Project

General

Profile

1
# Database access
2

    
3
import copy
4
import operator
5
import re
6
import warnings
7

    
8
import exc
9
import dicts
10
import iters
11
import lists
12
from Proxy import Proxy
13
import rand
14
import sql_gen
15
import strings
16
import util
17

    
18
##### Exceptions
19

    
20
def get_cur_query(cur, input_query=None):
21
    raw_query = None
22
    if hasattr(cur, 'query'): raw_query = cur.query
23
    elif hasattr(cur, '_last_executed'): raw_query = cur._last_executed
24
    
25
    if raw_query != None: return raw_query
26
    else: return '[input] '+strings.ustr(input_query)
27

    
28
def _add_cursor_info(e, *args, **kw_args):
29
    '''For params, see get_cur_query()'''
30
    exc.add_msg(e, 'query: '+strings.ustr(get_cur_query(*args, **kw_args)))
31

    
32
class DbException(exc.ExceptionWithCause):
33
    def __init__(self, msg, cause=None, cur=None):
34
        exc.ExceptionWithCause.__init__(self, msg, cause, cause_newline=True)
35
        if cur != None: _add_cursor_info(self, cur)
36

    
37
class ExceptionWithName(DbException):
38
    def __init__(self, name, cause=None):
39
        DbException.__init__(self, 'for name: '+strings.as_tt(str(name)), cause)
40
        self.name = name
41

    
42
class ExceptionWithNameValue(DbException):
43
    def __init__(self, name, value, cause=None):
44
        DbException.__init__(self, 'for name: '+strings.as_tt(str(name))
45
            +'; value: '+strings.as_tt(repr(value)), cause)
46
        self.name = name
47
        self.value = value
48

    
49
class ConstraintException(DbException):
50
    def __init__(self, name, cols, cause=None):
51
        DbException.__init__(self, 'Violated '+strings.as_tt(name)
52
            +' constraint on columns: '+strings.as_tt(', '.join(cols)), cause)
53
        self.name = name
54
        self.cols = cols
55

    
56
class MissingCastException(DbException):
57
    def __init__(self, type_, col, cause=None):
58
        DbException.__init__(self, 'Missing cast to type '+strings.as_tt(type_)
59
            +' on column: '+strings.as_tt(col), cause)
60
        self.type = type_
61
        self.col = col
62

    
63
class NameException(DbException): pass
64

    
65
class DuplicateKeyException(ConstraintException): pass
66

    
67
class NullValueException(ConstraintException): pass
68

    
69
class FunctionValueException(ExceptionWithNameValue): pass
70

    
71
class DuplicateTableException(ExceptionWithName): pass
72

    
73
class DuplicateFunctionException(ExceptionWithName): pass
74

    
75
class EmptyRowException(DbException): pass
76

    
77
##### Warnings
78

    
79
class DbWarning(UserWarning): pass
80

    
81
##### Result retrieval
82

    
83
def col_names(cur): return (col[0] for col in cur.description)
84

    
85
def rows(cur): return iter(lambda: cur.fetchone(), None)
86

    
87
def consume_rows(cur):
88
    '''Used to fetch all rows so result will be cached'''
89
    iters.consume_iter(rows(cur))
90

    
91
def next_row(cur): return rows(cur).next()
92

    
93
def row(cur):
94
    row_ = next_row(cur)
95
    consume_rows(cur)
96
    return row_
97

    
98
def next_value(cur): return next_row(cur)[0]
99

    
100
def value(cur): return row(cur)[0]
101

    
102
def values(cur): return iters.func_iter(lambda: next_value(cur))
103

    
104
def value_or_none(cur):
105
    try: return value(cur)
106
    except StopIteration: return None
107

    
108
##### Escaping
109

    
110
def esc_name_by_module(module, name):
111
    if module == 'psycopg2' or module == None: quote = '"'
112
    elif module == 'MySQLdb': quote = '`'
113
    else: raise NotImplementedError("Can't escape name for "+module+' database')
114
    return sql_gen.esc_name(name, quote)
115

    
116
def esc_name_by_engine(engine, name, **kw_args):
117
    return esc_name_by_module(db_engines[engine][0], name, **kw_args)
118

    
119
def esc_name(db, name, **kw_args):
120
    return esc_name_by_module(util.root_module(db.db), name, **kw_args)
121

    
122
def qual_name(db, schema, table):
123
    def esc_name_(name): return esc_name(db, name)
124
    table = esc_name_(table)
125
    if schema != None: return esc_name_(schema)+'.'+table
126
    else: return table
127

    
128
##### Database connections
129

    
130
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
131

    
132
db_engines = {
133
    'MySQL': ('MySQLdb', {'password': 'passwd', 'database': 'db'}),
134
    'PostgreSQL': ('psycopg2', {}),
135
}
136

    
137
DatabaseErrors_set = set([DbException])
138
DatabaseErrors = tuple(DatabaseErrors_set)
139

    
140
def _add_module(module):
141
    DatabaseErrors_set.add(module.DatabaseError)
142
    global DatabaseErrors
143
    DatabaseErrors = tuple(DatabaseErrors_set)
144

    
145
def db_config_str(db_config):
146
    return db_config['engine']+' database '+db_config['database']
147

    
148
log_debug_none = lambda msg, level=2: None
149

    
150
class DbConn:
151
    def __init__(self, db_config, autocommit=False, caching=True,
152
        log_debug=log_debug_none):
153
        self.db_config = db_config
154
        self.autocommit = autocommit
155
        self.caching = caching
156
        self.log_debug = log_debug
157
        self.debug = log_debug != log_debug_none
158
        
159
        self.__db = None
160
        self.query_results = {}
161
        self._savepoint = 0
162
        self._notices_seen = set()
163
    
164
    def __getattr__(self, name):
165
        if name == '__dict__': raise Exception('getting __dict__')
166
        if name == 'db': return self._db()
167
        else: raise AttributeError()
168
    
169
    def __getstate__(self):
170
        state = copy.copy(self.__dict__) # shallow copy
171
        state['log_debug'] = None # don't pickle the debug callback
172
        state['_DbConn__db'] = None # don't pickle the connection
173
        return state
174
    
175
    def connected(self): return self.__db != None
176
    
177
    def _db(self):
178
        if self.__db == None:
179
            # Process db_config
180
            db_config = self.db_config.copy() # don't modify input!
181
            schemas = db_config.pop('schemas', None)
182
            module_name, mappings = db_engines[db_config.pop('engine')]
183
            module = __import__(module_name)
184
            _add_module(module)
185
            for orig, new in mappings.iteritems():
186
                try: util.rename_key(db_config, orig, new)
187
                except KeyError: pass
188
            
189
            # Connect
190
            self.__db = module.connect(**db_config)
191
            
192
            # Configure connection
193
            if hasattr(self.db, 'set_isolation_level'):
194
                import psycopg2.extensions
195
                self.db.set_isolation_level(
196
                    psycopg2.extensions.ISOLATION_LEVEL_READ_COMMITTED)
197
            if schemas != None:
