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 ExceptionWithNameType(DbException):
50
    def __init__(self, type_, name, cause=None):
51
        DbException.__init__(self, 'for type: '+strings.as_tt(str(type_))
52
            +'; name: '+strings.as_tt(name), cause)
53
        self.type = type_
54
        self.name = name
55

    
56
class ConstraintException(DbException):
57
    def __init__(self, name, cols, cause=None):
58
        DbException.__init__(self, 'Violated '+strings.as_tt(name)
59
            +' constraint on columns: '+strings.as_tt(', '.join(cols)), cause)
60
        self.name = name
61
        self.cols = cols
62

    
63
class MissingCastException(DbException):
64
    def __init__(self, type_, col, cause=None):
65
        DbException.__init__(self, 'Missing cast to type '+strings.as_tt(type_)
66
            +' on column: '+strings.as_tt(col), cause)
67
        self.type = type_
68
        self.col = col
69

    
70
class NameException(DbException): pass
71

    
72
class DuplicateKeyException(ConstraintException): pass
73

    
74
class NullValueException(ConstraintException): pass
75

    
76
class FunctionValueException(ExceptionWithNameValue): pass
77

    
78
class DuplicateException(ExceptionWithNameType): pass
79

    
80
class EmptyRowException(DbException): pass
81

    
82
##### Warnings
83

    
84
class DbWarning(UserWarning): pass
85

    
86
##### Result retrieval
87

    
88
def col_names(cur): return (col[0] for col in cur.description)
89

    
90
def rows(cur): return iter(lambda: cur.fetchone(), None)
91

    
92
def consume_rows(cur):
93
    '''Used to fetch all rows so result will be cached'''
94
    iters.consume_iter(rows(cur))
95

    
96
def next_row(cur): return rows(cur).next()
97

    
98
def row(cur):
99
    row_ = next_row(cur)
100
    consume_rows(cur)
101
    return row_
102

    
103
def next_value(cur): return next_row(cur)[0]
104

    
105
def value(cur): return row(cur)[0]
106

    
107
def values(cur): return iters.func_iter(lambda: next_value(cur))
108

    
109
def value_or_none(cur):
110
    try: return value(cur)
111
    except StopIteration: return None
112

    
113
##### Escaping
114

    
115
def esc_name_by_module(module, name):
116
    if module == 'psycopg2' or module == None: quote = '"'
117
    elif module == 'MySQLdb': quote = '`'
118
    else: raise NotImplementedError("Can't escape name for "+module+' database')
119
    return sql_gen.esc_name(name, quote)
120

    
121
def esc_name_by_engine(engine, name, **kw_args):
122
    return esc_name_by_module(db_engines[engine][0], name, **kw_args)
123

    
124
def esc_name(db, name, **kw_args):
125
    return esc_name_by_module(util.root_module(db.db), name, **kw_args)
126

    
127
def qual_name(db, schema, table):
128
    def esc_name_(name): return esc_name(db, name)
129
    table = esc_name_(table)
130
    if schema != None: return esc_name_(schema)+'.'+table
131
    else: return table
132

    
133
##### Database connections
134

    
135
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
136

    
137
db_engines = {
138
    'MySQL': ('MySQLdb', {'password': 'passwd', 'database': 'db'}),
139
    'PostgreSQL': ('psycopg2', {}),
140
}
141

    
142
DatabaseErrors_set = set([DbException])
143
DatabaseErrors = tuple(DatabaseErrors_set)
144

    
145
def _add_module(module):
146
    DatabaseErrors_set.add(module.DatabaseError)
147
    global DatabaseErrors
148
    DatabaseErrors = tuple(DatabaseErrors_set)
149

    
150
def db_config_str(db_config):
151
    return db_config['engine']+' database '+db_config['database']
152

    
153
log_debug_none = lambda msg, level=2: None
154

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

    
407
connect = DbConn
408

    
409
##### Recoverable querying
410

    
411
def with_savepoint(db, func): return db.with_savepoint(func)
412

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

    
473
##### Basic queries
474

    
475
def next_version(name):
476
    version = 1 # first existing name was version 0
477
    match = re.match(r'^(.*)#(\d+)$', name)
478
    if match:
479
        name, version = match.groups()
480
        version = int(version)+1
481
    return sql_gen.concat(name, '#'+str(version))
