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

    
389
connect = DbConn
390

    
391
##### Recoverable querying
392

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

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

    
456
##### Basic queries
457

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

    
841
##### Database structure queries
842

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

    
847
def table_cols(db, table, recover=None):
848
    return list(col_names(select(db, table, limit=0, order_by=None,
849
        recover=recover, log_level=4)))
850

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

    
855
not_null_col = 'not_null_col'
856

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

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

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

    
920
row_num_col = '_row_num'
921

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

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

    
985
already_indexed = object() # tells add_indexes() the pkey has already been added
986

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

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

    
1006
def drop_table(db, table):
1007
    table = sql_gen.as_Table(table)
1008
    return run_query(db, 'DROP TABLE IF EXISTS '+table.to_str(db)+' CASCADE')
1009

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

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

    
1041
def truncate(db, table, schema='public'):
1042
    table = sql_gen.as_Table(table, schema)
1043
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE')
1044

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

    
1060
def table_exists(db, table):
1061
    table = sql_gen.as_Table(table)
1062
    return list(tables(db, table.schema, table.name, exact=True)) != []
1063

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

    
1076
##### Database management
1077

    
1078
def empty_db(db, schema='public', **kw_args):
1079
    '''For kw_args, see tables()'''
1080
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1081

    
1082
##### Heuristic queries
1083

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

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

    
1108
def is_func_result(col):
1109
    return col.table.name.find('(') >= 0 and col.name == 'result'
1110

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

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

    
1377
##### Data cleanup
1378

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