198
                search_path = [self.esc_name(s) for s in schemas.split(',')]
199
                search_path.append(value(run_query(self, 'SHOW search_path',
200
                    log_level=4)))
201
                run_query(self, 'SET search_path TO '+(','.join(search_path)),
202
                    log_level=3)
203
        
204
        return self.__db
205
    
206
    class DbCursor(Proxy):
207
        def __init__(self, outer):
208
            Proxy.__init__(self, outer.db.cursor())
209
            self.outer = outer
210
            self.query_results = outer.query_results
211
            self.query_lookup = None
212
            self.result = []
213
        
214
        def execute(self, query):
215
            self._is_insert = query.startswith('INSERT')
216
            self.query_lookup = query
217
            try:
218
                try:
219
                    cur = self.inner.execute(query)
220
                    self.outer.do_autocommit()
221
                finally: self.query = get_cur_query(self.inner, query)
222
            except Exception, e:
223
                _add_cursor_info(e, self, query)
224
                self.result = e # cache the exception as the result
225
                self._cache_result()
226
                raise
227
            if self.rowcount == 0 and query.startswith('SELECT'): # empty SELECT
228
                consume_rows(self) # fetch all rows so result will be cached
229
            return cur
230
        
231
        def fetchone(self):
232
            row = self.inner.fetchone()
233
            if row != None: self.result.append(row)
234
            # otherwise, fetched all rows
235
            else: self._cache_result()
236
            return row
237
        
238
        def _cache_result(self):
239
            # For inserts, only cache exceptions since inserts are not
240
            # idempotent, but an invalid insert will always be invalid
241
            if self.query_results != None and (not self._is_insert
242
                or isinstance(self.result, Exception)):
243
                
244
                assert self.query_lookup != None
245
                self.query_results[self.query_lookup] = self.CacheCursor(
246
                    util.dict_subset(dicts.AttrsDictView(self),
247
                    ['query', 'result', 'rowcount', 'description']))
248
        
249
        class CacheCursor:
250
            def __init__(self, cached_result): self.__dict__ = cached_result
251
            
252
            def execute(self, *args, **kw_args):
253
                if isinstance(self.result, Exception): raise self.result
254
                # otherwise, result is a rows list
255
                self.iter = iter(self.result)
256
            
257
            def fetchone(self):
258
                try: return self.iter.next()
259
                except StopIteration: return None
260
    
261
    def esc_value(self, value):
262
        try: str_ = self.mogrify('%s', [value])
263
        except NotImplementedError, e:
264
            module = util.root_module(self.db)
265
            if module == 'MySQLdb':
266
                import _mysql
267
                str_ = _mysql.escape_string(value)
268
            else: raise e
269
        return strings.to_unicode(str_)
270
    
271
    def esc_name(self, name): return esc_name(self, name) # calls global func
272
    
273
    def std_code(self, str_):
274
        '''Standardizes SQL code.
275
        * Ensures that string literals are prefixed by `E`
276
        '''
277
        if str_.startswith("'"): str_ = 'E'+str_
278
        return str_
279
    
280
    def can_mogrify(self):
281
        module = util.root_module(self.db)
282
        return module == 'psycopg2'
283
    
284
    def mogrify(self, query, params=None):
285
        if self.can_mogrify(): return self.db.cursor().mogrify(query, params)
286
        else: raise NotImplementedError("Can't mogrify query")
287
    
288
    def print_notices(self):
289
        if hasattr(self.db, 'notices'):
290
            for msg in self.db.notices:
291
                if msg not in self._notices_seen:
292
                    self._notices_seen.add(msg)
293
                    self.log_debug(msg, level=2)
294
    
295
    def run_query(self, query, cacheable=False, log_level=2,
296
        debug_msg_ref=None):
297
        '''
298
        @param log_ignore_excs The log_level will be increased by 2 if the query
299
            throws one of these exceptions.
300
        @param debug_msg_ref If specified, the log message will be returned in
301
            this instead of being output. This allows you to filter log messages
302
            depending on the result of the query.
303
        '''
304
        assert query != None
305
        
306
        if not self.caching: cacheable = False
307
        used_cache = False
308
        
309
        def log_msg(query):
310
            if used_cache: cache_status = 'cache hit'
311
            elif cacheable: cache_status = 'cache miss'
312
            else: cache_status = 'non-cacheable'
313
            return 'DB query: '+cache_status+':\n'+strings.as_code(query, 'SQL')
314
        
315
        try:
316
            # Get cursor
317
            if cacheable:
318
                try:
319
                    cur = self.query_results[query]
320
                    used_cache = True
321
                except KeyError: cur = self.DbCursor(self)
322
            else: cur = self.db.cursor()
323
            
324
            # Log query
325
            if self.debug and debug_msg_ref == None: # log before running
326
                self.log_debug(log_msg(query), log_level)
327
            
328
            # Run query
329
            cur.execute(query)
330
        finally:
331
            self.print_notices()
332
            if self.debug and debug_msg_ref != None: # return after running
333
                debug_msg_ref[0] = log_msg(str(get_cur_query(cur, query)))
334
        
335
        return cur
336
    
337
    def is_cached(self, query): return query in self.query_results
338
    
339
    def with_autocommit(self, func):
340
        import psycopg2.extensions
341
        
342
        prev_isolation_level = self.db.isolation_level
343
        self.db.set_isolation_level(
344
            psycopg2.extensions.ISOLATION_LEVEL_AUTOCOMMIT)
345
        try: return func()
346
        finally: self.db.set_isolation_level(prev_isolation_level)
347
    
348
    def with_savepoint(self, func):
349
        savepoint = 'level_'+str(self._savepoint)
350
        self.run_query('SAVEPOINT '+savepoint, log_level=4)
351
        self._savepoint += 1
352
        try:
353
            try: return_val = func()
354
            finally:
355
                self._savepoint -= 1
356
                assert self._savepoint >= 0
357
        except:
358
            self.run_query('ROLLBACK TO SAVEPOINT '+savepoint, log_level=4)
359
            raise
360
        else:
361
            self.run_query('RELEASE SAVEPOINT '+savepoint, log_level=4)
362
            self.do_autocommit()
363
            return return_val
364
    
365
    def do_autocommit(self):
366
        '''Autocommits if outside savepoint'''
367
        assert self._savepoint >= 0
368
        if self.autocommit and self._savepoint == 0:
369
            self.log_debug('Autocommitting')
370
            self.db.commit()
371
    
372
    def col_info(self, col):
373
        table = sql_gen.Table('columns', 'information_schema')
374
        cols = ['data_type', 'column_default',
375
            cast(self, 'boolean', 'is_nullable')]
376
        
377
        conds = [('table_name', col.table.name), ('column_name', col.name)]
378
        schema = col.table.schema
379
        if schema != None: conds.append(('table_schema', schema))
380
        
381
        type_, default, nullable = row(select(self, table, cols, conds,
382
            order_by='table_schema', limit=1, log_level=4))
383
            # TODO: order_by search_path schema order
384
        default = sql_gen.as_Code(default, self)