482

    
483
def lock_table(db, table, mode):
484
    table = sql_gen.as_Table(table)
485
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
486

    
487
def run_query_into(db, query, into=None, add_indexes_=False, **kw_args):
488
    '''Outputs a query to a temp table.
489
    For params, see run_query().
490
    '''
491
    if into == None: return run_query(db, query, **kw_args)
492
    
493
    assert isinstance(into, sql_gen.Table)
494
    
495
    kw_args['recover'] = True
496
    kw_args.setdefault('log_ignore_excs', (DuplicateException,))
497
    
498
    temp = not db.debug_temp # tables are permanent in debug_temp mode
499
    # "temporary tables cannot specify a schema name", so remove schema
500
    if temp: into.schema = None
501
    
502
    # Create table
503
    while True:
504
        create_query = 'CREATE'
505
        if temp: create_query += ' TEMP'
506
        create_query += ' TABLE '+into.to_str(db)+' AS\n'+query
507
        
508
        try:
509
            cur = run_query(db, create_query, **kw_args)
510
                # CREATE TABLE AS sets rowcount to # rows in query
511
            break
512
        except DuplicateException, e:
513
            into.name = next_version(into.name)
514
            # try again with next version of name
515
    
516
    if add_indexes_: add_indexes(db, into)
517
    
518
    return cur
519

    
520
order_by_pkey = object() # tells mk_select() to order by the pkey
521

    
522
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
523

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

    
605
def select(db, *args, **kw_args):
606
    '''For params, see mk_select() and run_query()'''
607
    recover = kw_args.pop('recover', None)
608
    cacheable = kw_args.pop('cacheable', True)
609
    log_level = kw_args.pop('log_level', 2)
610
    
611
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
612
        log_level=log_level)
613

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

    
670
def insert_select(db, *args, **kw_args):
671
    '''For params, see mk_insert_select() and run_query_into()
672
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
673
        values in
674
    '''
675
    into = kw_args.pop('into', None)
676
    if into != None: kw_args['embeddable'] = True
677
    recover = kw_args.pop('recover', None)
678
    cacheable = kw_args.pop('cacheable', True)
679
    log_level = kw_args.pop('log_level', 2)
680
    
681
    return run_query_into(db, mk_insert_select(db, *args, **kw_args), into,
682
        recover=recover, cacheable=cacheable, log_level=log_level)
683

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

    
686
def insert(db, table, row, *args, **kw_args):
687
    '''For params, see insert_select()'''
688
    if lists.is_seq(row): cols = None
689
    else:
690
        cols = row.keys()
691
        row = row.values()
692
    row = list(row) # ensure that "== []" works
693
    
694
    if row == []: query = None
695
    else: query = sql_gen.Values(row).to_str(db)
696
    
697
    return insert_select(db, table, cols, query, *args, **kw_args)
698

    
699
def mk_update(db, table, changes=None, cond=None):
700
    '''
701
    @param changes [(col, new_value),...]
702
        * container can be any iterable type
703
        * col: sql_gen.Code|str (for col name)
704
        * new_value: sql_gen.Code|literal value
705
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
706
    @return str query
707
    '''
708
    query = 'UPDATE '+sql_gen.as_Table(table).to_str(db)+'\nSET\n'
709
    query += ',\n'.join((sql_gen.to_name_only_col(col, table).to_str(db)+' = '
710
        +sql_gen.as_Value(new_value).to_str(db) for col, new_value in changes))
711
    if cond != None: query += '\nWHERE\n'+cond.to_str(db)
712
    
713
    return query
714

    
715
def update(db, *args, **kw_args):
716
    '''For params, see mk_update() and run_query()'''
717
    recover = kw_args.pop('recover', None)
718
    
719
    return run_query(db, mk_update(db, *args, **kw_args), recover)
720

    
721
def last_insert_id(db):
722
    module = util.root_module(db.db)
723
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
724
    elif module == 'MySQLdb': return db.insert_id()
725
    else: return None
726

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

    
759
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
760
    '''For params, see mk_flatten_mapping()
761
    @return See return value of mk_flatten_mapping()
762
    '''
763
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
764
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
765
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
766
        into=into, add_indexes_=True)
767
    return dict(items)
768

    
769
def mk_track_data_error(db, errors_table, cols, value, error_code, error):
770
    assert cols != ()