385
        
386
        return sql_gen.TypedCol(col.name, type_, default, nullable)
387

    
388
connect = DbConn
389

    
390
##### Recoverable querying
391

    
392
def with_savepoint(db, func): return db.with_savepoint(func)
393

    
394
def run_query(db, query, recover=None, cacheable=False, log_level=2,
395
    log_ignore_excs=None, **kw_args):
396
    '''For params, see DbConn.run_query()'''
397
    if recover == None: recover = False
398
    if log_ignore_excs == None: log_ignore_excs = ()
399
    log_ignore_excs = tuple(log_ignore_excs)
400
    
401
    debug_msg_ref = None # usually, db.run_query() logs query before running it
402
    # But if filtering with log_ignore_excs, wait until after exception parsing
403
    if log_ignore_excs != () or not db.can_mogrify(): debug_msg_ref = [None] 
404
    
405
    try:
406
        try:
407
            def run(): return db.run_query(query, cacheable, log_level,
408
                debug_msg_ref, **kw_args)
409
            if recover and not db.is_cached(query):
410
                return with_savepoint(db, run)
411
            else: return run() # don't need savepoint if cached
412
        except Exception, e:
413
            if not recover: raise # need savepoint to run index_cols()
414
            msg = exc.str_(e)
415
            
416
            match = re.search(r'duplicate key value violates unique constraint '
417
                r'"((_?[^\W_]+)_.+?)"', msg)
418
            if match:
419
                constraint, table = match.groups()
420
                try: cols = index_cols(db, table, constraint)
421
                except NotImplementedError: raise e
422
                else: raise DuplicateKeyException(constraint, cols, e)
423
            
424
            match = re.search(r'null value in column "(.+?)" violates not-null'
425
                r' constraint', msg)
426
            if match: raise NullValueException('NOT NULL', [match.group(1)], e)
427
            
428
            match = re.search(r'\b(?:invalid input (?:syntax|value)\b.*?'
429
                r'|date/time field value out of range): "(.+?)"\n'
430
                r'(?:(?s).*?)\bfunction "(.+?)"', msg)
431
            if match:
432
                value, name = match.groups()
433
                raise FunctionValueException(name, strings.to_unicode(value), e)
434
            
435
            match = re.search(r'column "(.+?)" is of type (.+?) but expression '
436
                r'is of type', msg)
437
            if match:
438
                col, type_ = match.groups()
439
                raise MissingCastException(type_, col, e)
440
            
441
            match = re.search(r'relation "(.+?)" already exists', msg)
442
            if match: raise DuplicateTableException(match.group(1), e)
443
            
444
            match = re.search(r'function "(.+?)" already exists', msg)
445
            if match: raise DuplicateFunctionException(match.group(1), e)
446
            
447
            raise # no specific exception raised
448
    except log_ignore_excs:
449
        log_level += 2
450
        raise
451
    finally:
452
        if debug_msg_ref != None and debug_msg_ref[0] != None:
453
            db.log_debug(debug_msg_ref[0], log_level)
454

    
455
##### Basic queries
456

    
457
def next_version(name):
458
    version = 1 # first existing name was version 0
459
    match = re.match(r'^(.*)#(\d+)$', name)
460
    if match:
461
        name, version = match.groups()
462
        version = int(version)+1
463
    return sql_gen.add_suffix(name, '#'+str(version))
464

    
465
def lock_table(db, table, mode):
466
    table = sql_gen.as_Table(table)
467
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
468

    
469
def run_query_into(db, query, into=None, add_indexes_=False, **kw_args):
470
    '''Outputs a query to a temp table.
471
    For params, see run_query().
472
    '''
473
    if into == None: return run_query(db, query, **kw_args)
474
    
475
    assert isinstance(into, sql_gen.Table)
476
    
477
    kw_args['recover'] = True
478
    kw_args.setdefault('log_ignore_excs', (DuplicateTableException,))
479
    
480
    temp = not db.autocommit # tables are permanent in autocommit mode
481
    # "temporary tables cannot specify a schema name", so remove schema
482
    if temp: into.schema = None
483
    
484
    # Create table
485
    while True:
486
        create_query = 'CREATE'
487
        if temp: create_query += ' TEMP'
488
        create_query += ' TABLE '+into.to_str(db)+' AS\n'+query
489
        
490
        try:
491
            cur = run_query(db, create_query, **kw_args)
492
                # CREATE TABLE AS sets rowcount to # rows in query
493
            break
494
        except DuplicateTableException, e:
495
            into.name = next_version(into.name)
496
            # try again with next version of name
497
    
498
    if add_indexes_: add_indexes(db, into)
499
    
500
    return cur
501

    
502
order_by_pkey = object() # tells mk_select() to order by the pkey
503

    
504
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
505

    
506
def mk_select(db, tables, fields=None, conds=None, distinct_on=[], limit=None,
507
    start=None, order_by=order_by_pkey, default_table=None):
508
    '''
509
    @param tables The single table to select from, or a list of tables to join
510
        together, with tables after the first being sql_gen.Join objects
511
    @param fields Use None to select all fields in the table
512
    @param conds WHERE conditions: [(compare_left_side, compare_right_side),...]
513
        * container can be any iterable type
514
        * compare_left_side: sql_gen.Code|str (for col name)
515
        * compare_right_side: sql_gen.ValueCond|literal value
516
    @param distinct_on The columns to SELECT DISTINCT ON, or distinct_on_all to
517
        use all columns
518
    @return query
519
    '''
520
    # Parse tables param
521
    if not lists.is_seq(tables): tables = [tables]
522
    tables = list(tables) # don't modify input! (list() copies input)
523
    table0 = sql_gen.as_Table(tables.pop(0)) # first table is separate
524
    
525
    # Parse other params
526
    if conds == None: conds = []
527
    elif dicts.is_dict(conds): conds = conds.items()
528
    conds = list(conds) # don't modify input! (list() copies input)
529
    assert limit == None or type(limit) == int
530
    assert start == None or type(start) == int
531
    if order_by is order_by_pkey:
532
        if distinct_on != []: order_by = None
533
        else: order_by = pkey(db, table0, recover=True)
534
    
535
    query = 'SELECT'
536
    
537
    def parse_col(col): return sql_gen.as_Col(col, default_table).to_str(db)
538
    
539
    # DISTINCT ON columns
540
    if distinct_on != []:
541
        query += '\nDISTINCT'
542
        if distinct_on is not distinct_on_all:
543
            query += ' ON ('+(', '.join(map(parse_col, distinct_on)))+')'
544
    
545
    # Columns
546
    query += '\n'
547
    if fields == None: query += '*'
548
    else:
549
        assert fields != []
550
        query += '\n, '.join(map(parse_col, fields))
551
    
552
    # Main table
553
    query += '\nFROM '+table0.to_str(db)
554
    
555
    # Add joins
556
    left_table = table0
557
    for join_ in tables:
558
        table = join_.table
559
        
560
        # Parse special values
561
        if join_.type_ is sql_gen.filter_out: # filter no match
562
            conds.append((sql_gen.Col(table_not_null_col(db, table), table),
563
                sql_gen.CompareCond(None, '~=')))
564
        
565
        query += '\n'+join_.to_str(db, left_table)
566
        
567
        left_table = table
568
    
569
    missing = True
570
    if conds != []:
571
        if len(conds) == 1: whitespace = ' '
572
        else: whitespace = '\n'
573
        query += '\n'+sql_gen.combine_conds([sql_gen.ColValueCond(l, r)
574
            .to_str(db) for l, r in conds], 'WHERE')
575
        missing = False
576
    if order_by != None:
577
        query += '\nORDER BY '+sql_gen.as_Col(order_by, table0).to_str(db)
578
    if limit != None: query += '\nLIMIT '+str(limit); missing = False
579
    if start != None:
580
        if start != 0: query += '\nOFFSET '+str(start)
581
        missing = False
582
    if missing: warnings.warn(DbWarning(
583
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
584
    
585
    return query
586

    
587
def select(db, *args, **kw_args):
588
    '''For params, see mk_select() and run_query()'''
589
    recover = kw_args.pop('recover', None)
590
    cacheable = kw_args.pop('cacheable', True)
591
    log_level = kw_args.pop('log_level', 2)
592
    
593
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
594
        log_level=log_level)
595

    
596
def mk_insert_select(db, table, cols=None, select_query=None, returning=None,
597
    embeddable=False):
598
    '''
599
    @param returning str|None An inserted column (such as pkey) to return
600
    @param embeddable Whether the query should be embeddable as a nested SELECT.
601
        Warning: If you set this and cacheable=True when the query is run, the
602
        query will be fully cached, not just if it raises an exception.
603
    '''
604
    table = sql_gen.remove_table_rename(sql_gen.as_Table(table))
605
    if cols == []: cols = None # no cols (all defaults) = unknown col names
606
    if cols != None:
607
        cols = [sql_gen.to_name_only_col(v, table).to_str(db) for v in cols]
608
    if select_query == None: select_query = 'DEFAULT VALUES'
609
    if returning != None: returning = sql_gen.as_Col(returning, table)
610
    
611
    # Build query
612
    first_line = 'INSERT INTO '+table.to_str(db)
613
    query = first_line
614
    if cols != None: query += '\n('+', '.join(cols)+')'
615
    query += '\n'+select_query
616
    
617
    if returning != None:
618
        query += '\nRETURNING '+sql_gen.to_name_only_col(returning).to_str(db)
619
    
620
    if embeddable:
621
        assert returning != None
622
        
623
        # Create function
624
        function_name = sql_gen.clean_name(first_line)
625
        return_type = 'SETOF '+returning.to_str(db)+'%TYPE'
626
        while True:
627
            try:
628
                function = sql_gen.TempFunction(function_name, db.autocommit)
629
                
630
                function_query = '''\
631
CREATE FUNCTION '''+function.to_str(db)+'''()
632
RETURNS '''+return_type+'''
633
LANGUAGE sql
634
AS $$
635
'''+query+''';
636
$$;
637
'''
638
                run_query(db, function_query, recover=True, cacheable=True,
639
                    log_ignore_excs=(DuplicateFunctionException,))
640
                break # this version was successful
641
            except DuplicateFunctionException, e:
642
                function_name = next_version(function_name)
643
                # try again with next version of name
644
        
645
        # Return query that uses function
646
        func_table = sql_gen.NamedTable('f', sql_gen.FunctionCall(function),
647
            [returning]) # AS clause requires function alias
648
        return mk_select(db, func_table, start=0, order_by=None)
649
    
650
    return query
651

    
652
def insert_select(db, *args, **kw_args):
653
    '''For params, see mk_insert_select() and run_query_into()
654
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
655
        values in
656
    '''
657
    into = kw_args.pop('into', None)
658
    if into != None: kw_args['embeddable'] = True
659
    recover = kw_args.pop('recover', None)
660
    cacheable = kw_args.pop('cacheable', True)
661
    log_level = kw_args.pop('log_level', 2)
662
    
663
    return run_query_into(db, mk_insert_select(db, *args, **kw_args), into,
664
        recover=recover, cacheable=cacheable, log_level=log_level)
665

    
666
default = sql_gen.default # tells insert() to use the default value for a column
667

    
668
def insert(db, table, row, *args, **kw_args):
669
    '''For params, see insert_select()'''
670
    if lists.is_seq(row): cols = None
671
    else:
672
        cols = row.keys()
673
        row = row.values()
674
    row = list(row) # ensure that "== []" works
675
    
676
    if row == []: query = None
677
    else: query = sql_gen.Values(row).to_str(db)
678
    
679
    return insert_select(db, table, cols, query, *args, **kw_args)
680

    
681
def mk_update(db, table, changes=None, cond=None):
682
    '''
683
    @param changes [(col, new_value),...]
684
        * container can be any iterable type
685
        * col: sql_gen.Code|str (for col name)
686
        * new_value: sql_gen.Code|literal value
687
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
688
    @return str query
689
    '''
690
    query = 'UPDATE '+sql_gen.as_Table(table).to_str(db)+'\nSET\n'
691
    query += ',\n'.join((sql_gen.to_name_only_col(col, table).to_str(db)+' = '
692
        +sql_gen.as_Value(new_value).to_str(db) for col, new_value in changes))
693
    if cond != None: query += '\nWHERE\n'+cond.to_str(db)
694
    
695
    return query
696

    
697
def update(db, *args, **kw_args):
698
    '''For params, see mk_update() and run_query()'''
699
    recover = kw_args.pop('recover', None)
700
    
701
    return run_query(db, mk_update(db, *args, **kw_args), recover)
702

    
703
def last_insert_id(db):
704
    module = util.root_module(db.db)
705
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
706
    elif module == 'MySQLdb': return db.insert_id()
707
    else: return None
708

    
709
def mk_flatten_mapping(db, into, cols, preserve=[], as_items=False):
710
    '''Creates a mapping from original column names (which may have collisions)
711
    to names that will be distinct among the columns' tables.
712
    This is meant to be used for several tables that are being joined together.
713
    @param cols The columns to combine. Duplicates will be removed.
714
    @param into The table for the new columns.
715
    @param preserve [sql_gen.Col...] Columns not to rename. Note that these
716
        columns will be included in the mapping even if they are not in cols.
717
        The tables of the provided Col objects will be changed to into, so make
718
        copies of them if you want to keep the original tables.
719
    @param as_items Whether to return a list of dict items instead of a dict
720
    @return dict(orig_col=new_col, ...)
721
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
722
        * new_col: sql_gen.Col(orig_col_name, into)
723
        * All mappings use the into table so its name can easily be
724
          changed for all columns at once
725
    '''
726
    cols = lists.uniqify(cols)
727
    
728
    items = []
729
    for col in preserve:
730
        orig_col = copy.copy(col)
731
        col.table = into
732
        items.append((orig_col, col))
733
    preserve = set(preserve)
734
    for col in cols:
735
        if col not in preserve:
736
            items.append((col, sql_gen.Col(str(col), into, col.srcs)))
737
    
738
    if not as_items: items = dict(items)
739
    return items
740

    
741
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
742
    '''For params, see mk_flatten_mapping()
743
    @return See return value of mk_flatten_mapping()
744
    '''
745
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
746
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
747
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
748
        into=into, add_indexes_=True)