771
    
772
    cols = map(sql_gen.to_name_only_col, cols)
773
    
774
    columns_cols = ['column']
775
    columns = sql_gen.NamedValues('columns', columns_cols,
776
        [[c.name] for c in cols])
777
    values_cols = ['value', 'error_code', 'error']
778
    values = sql_gen.NamedValues('values', values_cols,
779
        [value, error_code, error])
780
    
781
    select_cols = columns_cols+values_cols
782
    name_only_cols = map(sql_gen.to_name_only_col, select_cols)
783
    errors_table = sql_gen.NamedTable('errors', errors_table)
784
    joins = [columns, sql_gen.Join(values, type_='CROSS'),
785
        sql_gen.Join(errors_table, dict(zip(name_only_cols, select_cols)),
786
        sql_gen.filter_out)]
787
    
788
    return mk_insert_select(db, errors_table, name_only_cols,
789
        mk_select(db, joins, select_cols, order_by=None))
790

    
791
def track_data_error(db, errors_table, cols, *args, **kw_args):
792
    '''
793
    @param errors_table If None, does nothing.
794
    '''
795
    if errors_table == None or cols == (): return
796
    run_query(db, mk_track_data_error(db, errors_table, cols, *args, **kw_args),
797
        cacheable=True, log_level=4)
798

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

    
856
##### Database structure queries
857

    
858
def table_row_count(db, table, recover=None):
859
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
860
        order_by=None, start=0), recover=recover, log_level=3))
861

    
862
def table_cols(db, table, recover=None):
863
    return list(col_names(select(db, table, limit=0, order_by=None,
864
        recover=recover, log_level=4)))
865

    
866
def pkey(db, table, recover=None):
867
    '''Assumed to be first column in table'''
868
    return table_cols(db, table, recover)[0]
869

    
870
not_null_col = 'not_null_col'
871

    
872
def table_not_null_col(db, table, recover=None):
873
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
874
    if not_null_col in table_cols(db, table, recover): return not_null_col
875
    else: return pkey(db, table, recover)
876

    
877
def index_cols(db, table, index):
878
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
879
    automatically created. When you don't know whether something is a UNIQUE
880
    constraint or a UNIQUE index, use this function.'''
881
    module = util.root_module(db.db)
882
    if module == 'psycopg2':
883
        return list(values(run_query(db, '''\
884
SELECT attname
885
FROM
886
(
887
        SELECT attnum, attname
888
        FROM pg_index
889
        JOIN pg_class index ON index.oid = indexrelid
890
        JOIN pg_class table_ ON table_.oid = indrelid
891
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
892
        WHERE
893
            table_.relname = '''+db.esc_value(table)+'''
894
            AND index.relname = '''+db.esc_value(index)+'''
895
    UNION
896
        SELECT attnum, attname
897
        FROM
898
        (
899
            SELECT
900
                indrelid
901
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
902
                    AS indkey
903
            FROM pg_index
904
            JOIN pg_class index ON index.oid = indexrelid
905
            JOIN pg_class table_ ON table_.oid = indrelid
906
            WHERE
907
                table_.relname = '''+db.esc_value(table)+'''
908
                AND index.relname = '''+db.esc_value(index)+'''
909
        ) s
910
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
911
) s
912
ORDER BY attnum
913
'''
914
            , cacheable=True, log_level=4)))
915
    else: raise NotImplementedError("Can't list index columns for "+module+
916
        ' database')
917

    
918
def constraint_cols(db, table, constraint):
919
    module = util.root_module(db.db)
920
    if module == 'psycopg2':
921
        return list(values(run_query(db, '''\
922
SELECT attname
923
FROM pg_constraint
924
JOIN pg_class ON pg_class.oid = conrelid
925
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
926
WHERE
927
    relname = '''+db.esc_value(table)+'''
928
    AND conname = '''+db.esc_value(constraint)+'''
929
ORDER BY attnum
930
'''
931
            )))
932
    else: raise NotImplementedError("Can't list constraint columns for "+module+
933
        ' database')
934

    
935
row_num_col = '_row_num'
936

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

    
986
def add_pkey(db, table, cols=None, recover=None):
987
    '''Adds a primary key.
988
    @param cols [sql_gen.Col,...] The columns in the primary key.
989
        Defaults to the first column in the table.
990
    @pre The table must not already have a primary key.
991
    '''
992
    table = sql_gen.as_Table(table)
993
    if cols == None: cols = [pkey(db, table, recover)]
994
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
995
    
996
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
997
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
998
        log_ignore_excs=(DuplicateException,))
999

    
1000
already_indexed = object() # tells add_indexes() the pkey has already been added
1001

    
1002
def add_indexes(db, table, has_pkey=True):
1003
    '''Adds an index on all columns in a table.
1004
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1005
        index should be added on the first column.
1006
        * If already_indexed, the pkey is assumed to have already been added
1007
    '''
1008
    cols = table_cols(db, table)
1009
    if has_pkey:
1010
        if has_pkey is not already_indexed: add_pkey(db, table)
1011
        cols = cols[1:]
1012
    for col in cols: add_index(db, col, table)
1013

    
1014
def add_col(db, table, col, **kw_args):
1015
    assert isinstance(col, sql_gen.TypedCol)
1016
    try: run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '
1017
        +col.to_str(db), recover=True, cacheable=True, **kw_args)
1018
    except DuplicateException: pass # column already existed
1019

    
1020
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1021
    constraints='PRIMARY KEY')
1022

    
1023
def add_row_num(db, table):
1024
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1025
    be the primary key.'''
1026
    add_col(db, table, row_num_typed_col, log_level=3)
1027

    
1028
def cast_temp_col(db, type_, col, errors_table=None):
1029
    '''Like cast(), but creates a new column with the cast values if the input
1030
    is a column.
1031
    @return The new column or cast value
1032
    '''
1033
    def cast_(col): return cast(db, type_, col, errors_table)
1034
    
1035
    try: col = sql_gen.underlying_col(col)
1036
    except sql_gen.NoUnderlyingTableException: return sql_gen.wrap(cast_, col)
1037
    
1038
    table = col.table
1039
    new_col = sql_gen.Col(sql_gen.concat(col.name, '::'+type_), table, col.srcs)
1040
    expr = cast_(col)
1041
    add_col(db, table, sql_gen.TypedCol(new_col.name, type_))
1042
    update(db, table, [(new_col, expr)])
1043
    
1044
    return new_col
1045

    
1046
def drop_table(db, table):
1047
    table = sql_gen.as_Table(table)
1048
    return run_query(db, 'DROP TABLE IF EXISTS '+table.to_str(db)+' CASCADE')
1049

    
1050
def create_table(db, table, cols, has_pkey=True, col_indexes=True):
1051
    '''Creates a table.
1052
    @param cols [sql_gen.TypedCol,...] The column names and types
1053
    @param has_pkey If set, the first column becomes the primary key.
1054
    @param col_indexes bool|[ref]
1055
        * If True, indexes will be added on all non-pkey columns.
1056
        * If a list reference, [0] will be set to a function to do this.
1057
          This can be used to delay index creation until the table is populated.
1058
    '''
1059
    table = sql_gen.as_Table(table)
1060
    
1061
    if has_pkey:
1062
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1063
        pkey.constraints = 'PRIMARY KEY'
1064
    
1065
    str_ = 'CREATE TABLE '+table.to_str(db)+' (\n'
1066
    str_ += '\n, '.join(v.to_str(db) for v in cols)
1067
    str_ += '\n);\n'
1068
    run_query(db, str_, cacheable=True, log_level=2)
1069
    
1070
    # Add indexes
1071
    if has_pkey: has_pkey = already_indexed
1072
    def add_indexes_(): add_indexes(db, table, has_pkey)
1073
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1074
    elif col_indexes: add_indexes_() # add now
1075

    
1076
def vacuum(db, table):
1077
    table = sql_gen.as_Table(table)
1078
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1079
        log_level=3))
1080

    
1081
def truncate(db, table, schema='public'):
1082
    table = sql_gen.as_Table(table, schema)
1083
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE')
1084

    
1085
def tables(db, schema_like='public', table_like='%', exact=False):
1086
    if exact: compare = '='
1087
    else: compare = 'LIKE'
1088
    
1089
    module = util.root_module(db.db)
1090
    if module == 'psycopg2':
1091
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1092
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1093
        return values(select(db, 'pg_tables', ['tablename'], conds,
1094
            order_by='tablename', log_level=4))