749
    return dict(items)
750

    
751
def mk_track_data_error(db, errors_table, cols, value, error_code, error):
752
    assert cols != ()
753
    
754
    cols = map(sql_gen.to_name_only_col, cols)
755
    
756
    columns_cols = ['column']
757
    columns = sql_gen.NamedValues('columns', columns_cols,
758
        [[c.name] for c in cols])
759
    values_cols = ['value', 'error_code', 'error']
760
    values = sql_gen.NamedValues('values', values_cols,
761
        [value, error_code, error])
762
    
763
    select_cols = columns_cols+values_cols
764
    name_only_cols = map(sql_gen.to_name_only_col, select_cols)
765
    errors_table = sql_gen.NamedTable('errors', errors_table)
766
    joins = [columns, sql_gen.Join(values, type_='CROSS'),
767
        sql_gen.Join(errors_table, dict(zip(name_only_cols, select_cols)),
768
        sql_gen.filter_out)]
769
    
770
    return mk_insert_select(db, errors_table, name_only_cols,
771
        mk_select(db, joins, select_cols, order_by=None))
772

    
773
def track_data_error(db, errors_table, cols, *args, **kw_args):
774
    '''
775
    @param errors_table If None, does nothing.
776
    '''
777
    if errors_table == None or cols == (): return
778
    run_query(db, mk_track_data_error(db, errors_table, cols, *args, **kw_args),
779
        cacheable=True, log_level=4)
780

    
781
def cast(db, type_, col, errors_table=None):
782
    '''Casts an (unrenamed) column or value.
783
    If errors_table set and col has srcs, saves errors in errors_table (using
784
    col's srcs attr as the source columns) and converts errors to warnings.
785
    @param col str|sql_gen.Col|sql_gen.Literal
786
    @param errors_table None|sql_gen.Table|str
787
    '''
788
    col = sql_gen.as_Col(col)
789
    save_errors = (errors_table != None and isinstance(col, sql_gen.Col)
790
        and col.srcs != ())
791
    if not save_errors: # can't save errors
792
        return sql_gen.CustomCode(col.to_str(db)+'::'+type_) # just cast
793
    
794
    assert not isinstance(col, sql_gen.NamedCol)
795
    
796
    errors_table = sql_gen.as_Table(errors_table)
797
    srcs = map(sql_gen.to_name_only_col, col.srcs)
798
    function_name = str(sql_gen.FunctionCall(type_, *srcs))
799
    function = sql_gen.TempFunction(function_name, db.autocommit)
800
    
801
    while True:
802
        # Create function definition
803
        query = '''\
804
CREATE FUNCTION '''+function.to_str(db)+'''(value text)
805
RETURNS '''+type_+'''
806
LANGUAGE plpgsql
807
STRICT
808
AS $$
809
BEGIN
810
    /* The explicit cast to the return type is needed to make the cast happen
811
    inside the try block. (Implicit casts to the return type happen at the end
812
    of the function, outside any block.) */
813
    RETURN value::'''+type_+''';
814
EXCEPTION
815
    WHEN data_exception THEN
816
        -- Save error in errors table.
817
        -- Insert the value and error for *each* source column.
818
'''+mk_track_data_error(db, errors_table, srcs,
819
    *map(sql_gen.CustomCode, ['value', 'SQLSTATE', 'SQLERRM']))+''';
820
        
821
        RAISE WARNING '%', SQLERRM;
822
        RETURN NULL;
823
END;
824
$$;
825
'''
826
        
827
        # Create function
828
        try:
829
            run_query(db, query, recover=True, cacheable=True,
830
                log_ignore_excs=(DuplicateFunctionException,))
831
            break # successful
832
        except DuplicateFunctionException:
833
            function.name = next_version(function.name)
834
            # try again with next version of name
835
    
836
    return sql_gen.FunctionCall(function, col)
837

    
838
##### Database structure queries
839

    
840
def table_row_count(db, table, recover=None):
841
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
842
        order_by=None, start=0), recover=recover, log_level=3))
843

    
844
def table_cols(db, table, recover=None):
845
    return list(col_names(select(db, table, limit=0, order_by=None,
846
        recover=recover, log_level=4)))
847

    
848
def pkey(db, table, recover=None):
849
    '''Assumed to be first column in table'''
850
    return table_cols(db, table, recover)[0]
851

    
852
not_null_col = 'not_null_col'
853

    
854
def table_not_null_col(db, table, recover=None):
855
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
856
    if not_null_col in table_cols(db, table, recover): return not_null_col
857
    else: return pkey(db, table, recover)
858

    
859
def index_cols(db, table, index):
860
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
861
    automatically created. When you don't know whether something is a UNIQUE
862
    constraint or a UNIQUE index, use this function.'''
863
    module = util.root_module(db.db)
864
    if module == 'psycopg2':
865
        return list(values(run_query(db, '''\
866
SELECT attname
867
FROM
868
(
869
        SELECT attnum, attname
870
        FROM pg_index
871
        JOIN pg_class index ON index.oid = indexrelid
872
        JOIN pg_class table_ ON table_.oid = indrelid
873
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
874
        WHERE
875
            table_.relname = '''+db.esc_value(table)+'''
876
            AND index.relname = '''+db.esc_value(index)+'''
877
    UNION
878
        SELECT attnum, attname
879
        FROM
880
        (
881
            SELECT
882
                indrelid
883
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
884
                    AS indkey
885
            FROM pg_index
886
            JOIN pg_class index ON index.oid = indexrelid
887
            JOIN pg_class table_ ON table_.oid = indrelid
888
            WHERE
889
                table_.relname = '''+db.esc_value(table)+'''
890
                AND index.relname = '''+db.esc_value(index)+'''
891
        ) s
892
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
893
) s
894
ORDER BY attnum
895
'''
896
            , cacheable=True, log_level=4)))
897
    else: raise NotImplementedError("Can't list index columns for "+module+
898
        ' database')
899

    
900
def constraint_cols(db, table, constraint):
901
    module = util.root_module(db.db)
902
    if module == 'psycopg2':
903
        return list(values(run_query(db, '''\
904
SELECT attname
905
FROM pg_constraint
906
JOIN pg_class ON pg_class.oid = conrelid
907
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
908
WHERE
909
    relname = '''+db.esc_value(table)+'''
910
    AND conname = '''+db.esc_value(constraint)+'''
911
ORDER BY attnum
912
'''
913
            )))
914
    else: raise NotImplementedError("Can't list constraint columns for "+module+
915
        ' database')
916

    
917
row_num_col = '_row_num'
918

    
919
def add_index(db, exprs, table=None, unique=False, ensure_not_null=True):
920
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
921
    Currently, only function calls are supported as expressions.
922
    @param ensure_not_null If set, translates NULL values to sentinel values.
923
        This allows indexes to be used for comparisons where NULLs are equal.
924
    '''