1095
    elif module == 'MySQLdb':
1096
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1097
            , cacheable=True, log_level=4))
1098
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1099

    
1100
def table_exists(db, table):
1101
    table = sql_gen.as_Table(table)
1102
    return list(tables(db, table.schema, table.name, exact=True)) != []
1103

    
1104
def function_exists(db, function):
1105
    function = sql_gen.as_Function(function)
1106
    
1107
    info_table = sql_gen.Table('routines', 'information_schema')
1108
    conds = [('routine_name', function.name)]
1109
    schema = function.schema
1110
    if schema != None: conds.append(('routine_schema', schema))
1111
    # Exclude trigger functions, since they cannot be called directly
1112
    conds.append(('data_type', sql_gen.CompareCond('trigger', '!=')))
1113
    
1114
    return list(values(select(db, info_table, ['routine_name'], conds,
1115
        order_by='routine_schema', limit=1, log_level=4))) != []
1116
        # TODO: order_by search_path schema order
1117

    
1118
def errors_table(db, table, if_exists=True):
1119
    '''
1120
    @param if_exists If set, returns None if the errors table doesn't exist
1121
    @return None|sql_gen.Table
1122
    '''
1123
    table = sql_gen.as_Table(table)
1124
    if table.srcs != (): table = table.srcs[0]
1125
    
1126
    errors_table = sql_gen.suffixed_table(table, '.errors')
1127
    if if_exists and not table_exists(db, errors_table): return None
1128
    return errors_table
1129

    
1130
##### Database management
1131

    
1132
def empty_db(db, schema='public', **kw_args):
1133
    '''For kw_args, see tables()'''
1134
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1135

    
1136
##### Heuristic queries
1137

    
1138
def put(db, table, row, pkey_=None, row_ct_ref=None):
1139
    '''Recovers from errors.
1140
    Only works under PostgreSQL (uses INSERT RETURNING).
1141
    '''
1142
    row = sql_gen.ColDict(db, table, row)
1143
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
1144
    
1145
    try:
1146
        cur = insert(db, table, row, pkey_, recover=True)
1147
        if row_ct_ref != None and cur.rowcount >= 0:
1148
            row_ct_ref[0] += cur.rowcount
1149
        return value(cur)
1150
    except DuplicateKeyException, e:
1151
        row = sql_gen.ColDict(db, table,
1152
            util.dict_subset_right_join(row, e.cols))
1153
        return value(select(db, table, [pkey_], row, recover=True))
1154

    
1155
def get(db, table, row, pkey, row_ct_ref=None, create=False):
1156
    '''Recovers from errors'''
1157
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
1158
    except StopIteration:
1159
        if not create: raise
1160
        return put(db, table, row, pkey, row_ct_ref) # insert new row
1161

    
1162
def is_func_result(col):
1163
    return col.table.name.find('(') >= 0 and col.name == 'result'
1164

    
1165
def into_table_name(out_table, in_tables0, mapping, is_func):
1166
    def in_col_str(in_col):
1167
        in_col = sql_gen.remove_col_rename(in_col)
1168
        if isinstance(in_col, sql_gen.Col):
1169
            table = in_col.table
1170
            if table == in_tables0:
1171
                in_col = sql_gen.to_name_only_col(in_col)
1172
            elif is_func_result(in_col): in_col = table # omit col name
1173
        return str(in_col)
1174
    
1175
    str_ = str(out_table)
1176
    if is_func:
1177
        str_ += '('
1178
        
1179
        try: value_in_col = mapping['value']
1180
        except KeyError:
1181
            str_ += ', '.join((str(k)+'='+in_col_str(v)
1182
                for k, v in mapping.iteritems()))
1183
        else: str_ += in_col_str(value_in_col)
1184
        
1185
        str_ += ')'
1186
    else:
1187
        out_col = 'rank'
1188
        try: in_col = mapping[out_col]
1189
        except KeyError: str_ += '_pkeys'
1190
        else: # has a rank column, so hierarchical
1191
            str_ += '['+str(out_col)+'='+in_col_str(in_col)+']'
1192
    return str_
1193

    
1194
def put_table(db, out_table, in_tables, mapping, row_ct_ref=None, into=None,
1195
    default=None, is_func=False, on_error=exc.raise_):
1196
    '''Recovers from errors.
1197
    Only works under PostgreSQL (uses INSERT RETURNING).
1198
    IMPORTANT: Must be run at the *beginning* of a transaction.
1199
    @param in_tables The main input table to select from, followed by a list of
1200
        tables to join with it using the main input table's pkey
1201
    @param mapping dict(out_table_col=in_table_col, ...)
1202
        * out_table_col: str (*not* sql_gen.Col)
1203
        * in_table_col: sql_gen.Col|literal-value
1204
    @param into The table to contain the output and input pkeys.
1205
        Defaults to `out_table.name+'_pkeys'`.
1206
    @param default The *output* column to use as the pkey for missing rows.
1207
        If this output column does not exist in the mapping, uses None.
1208
    @param is_func Whether out_table is the name of a SQL function, not a table
1209
    @return sql_gen.Col Where the output pkeys are made available
1210
    '''
1211
    out_table = sql_gen.as_Table(out_table)
1212
    
1213
    def log_debug(msg): db.log_debug(msg, level=1.5)
1214
    def col_ustr(str_):
1215
        return strings.repr_no_u(sql_gen.remove_col_rename(str_))
1216
    
1217
    log_debug('********** New iteration **********')
1218
    log_debug('Inserting these input columns into '+strings.as_tt(
1219
        out_table.to_str(db))+':\n'+strings.as_table(mapping, ustr=col_ustr))
1220
    
1221
    is_function = function_exists(db, out_table)
1222
    
1223
    if is_function: out_pkey = 'result'
1224
    else: out_pkey = pkey(db, out_table, recover=True)
1225
    out_pkey_col = sql_gen.as_Col(out_pkey, out_table)
1226
    
1227
    if mapping == {}: # need at least one column for INSERT SELECT
1228
        mapping = {out_pkey: None} # ColDict will replace with default value
1229
    
1230
    # Create input joins from list of input tables
1231
    in_tables_ = in_tables[:] # don't modify input!
1232
    in_tables0 = in_tables_.pop(0) # first table is separate
1233
    errors_table_ = errors_table(db, in_tables0)
1234
    in_pkey = pkey(db, in_tables0, recover=True)
1235
    in_pkey_col = sql_gen.as_Col(in_pkey, in_tables0)
1236
    input_joins = [in_tables0]+[sql_gen.Join(v,
1237
        {in_pkey: sql_gen.join_same_not_null}) for v in in_tables_]
1238
    
1239
    if into == None:
1240
        into = into_table_name(out_table, in_tables0, mapping, is_func)
1241
    into = sql_gen.as_Table(into)
1242
    
1243
    # Set column sources
1244
    in_cols = filter(sql_gen.is_table_col, mapping.values())
1245
    for col in in_cols:
1246
        if col.table == in_tables0: col.set_srcs(sql_gen.src_self)
1247
    
1248
    log_debug('Joining together input tables into temp table')
1249
    # Place in new table for speed and so don't modify input if values edited
1250
    in_table = sql_gen.Table('in')
1251
    mapping = dicts.join(mapping, flatten(db, in_table, input_joins, in_cols,
1252
        preserve=[in_pkey_col], start=0))
1253
    input_joins = [in_table]
1254
    db.log_debug('Temp table: '+strings.as_tt(in_table.to_str(db)), level=2)
1255
    
1256
    mapping = sql_gen.ColDict(db, out_table, mapping)
1257
        # after applying dicts.join() because that returns a plain dict
1258
    
1259
    # Resolve default value column
1260
    if default != None:
1261
        try: default = mapping[default]
1262
        except KeyError:
1263
            db.log_debug('Default value column '
1264
                +strings.as_tt(strings.repr_no_u(default))
1265
                +' does not exist in mapping, falling back to None', level=2.1)
1266
            default = None
1267
    
1268
    pkeys_names = [in_pkey, out_pkey]
1269
    pkeys_cols = [in_pkey_col, out_pkey_col]
1270
    
1271
    pkeys_table_exists_ref = [False]
1272
    def insert_into_pkeys(joins, cols):
1273
        query = mk_select(db, joins, cols, order_by=None, start=0)
1274
        if pkeys_table_exists_ref[0]:
1275
            insert_select(db, into, pkeys_names, query)