925
    if not lists.is_seq(exprs): exprs = [exprs]
926
    
927
    # Parse exprs
928
    old_exprs = exprs[:]
929
    exprs = []
930
    cols = []
931
    for i, expr in enumerate(old_exprs):
932
        expr = copy.deepcopy(expr) # don't modify input!
933
        expr = sql_gen.as_Col(expr, table)
934
        
935
        # Handle nullable columns
936
        if ensure_not_null:
937
            try: expr = sql_gen.ensure_not_null(db, expr)
938
            except KeyError: pass # unknown type, so just create plain index
939
        
940
        # Extract col
941
        if isinstance(expr, sql_gen.FunctionCall):
942
            col = expr.args[0]
943
            expr = sql_gen.Expr(expr)
944
        else: col = expr
945
        assert isinstance(col, sql_gen.Col)
946
        
947
        # Extract table
948
        if table == None:
949
            assert sql_gen.is_table_col(col)
950
            table = col.table
951
        
952
        col.table = None
953
        
954
        exprs.append(expr)
955
        cols.append(col)
956
    
957
    table = sql_gen.as_Table(table)
958
    index = sql_gen.Table(str(sql_gen.Col(','.join(map(str, cols)), table)))
959
    
960
    str_ = 'CREATE'
961
    if unique: str_ += ' UNIQUE'
962
    str_ += ' INDEX '+index.to_str(db)+' ON '+table.to_str(db)+' ('+(
963
        ', '.join((v.to_str(db) for v in exprs)))+')'
964
    
965
    try: run_query(db, str_, recover=True, cacheable=True, log_level=3)
966
    except DuplicateTableException: pass # index already existed
967

    
968
def add_pkey(db, table, cols=None, recover=None):
969
    '''Adds a primary key.
970
    @param cols [sql_gen.Col,...] The columns in the primary key.
971
        Defaults to the first column in the table.
972
    @pre The table must not already have a primary key.
973
    '''
974
    table = sql_gen.as_Table(table)
975
    if cols == None: cols = [pkey(db, table, recover)]
976
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
977
    
978
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
979
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
980
        log_ignore_excs=(DuplicateTableException,))
981

    
982
already_indexed = object() # tells add_indexes() the pkey has already been added
983

    
984
def add_indexes(db, table, has_pkey=True):
985
    '''Adds an index on all columns in a table.
986
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
987
        index should be added on the first column.
988
        * If already_indexed, the pkey is assumed to have already been added
989
    '''
990
    cols = table_cols(db, table)
991
    if has_pkey:
992
        if has_pkey is not already_indexed: add_pkey(db, table)
993
        cols = cols[1:]
994
    for col in cols: add_index(db, col, table)
995

    
996
def add_row_num(db, table):
997
    '''Adds a row number column to a table. Its name is in row_num_col. It will
998
    be the primary key.'''
999
    table = sql_gen.as_Table(table).to_str(db)
1000
    run_query(db, 'ALTER TABLE '+table+' ADD COLUMN '+row_num_col
1001
        +' serial NOT NULL PRIMARY KEY', log_level=3)
1002

    
1003
def drop_table(db, table):
1004
    table = sql_gen.as_Table(table)
1005
    return run_query(db, 'DROP TABLE IF EXISTS '+table.to_str(db)+' CASCADE')
1006

    
1007
def create_table(db, table, cols, has_pkey=True, col_indexes=True):
1008
    '''Creates a table.
1009
    @param cols [sql_gen.TypedCol,...] The column names and types
1010
    @param has_pkey If set, the first column becomes the primary key.
1011
    @param col_indexes bool|[ref]
1012
        * If True, indexes will be added on all non-pkey columns.
1013
        * If a list reference, [0] will be set to a function to do this.
1014
          This can be used to delay index creation until the table is populated.
1015
    '''
1016
    table = sql_gen.as_Table(table)
1017
    
1018
    if has_pkey:
1019
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1020
        pkey.constraints = 'PRIMARY KEY'
1021
    
1022
    str_ = 'CREATE TABLE '+table.to_str(db)+' (\n'
1023
    str_ += '\n, '.join(v.to_str(db) for v in cols)
1024
    str_ += '\n);\n'
1025
    run_query(db, str_, cacheable=True, log_level=2)
1026
    
1027
    # Add indexes
1028
    if has_pkey: has_pkey = already_indexed
1029
    def add_indexes_(): add_indexes(db, table, has_pkey)
1030
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1031
    elif col_indexes: add_indexes_() # add now
1032

    
1033
def vacuum(db, table):
1034
    table = sql_gen.as_Table(table)
1035
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1036
        log_level=3))
1037

    
1038
def truncate(db, table, schema='public'):
1039
    table = sql_gen.as_Table(table, schema)
1040
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE')
1041

    
1042
def tables(db, schema_like='public', table_like='%', exact=False):
1043
    if exact: compare = '='
1044
    else: compare = 'LIKE'
1045
    
1046
    module = util.root_module(db.db)
1047
    if module == 'psycopg2':
1048
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1049
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1050
        return values(select(db, 'pg_tables', ['tablename'], conds,
1051
            order_by='tablename', log_level=4))
1052
    elif module == 'MySQLdb':
1053
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1054
            , cacheable=True, log_level=4))
1055
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1056

    
1057
def table_exists(db, table):
1058
    table = sql_gen.as_Table(table)
1059
    return list(tables(db, table.schema, table.name, exact=True)) != []
1060

    
1061
def errors_table(db, table, if_exists=True):
1062
    '''
1063
    @param if_exists If set, returns None if the errors table doesn't exist
1064
    @return None|sql_gen.Table
1065
    '''
1066
    table = sql_gen.as_Table(table)
1067
    if table.srcs != (): table = table.srcs[0]
1068
    
1069
    errors_table = sql_gen.suffixed_table(table, '.errors')
1070
    if if_exists and not table_exists(db, errors_table): return None
1071
    return errors_table
1072

    
1073
##### Database management
1074

    
1075
def empty_db(db, schema='public', **kw_args):
1076
    '''For kw_args, see tables()'''
1077
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1078

    
1079
##### Heuristic queries
1080

    
1081
def put(db, table, row, pkey_=None, row_ct_ref=None):
1082
    '''Recovers from errors.
1083
    Only works under PostgreSQL (uses INSERT RETURNING).
1084
    '''
1085
    row = sql_gen.ColDict(db, table, row)
1086
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
1087
    
1088
    try:
1089
        cur = insert(db, table, row, pkey_, recover=True)
1090
        if row_ct_ref != None and cur.rowcount >= 0:
1091
            row_ct_ref[0] += cur.rowcount
1092
        return value(cur)
1093
    except DuplicateKeyException, e:
1094
        row = sql_gen.ColDict(db, table,
1095
            util.dict_subset_right_join(row, e.cols))
1096
        return value(select(db, table, [pkey_], row, recover=True))
1097

    
1098
def get(db, table, row, pkey, row_ct_ref=None, create=False):
1099
    '''Recovers from errors'''
1100
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
1101
    except StopIteration:
1102
        if not create: raise
1103
        return put(db, table, row, pkey, row_ct_ref) # insert new row
1104

    
1105
def is_func_result(col):
1106
    return col.table.name.find('(') >= 0 and col.name == 'result'
1107

    
1108
def into_table_name(out_table, in_tables0, mapping, is_func):
1109
    def in_col_str(in_col):
1110
        in_col = sql_gen.remove_col_rename(in_col)
1111
        if isinstance(in_col, sql_gen.Col):
1112
            table = in_col.table
1113
            if table == in_tables0:
1114
                in_col = sql_gen.to_name_only_col(in_col)
1115
            elif is_func_result(in_col): in_col = table # omit col name
1116
        return str(in_col)
1117
    
1118
    str_ = str(out_table)
1119
    if is_func:
1120
        str_ += '('
1121
        
1122
        try: value_in_col = mapping['value']
1123
        except KeyError:
1124
            str_ += ', '.join((str(k)+'='+in_col_str(v)
1125
                for k, v in mapping.iteritems()))
1126
        else: str_ += in_col_str(value_in_col)
1127
        
1128
        str_ += ')'
1129
    else:
1130
        out_col = 'rank'
1131
        try: in_col = mapping[out_col]
1132
        except KeyError: str_ += '_pkeys'
1133
        else: # has a rank column, so hierarchical
1134
            str_ += '['+str(out_col)+'='+in_col_str(in_col)+']'
1135
    return str_
1136

    
1137
def put_table(db, out_table, in_tables, mapping, row_ct_ref=None, into=None,
1138
    default=None, is_func=False, on_error=exc.raise_):
1139
    '''Recovers from errors.
1140
    Only works under PostgreSQL (uses INSERT RETURNING).
1141
    IMPORTANT: Must be run at the *beginning* of a transaction.
1142
    @param in_tables The main input table to select from, followed by a list of
1143
        tables to join with it using the main input table's pkey
1144
    @param mapping dict(out_table_col=in_table_col, ...)
1145
        * out_table_col: str (*not* sql_gen.Col)
1146
        * in_table_col: sql_gen.Col|literal-value
1147
    @param into The table to contain the output and input pkeys.
1148
        Defaults to `out_table.name+'_pkeys'`.
1149
    @param default The *output* column to use as the pkey for missing rows.
1150
        If this output column does not exist in the mapping, uses None.
1151
    @param is_func Whether out_table is the name of a SQL function, not a table
1152
    @return sql_gen.Col Where the output pkeys are made available
1153
    '''
1154
    out_table = sql_gen.as_Table(out_table)
1155
    
1156
    def log_debug(msg): db.log_debug(msg, level=1.5)
1157
    def col_ustr(str_):
1158
        return strings.repr_no_u(sql_gen.remove_col_rename(str_))
1159
    
1160
    log_debug('********** New iteration **********')
1161
    log_debug('Inserting these input columns into '+strings.as_tt(
1162
        out_table.to_str(db))+':\n'+strings.as_table(mapping, ustr=col_ustr))
1163
    
1164
    log_debug('Locking output table to prevent concurrent duplicate keys')
1165
    # Must happen before any SELECT query on the table to avoid lock upgrades
1166
    lock_table(db, out_table, 'EXCLUSIVE')
1167
    
1168
    out_pkey = pkey(db, out_table, recover=True)
1169
    out_pkey_col = sql_gen.as_Col(out_pkey, out_table)
1170
    
1171
    if mapping == {}: # need at least one column for INSERT SELECT
1172
        mapping = {out_pkey: None} # ColDict will replace with default value
1173
    
1174
    # Create input joins from list of input tables
1175
    in_tables_ = in_tables[:] # don't modify input!
1176
    in_tables0 = in_tables_.pop(0) # first table is separate
1177
    errors_table_ = errors_table(db, in_tables0)
1178
    in_pkey = pkey(db, in_tables0, recover=True)
1179
    in_pkey_col = sql_gen.as_Col(in_pkey, in_tables0)
1180
    input_joins = [in_tables0]+[sql_gen.Join(v,
1181
        {in_pkey: sql_gen.join_same_not_null}) for v in in_tables_]
1182
    
1183
    if into == None:
1184
        into = into_table_name(out_table, in_tables0, mapping, is_func)
1185
    into = sql_gen.as_Table(into)
1186
    
1187
    # Set column sources
1188
    in_cols = filter(sql_gen.is_table_col, mapping.values())
1189
    for col in in_cols:
1190
        if col.table == in_tables0: col.set_srcs(sql_gen.src_self)
1191
    
1192
    log_debug('Joining together input tables into temp table')
1193
    # Place in new table for speed and so don't modify input if values edited
1194
    in_table = sql_gen.Table('in')
1195
    mapping = dicts.join(mapping, flatten(db, in_table, input_joins, in_cols,
1196
        preserve=[in_pkey_col], start=0))
1197
    input_joins = [in_table]
1198
    db.log_debug('Temp table: '+strings.as_tt(in_table.to_str(db)), level=2)
1199
    
1200
    mapping = sql_gen.ColDict(db, out_table, mapping)
1201
        # after applying dicts.join() because that returns a plain dict
1202
    
1203
    # Resolve default value column
1204
    if default != None:
1205
        try: default = mapping[default]
1206
        except KeyError:
1207
            db.log_debug('Default value column '
1208
                +strings.as_tt(strings.repr_no_u(default))
1209
                +' does not exist in mapping, falling back to None', level=2.1)
1210
            default = None
1211
    
1212
    pkeys_names = [in_pkey, out_pkey]
1213
    pkeys_cols = [in_pkey_col, out_pkey_col]
1214
    
1215
    pkeys_table_exists_ref = [False]
1216
    def insert_into_pkeys(joins, cols):
1217
        query = mk_select(db, joins, cols, order_by=None, start=0)
1218
        if pkeys_table_exists_ref[0]:
1219
            insert_select(db, into, pkeys_names, query)
1220
        else:
1221
            run_query_into(db, query, into=into)
1222
            pkeys_table_exists_ref[0] = True
1223
    
1224
    limit_ref = [None]
1225
    conds = set()
1226
    distinct_on = sql_gen.ColDict(db, out_table)
1227
    def mk_main_select(joins, cols):
1228
        distinct_on_cols = [c.to_Col() for c in distinct_on.values()]
1229
        return mk_select(db, joins, cols, conds, distinct_on_cols,
1230
            limit=limit_ref[0], start=0)
1231
    
1232
    exc_strs = set()
1233
    def log_exc(e):
1234
        e_str = exc.str_(e, first_line_only=True)
1235
        log_debug('Caught exception: '+e_str)
1236
        assert e_str not in exc_strs # avoid infinite loops
1237
        exc_strs.add(e_str)
1238
    
1239
    def remove_all_rows():
1240
        log_debug('Ignoring all rows')