1276
        else:
1277
            run_query_into(db, query, into=into)
1278
            pkeys_table_exists_ref[0] = True
1279
    
1280
    limit_ref = [None]
1281
    conds = set()
1282
    distinct_on = sql_gen.ColDict(db, out_table)
1283
    def mk_main_select(joins, cols):
1284
        distinct_on_cols = [c.to_Col() for c in distinct_on.values()]
1285
        return mk_select(db, joins, cols, conds, distinct_on_cols,
1286
            limit=limit_ref[0], start=0)
1287
    
1288
    exc_strs = set()
1289
    def log_exc(e):
1290
        e_str = exc.str_(e, first_line_only=True)
1291
        log_debug('Caught exception: '+e_str)
1292
        assert e_str not in exc_strs # avoid infinite loops
1293
        exc_strs.add(e_str)
1294
    
1295
    def remove_all_rows():
1296
        log_debug('Ignoring all rows')
1297
        limit_ref[0] = 0 # just create an empty pkeys table
1298
    
1299
    def ignore(in_col, value, e):
1300
        track_data_error(db, errors_table_, in_col.srcs, value, e.cause.pgcode,
1301
            e.cause.pgerror)
1302
        log_debug('Ignoring rows with '+strings.as_tt(repr(in_col))+' = '
1303
            +strings.as_tt(repr(value)))
1304
    
1305
    def remove_rows(in_col, value, e):
1306
        ignore(in_col, value, e)
1307
        cond = (in_col, sql_gen.CompareCond(value, '!='))
1308
        assert cond not in conds # avoid infinite loops
1309
        conds.add(cond)
1310
    
1311
    def invalid2null(in_col, value, e):
1312
        ignore(in_col, value, e)
1313
        update(db, in_table, [(in_col, None)],
1314
            sql_gen.ColValueCond(in_col, value))
1315
    
1316
    def insert_pkeys_table(which):
1317
        return sql_gen.Table(sql_gen.concat(in_table.name,
1318
            '_insert_'+which+'_pkeys'))
1319
    insert_out_pkeys = insert_pkeys_table('out')
1320
    insert_in_pkeys = insert_pkeys_table('in')
1321
    
1322
    # Do inserts and selects
1323
    join_cols = sql_gen.ColDict(db, out_table)
1324
    while True:
1325
        if limit_ref[0] == 0: # special case
1326
            log_debug('Creating an empty pkeys table')
1327
            cur = run_query_into(db, mk_select(db, out_table, [out_pkey],
1328
                limit=limit_ref[0]), into=insert_out_pkeys)
1329
            break # don't do main case
1330
        
1331
        has_joins = join_cols != {}
1332
        
1333
        log_debug('Trying to insert new rows')
1334
        
1335
        # Prepare to insert new rows
1336
        insert_joins = input_joins[:] # don't modify original!
1337
        insert_args = dict(recover=True, cacheable=False)
1338
        if has_joins:
1339
            insert_joins.append(sql_gen.Join(out_table, join_cols,
1340
                sql_gen.filter_out))
1341
        else:
1342
            insert_args.update(dict(returning=out_pkey, into=insert_out_pkeys))
1343
        main_select = mk_main_select(insert_joins, mapping.values())
1344
        
1345
        def main_insert():
1346
            if is_function:
1347
                log_debug('Calling function on input rows')
1348
                args = dict(((k.name, v) for k, v in mapping.iteritems()))
1349
                func_call = sql_gen.NamedCol(out_pkey,
1350
                    sql_gen.FunctionCall(out_table, **args))
1351
                insert_into_pkeys(input_joins, [in_pkey_col, func_call])
1352
                return None
1353
            else:
1354
                lock_table(db, out_table, 'EXCLUSIVE')
1355
                return insert_select(db, out_table, mapping.keys(), main_select,
1356
                    **insert_args)
1357
        
1358
        try:
1359
            cur = with_savepoint(db, main_insert)
1360
            break # insert successful
1361
        except MissingCastException, e:
1362
            log_exc(e)
1363
            
1364
            out_col = e.col
1365
            type_ = e.type
1366
            
1367
            log_debug('Casting '+strings.as_tt(out_col)+' input to '
1368
                +strings.as_tt(type_))
1369
            mapping[out_col] = cast_temp_col(db, type_, mapping[out_col],
1370
                errors_table_)
1371
        except DuplicateKeyException, e:
1372
            log_exc(e)
1373
            
1374
            old_join_cols = join_cols.copy()
1375
            distinct_on.update(util.dict_subset(mapping, e.cols))
1376
            join_cols.update(util.dict_subset_right_join(mapping, e.cols))
1377
            log_debug('Ignoring existing rows, comparing on these columns:\n'
1378
                +strings.as_inline_table(join_cols, ustr=col_ustr))
1379
            assert join_cols != old_join_cols # avoid infinite loops
1380
        except NullValueException, e:
1381
            log_exc(e)
1382
            
1383
            out_col, = e.cols
1384
            try: in_col = mapping[out_col]
1385
            except KeyError:
1386
                log_debug('Missing mapping for NOT NULL column '+out_col)
1387
                remove_all_rows()
1388
            else: remove_rows(in_col, None, e)
1389
        except FunctionValueException, e:
1390
            log_exc(e)
1391
            
1392
            func_name = e.name
1393
            value = e.value
1394
            for out_col, in_col in mapping.iteritems():
1395
                in_col = sql_gen.unwrap_func_call(in_col, func_name)
1396
                invalid2null(in_col, value, e)
1397
        except DatabaseErrors, e:
1398
            log_exc(e)
1399
            
1400
            log_debug('No handler for exception')
1401
            on_error(e)
1402
            remove_all_rows()
1403
        # after exception handled, rerun loop with additional constraints
1404
    
1405
    if cur != None and row_ct_ref != None and cur.rowcount >= 0:
1406
        row_ct_ref[0] += cur.rowcount
1407
    
1408
    if is_function: pass # pkeys table already created
1409
    elif has_joins:
1410
        select_joins = input_joins+[sql_gen.Join(out_table, join_cols)]
1411
        log_debug('Getting output table pkeys of existing/inserted rows')
1412
        insert_into_pkeys(select_joins, pkeys_cols)
1413
    else:
1414
        add_row_num(db, insert_out_pkeys) # for joining with input pkeys
1415
        
1416
        log_debug('Getting input table pkeys of inserted rows')
1417
        run_query_into(db, mk_main_select(input_joins, [in_pkey]),
1418
            into=insert_in_pkeys)
1419
        add_row_num(db, insert_in_pkeys) # for joining with output pkeys
1420
        
1421
        assert table_row_count(db, insert_out_pkeys) == table_row_count(db,
1422
            insert_in_pkeys)
1423
        
1424
        log_debug('Combining output and input pkeys in inserted order')
1425
        pkey_joins = [insert_in_pkeys, sql_gen.Join(insert_out_pkeys,
1426
            {row_num_col: sql_gen.join_same_not_null})]
1427
        insert_into_pkeys(pkey_joins, pkeys_names)
1428
    
1429
    db.log_debug('Adding pkey on pkeys table to enable fast joins', level=2.5)
1430
    add_pkey(db, into)
1431
    
1432
    log_debug('Setting pkeys of missing rows to '+strings.as_tt(repr(default)))
1433
    missing_rows_joins = input_joins+[sql_gen.Join(into,
1434
        {in_pkey: sql_gen.join_same_not_null}, sql_gen.filter_out)]
1435
        # must use join_same_not_null or query will take forever
1436
    insert_into_pkeys(missing_rows_joins,
1437
        [in_pkey_col, sql_gen.NamedCol(out_pkey, default)])
1438
    
1439
    assert table_row_count(db, into) == table_row_count(db, in_table)
1440
    
1441
    srcs = []
1442
    if is_func: srcs = sql_gen.cols_srcs(in_cols)
1443
    return sql_gen.Col(out_pkey, into, srcs)
1444

    
1445
##### Data cleanup
1446

    
1447
def cleanup_table(db, table, cols):
1448
    table = sql_gen.as_Table(table)
1449
    cols = map(sql_gen.as_Col, cols)
1450
    
1451
    expr = ('nullif(nullif(trim(both from %s), '+db.esc_value('')+'), '
1452
        +db.esc_value(r'\N')+')')
1453
    changes = [(v, sql_gen.CustomCode(expr % v.to_str(db)))
1454
        for v in cols]
1455
    
1456
    update(db, table, changes)
(24-24/36)