1241
        limit_ref[0] = 0 # just create an empty pkeys table
1242
    
1243
    def ignore(in_col, value, e):
1244
        track_data_error(db, errors_table_, in_col.srcs, value, e.cause.pgcode,
1245
            e.cause.pgerror)
1246
        log_debug('Ignoring rows with '+strings.as_tt(repr(in_col))+' = '
1247
            +strings.as_tt(repr(value)))
1248
    
1249
    def remove_rows(in_col, value, e):
1250
        ignore(in_col, value, e)
1251
        cond = (in_col, sql_gen.CompareCond(value, '!='))
1252
        assert cond not in conds # avoid infinite loops
1253
        conds.add(cond)
1254
    
1255
    def invalid2null(in_col, value, e):
1256
        ignore(in_col, value, e)
1257
        update(db, in_table, [(in_col, None)],
1258
            sql_gen.ColValueCond(in_col, value))
1259
    
1260
    def insert_pkeys_table(which):
1261
        return sql_gen.Table(sql_gen.add_suffix(in_table.name,
1262
            '_insert_'+which+'_pkeys'))
1263
    insert_out_pkeys = insert_pkeys_table('out')
1264
    insert_in_pkeys = insert_pkeys_table('in')
1265
    
1266
    # Do inserts and selects
1267
    join_cols = sql_gen.ColDict(db, out_table)
1268
    while True:
1269
        if limit_ref[0] == 0: # special case
1270
            log_debug('Creating an empty pkeys table')
1271
            cur = run_query_into(db, mk_select(db, out_table, [out_pkey],
1272
                limit=limit_ref[0]), into=insert_out_pkeys)
1273
            break # don't do main case
1274
        
1275
        has_joins = join_cols != {}
1276
        
1277
        log_debug('Trying to insert new rows')
1278
        
1279
        # Prepare to insert new rows
1280
        insert_joins = input_joins[:] # don't modify original!
1281
        insert_args = dict(recover=True, cacheable=False)
1282
        if has_joins:
1283
            insert_joins.append(sql_gen.Join(out_table, join_cols,
1284
                sql_gen.filter_out))
1285
        else:
1286
            insert_args.update(dict(returning=out_pkey, into=insert_out_pkeys))
1287
        main_select = mk_main_select(insert_joins, mapping.values())
1288
        
1289
        try:
1290
            cur = insert_select(db, out_table, mapping.keys(), main_select,
1291
                **insert_args)
1292
            break # insert successful
1293
        except DuplicateKeyException, e:
1294
            log_exc(e)
1295
            
1296
            old_join_cols = join_cols.copy()
1297
            distinct_on.update(util.dict_subset(mapping, e.cols))
1298
            join_cols.update(util.dict_subset_right_join(mapping, e.cols))
1299
            log_debug('Ignoring existing rows, comparing on these columns:\n'
1300
                +strings.as_inline_table(join_cols, ustr=col_ustr))
1301
            assert join_cols != old_join_cols # avoid infinite loops
1302
        except NullValueException, e:
1303
            log_exc(e)
1304
            
1305
            out_col, = e.cols
1306
            try: in_col = mapping[out_col]
1307
            except KeyError:
1308
                log_debug('Missing mapping for NOT NULL column '+out_col)
1309
                remove_all_rows()
1310
            else: remove_rows(in_col, None, e)
1311
        except FunctionValueException, e:
1312
            log_exc(e)
1313
            
1314
            func_name = e.name
1315
            value = e.value
1316
            for out_col, in_col in mapping.iteritems():
1317
                in_col = sql_gen.unwrap_func_call(in_col, func_name)
1318
                invalid2null(in_col, value, e)
1319
        except MissingCastException, e:
1320
            log_exc(e)
1321
            
1322
            out_col = e.col
1323
            type_ = e.type
1324
            
1325
            log_debug('Casting '+strings.as_tt(out_col)+' input to '
1326
                +strings.as_tt(type_))
1327
            def wrap_func(col): return cast(db, type_, col, errors_table_)
1328
            mapping[out_col] = sql_gen.wrap(wrap_func, mapping[out_col])
1329
        except DatabaseErrors, e:
1330
            log_exc(e)
1331
            
1332
            log_debug('No handler for exception')
1333
            on_error(e)
1334
            remove_all_rows()
1335
        # after exception handled, rerun loop with additional constraints
1336
    
1337
    if row_ct_ref != None and cur.rowcount >= 0:
1338
        row_ct_ref[0] += cur.rowcount
1339
    
1340
    if has_joins:
1341
        select_joins = input_joins+[sql_gen.Join(out_table, join_cols)]
1342
        log_debug('Getting output table pkeys of existing/inserted rows')
1343
        insert_into_pkeys(select_joins, pkeys_cols)
1344
    else:
1345
        add_row_num(db, insert_out_pkeys) # for joining with input pkeys
1346
        
1347
        log_debug('Getting input table pkeys of inserted rows')
1348
        run_query_into(db, mk_main_select(input_joins, [in_pkey]),
1349
            into=insert_in_pkeys)
1350
        add_row_num(db, insert_in_pkeys) # for joining with output pkeys
1351
        
1352
        assert table_row_count(db, insert_out_pkeys) == table_row_count(db,
1353
            insert_in_pkeys)
1354
        
1355
        log_debug('Combining output and input pkeys in inserted order')
1356
        pkey_joins = [insert_in_pkeys, sql_gen.Join(insert_out_pkeys,
1357
            {row_num_col: sql_gen.join_same_not_null})]
1358
        insert_into_pkeys(pkey_joins, pkeys_names)
1359
    
1360
    db.log_debug('Adding pkey on pkeys table to enable fast joins', level=2.5)
1361
    add_pkey(db, into)
1362
    
1363
    log_debug('Setting pkeys of missing rows to '+strings.as_tt(repr(default)))
1364
    missing_rows_joins = input_joins+[sql_gen.Join(into,
1365
        {in_pkey: sql_gen.join_same_not_null}, sql_gen.filter_out)]
1366
        # must use join_same_not_null or query will take forever
1367
    insert_into_pkeys(missing_rows_joins,
1368
        [in_pkey_col, sql_gen.NamedCol(out_pkey, default)])
1369
    
1370
    assert table_row_count(db, into) == table_row_count(db, in_table)
1371
    
1372
    srcs = []
1373
    if is_func: srcs = sql_gen.cols_srcs(in_cols)
1374
    return sql_gen.Col(out_pkey, into, srcs)
1375

    
1376
##### Data cleanup
1377

    
1378
def cleanup_table(db, table, cols):
1379
    table = sql_gen.as_Table(table)
1380
    cols = map(sql_gen.as_Col, cols)
1381
    
1382
    expr = ('nullif(nullif(trim(both from %s), '+db.esc_value('')+'), '
1383
        +db.esc_value(r'\N')+')')
1384
    changes = [(v, sql_gen.CustomCode(expr % v.to_str(db)))
1385
        for v in cols]
1386
    
1387
    update(db, table, changes)
(24-24/36)