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
            
238
            # Always cache certain queries
239
            if query.startswith('CREATE') or query.startswith('ALTER'):
240
                # structural changes
241
                # Rest of query must be unique in the face of name collisions,
242
                # so don't cache ADD COLUMN unless it has distinguishing comment
243
                if query.find('ADD COLUMN') < 0 or query.endswith('*/'):
244
                    self._cache_result()
245
            elif self.rowcount == 0 and query.startswith('SELECT'): # empty
246
                consume_rows(self) # fetch all rows so result will be cached
247
            
248
            return cur
249
        
250
        def fetchone(self):
251
            row = self.inner.fetchone()
252
            if row != None: self.result.append(row)
253
            # otherwise, fetched all rows
254
            else: self._cache_result()
255
            return row
256
        
257
        def _cache_result(self):
258
            # For inserts that return a result set, don't cache result set since
259
            # inserts are not idempotent. Other non-SELECT queries don't have
260
            # their result set read, so only exceptions will be cached (an
261
            # invalid query will always be invalid).
262
            if self.query_results != None and (not self._is_insert
263
                or isinstance(self.result, Exception)):
264
                
265
                assert self.query_lookup != None
266
                self.query_results[self.query_lookup] = self.CacheCursor(
267
                    util.dict_subset(dicts.AttrsDictView(self),
268
                    ['query', 'result', 'rowcount', 'description']))
269
        
270
        class CacheCursor:
271
            def __init__(self, cached_result): self.__dict__ = cached_result
272
            
273
            def execute(self, *args, **kw_args):
274
                if isinstance(self.result, Exception): raise self.result
275
                # otherwise, result is a rows list
276
                self.iter = iter(self.result)
277
            
278
            def fetchone(self):
279
                try: return self.iter.next()
280
                except StopIteration: return None
281
    
282
    def esc_value(self, value):
283
        try: str_ = self.mogrify('%s', [value])
284
        except NotImplementedError, e:
285
            module = util.root_module(self.db)
286
            if module == 'MySQLdb':
287
                import _mysql
288
                str_ = _mysql.escape_string(value)
289
            else: raise e
290
        return strings.to_unicode(str_)
291
    
292
    def esc_name(self, name): return esc_name(self, name) # calls global func
293
    
294
    def std_code(self, str_):
295
        '''Standardizes SQL code.
296
        * Ensures that string literals are prefixed by `E`
297
        '''
298
        if str_.startswith("'"): str_ = 'E'+str_
299
        return str_
300
    
301
    def can_mogrify(self):
302
        module = util.root_module(self.db)
303
        return module == 'psycopg2'
304
    
305
    def mogrify(self, query, params=None):
306
        if self.can_mogrify(): return self.db.cursor().mogrify(query, params)
307
        else: raise NotImplementedError("Can't mogrify query")
308
    
309
    def print_notices(self):
310
        if hasattr(self.db, 'notices'):
311
            for msg in self.db.notices:
312
                if msg not in self._notices_seen:
313
                    self._notices_seen.add(msg)
314
                    self.log_debug(msg, level=2)
315
    
316
    def run_query(self, query, cacheable=False, log_level=2,
317
        debug_msg_ref=None):
318
        '''
319
        @param log_ignore_excs The log_level will be increased by 2 if the query
320
            throws one of these exceptions.
321
        @param debug_msg_ref If specified, the log message will be returned in
322
            this instead of being output. This allows you to filter log messages
323
            depending on the result of the query.
324
        '''
325
        assert query != None
326
        
327
        if not self.caching: cacheable = False
328
        used_cache = False
329
        
330
        def log_msg(query):
331
            if used_cache: cache_status = 'cache hit'
332
            elif cacheable: cache_status = 'cache miss'
333
            else: cache_status = 'non-cacheable'
334
            return 'DB query: '+cache_status+':\n'+strings.as_code(query, 'SQL')
335
        
336
        try:
337
            # Get cursor
338
            if cacheable:
339
                try:
340
                    cur = self.query_results[query]
341
                    used_cache = True
342
                except KeyError: cur = self.DbCursor(self)
343
            else: cur = self.db.cursor()
344
            
345
            # Log query
346
            if self.debug and debug_msg_ref == None: # log before running
347
                self.log_debug(log_msg(query), log_level)
348
            
349
            # Run query
350
            cur.execute(query)
351
        finally:
352
            self.print_notices()
353
            if self.debug and debug_msg_ref != None: # return after running
354
                debug_msg_ref[0] = log_msg(str(get_cur_query(cur, query)))
355
        
356
        return cur
357
    
358
    def is_cached(self, query): return query in self.query_results
359
    
360
    def with_autocommit(self, func):
361
        import psycopg2.extensions
362
        
363
        prev_isolation_level = self.db.isolation_level
364
        self.db.set_isolation_level(
365
            psycopg2.extensions.ISOLATION_LEVEL_AUTOCOMMIT)
366
        try: return func()
367
        finally: self.db.set_isolation_level(prev_isolation_level)
368
    
369
    def with_savepoint(self, func):
370
        savepoint = 'level_'+str(self._savepoint)
371
        self.run_query('SAVEPOINT '+savepoint, log_level=4)
372
        self._savepoint += 1
373
        try: return func()
374
        except:
375
            self.run_query('ROLLBACK TO SAVEPOINT '+savepoint, log_level=4)
376
            raise
377
        finally:
378
            # Always release savepoint, because after ROLLBACK TO SAVEPOINT,
379
            # "The savepoint remains valid and can be rolled back to again"
380
            # (http://www.postgresql.org/docs/8.3/static/sql-rollback-to.html).
381
            self.run_query('RELEASE SAVEPOINT '+savepoint, log_level=4)
382
            
383
            self._savepoint -= 1
384
            assert self._savepoint >= 0
385
            
386
            self.do_autocommit() # OK to do this after ROLLBACK TO SAVEPOINT
387
    
388
    def do_autocommit(self):
389
        '''Autocommits if outside savepoint'''
390
        assert self._savepoint >= 0
391
        if self.autocommit and self._savepoint == 0:
392
            self.log_debug('Autocommitting', level=4)
393
            self.db.commit()
394
    
395
    def col_info(self, col):
396
        table = sql_gen.Table('columns', 'information_schema')
397
        type_ = sql_gen.Coalesce(sql_gen.Nullif(sql_gen.Col('data_type'),
398
            'USER-DEFINED'), sql_gen.Col('udt_name'))
399
        cols = [type_, 'column_default', cast(self, 'boolean', 'is_nullable')]
400
        
401
        conds = [('table_name', col.table.name), ('column_name', col.name)]
402
        schema = col.table.schema
403
        if schema != None: conds.append(('table_schema', schema))
404
        
405
        type_, default, nullable = row(select(self, table, cols, conds,
406
            order_by='table_schema', limit=1, cacheable=False, log_level=4))
407
            # TODO: order_by search_path schema order
408
        default = sql_gen.as_Code(default, self)
409
        
410
        return sql_gen.TypedCol(col.name, type_, default, nullable)
411
    
412
    def TempFunction(self, name):
413
        if self.debug_temp: schema = None
414
        else: schema = 'pg_temp'
415
        return sql_gen.Function(name, schema)
416

    
417
connect = DbConn
418

    
419
##### Recoverable querying
420

    
421
def with_savepoint(db, func): return db.with_savepoint(func)
422

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

    
484
##### Basic queries
485

    
486
def next_version(name):
487
    version = 1 # first existing name was version 0
488
    match = re.match(r'^(.*)#(\d+)$', name)
489
    if match:
490
        name, version = match.groups()
491
        version = int(version)+1
492
    return sql_gen.concat(name, '#'+str(version))
493

    
494
def lock_table(db, table, mode):
495
    table = sql_gen.as_Table(table)
496
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
497

    
498
def run_query_into(db, query, into=None, add_indexes_=False, **kw_args):
499
    '''Outputs a query to a temp table.
500
    For params, see run_query().
501
    '''
502
    if into == None: return run_query(db, query, **kw_args)
503
    
504
    assert isinstance(into, sql_gen.Table)
505
    
506
    into.is_temp = True
507
    # "temporary tables cannot specify a schema name", so remove schema
508
    into.schema = None
509
    
510
    kw_args['recover'] = True
511
    kw_args.setdefault('log_ignore_excs', (DuplicateException,))
512
    
513
    temp = not db.debug_temp # tables are permanent in debug_temp mode
514
    
515
    # Create table
516
    while True:
517
        create_query = 'CREATE'
518
        if temp: create_query += ' TEMP'
519
        create_query += ' TABLE '+into.to_str(db)+' AS\n'+query
520
        
521
        try:
522
            cur = run_query(db, create_query, **kw_args)
523
                # CREATE TABLE AS sets rowcount to # rows in query
524
            break
525
        except DuplicateException, e:
526
            into.name = next_version(into.name)
527
            # try again with next version of name
528
    
529
    if add_indexes_: add_indexes(db, into)
530
    analyze(db, into)
531
    
532
    return cur
533

    
534
order_by_pkey = object() # tells mk_select() to order by the pkey
535

    
536
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
537

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

    
621
def select(db, *args, **kw_args):
622
    '''For params, see mk_select() and run_query()'''
623
    recover = kw_args.pop('recover', None)
624
    cacheable = kw_args.pop('cacheable', True)
625
    log_level = kw_args.pop('log_level', 2)
626
    
627
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
628
        log_level=log_level)
629

    
630
def mk_insert_select(db, table, cols=None, select_query=None, returning=None,
631
    embeddable=False, ignore=False):
632
    '''
633
    @param returning str|None An inserted column (such as pkey) to return
634
    @param embeddable Whether the query should be embeddable as a nested SELECT.
635
        Warning: If you set this and cacheable=True when the query is run, the
636
        query will be fully cached, not just if it raises an exception.
637
    @param ignore Whether to ignore duplicate keys.
638
    '''
639
    table = sql_gen.remove_table_rename(sql_gen.as_Table(table))
640
    if cols == []: cols = None # no cols (all defaults) = unknown col names
641
    if cols != None: cols = [sql_gen.to_name_only_col(c, table) for c in cols]
642
    if select_query == None: select_query = 'DEFAULT VALUES'
643
    if returning != None: returning = sql_gen.as_Col(returning, table)
644
    
645
    first_line = 'INSERT INTO '+table.to_str(db)
646
    
647
    def mk_insert(select_query):
648
        query = first_line
649
        if cols != None:
650
            query += '\n('+(', '.join((c.to_str(db) for c in cols)))+')'
651
        query += '\n'+select_query
652
        
653
        if returning != None:
654
            returning_name_col = sql_gen.to_name_only_col(returning)
655
            query += '\nRETURNING '+returning_name_col.to_str(db)
656
        
657
        return query
658
    
659
    return_type = 'unknown'
660
    if returning != None: return_type = returning.to_str(db)+'%TYPE'
661
    
662
    lang = 'sql'
663
    if ignore:
664
        assert cols != None
665
        # Always return something to set the correct rowcount
666
        if returning == None: returning = sql_gen.NamedCol('NULL', None)
667
        
668
        embeddable = True # must use function
669
        lang = 'plpgsql'
670
        row = [sql_gen.Col(c.name, 'row') for c in cols]
671
        
672
        query = '''\
673
DECLARE
674
    row '''+table.to_str(db)+'''%ROWTYPE;
675
BEGIN
676
    /* Need an EXCEPTION block for each individual row because "When an error is
677
    caught by an EXCEPTION clause, [...] all changes to persistent database
678
    state within the block are rolled back."
679
    This is unfortunate because "A block containing an EXCEPTION clause is
680
    significantly more expensive to enter and exit than a block without one."
681
    (http://www.postgresql.org/docs/8.3/static/plpgsql-control-structures.html\
682
#PLPGSQL-ERROR-TRAPPING)
683
    */
684
    FOR '''+(', '.join((c.to_str(db) for c in row)))+''' IN
685
'''+select_query+'''
686
    LOOP
687
        BEGIN
688
            RETURN QUERY
689
'''+mk_insert(sql_gen.Values(row).to_str(db))+'''
690
;
691
        EXCEPTION
692
            WHEN unique_violation THEN NULL; -- continue to next row
693
        END;
694
    END LOOP;
695
END;\
696
'''
697
    else: query = mk_insert(select_query)
698
    
699
    if embeddable:
700
        # Create function
701
        function_name = sql_gen.clean_name(first_line)
702
        while True:
703
            try:
704
                function = db.TempFunction(function_name)
705
                
706
                function_query = '''\
707
CREATE FUNCTION '''+function.to_str(db)+'''()
708
RETURNS SETOF '''+return_type+'''
709
LANGUAGE '''+lang+'''
710
AS $$
711
'''+query+'''
712
$$;
713
'''
714
                run_query(db, function_query, recover=True, cacheable=True,
715
                    log_ignore_excs=(DuplicateException,))
716
                break # this version was successful
717
            except DuplicateException, e:
718
                function_name = next_version(function_name)
719
                # try again with next version of name
720
        
721
        # Return query that uses function
722
        cols = None
723
        if returning != None: cols = [returning]
724
        func_table = sql_gen.NamedTable('f', sql_gen.FunctionCall(function),
725
            cols) # AS clause requires function alias
726
        return mk_select(db, func_table, start=0, order_by=None)
727
    
728
    return query
729

    
730
def insert_select(db, *args, **kw_args):
731
    '''For params, see mk_insert_select() and run_query_into()
732
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
733
        values in
734
    '''
735
    into = kw_args.pop('into', None)
736
    if into != None: kw_args['embeddable'] = True
737
    recover = kw_args.pop('recover', None)
738
    if kw_args.get('ignore', False): recover = True
739
    cacheable = kw_args.pop('cacheable', True)
740
    log_level = kw_args.pop('log_level', 2)
741
    
742
    return run_query_into(db, mk_insert_select(db, *args, **kw_args), into,
743
        recover=recover, cacheable=cacheable, log_level=log_level)
744

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

    
747
def insert(db, table, row, *args, **kw_args):
748
    '''For params, see insert_select()'''
749
    if lists.is_seq(row): cols = None
750
    else:
751
        cols = row.keys()
752
        row = row.values()
753
    row = list(row) # ensure that "== []" works
754
    
755
    if row == []: query = None
756
    else: query = sql_gen.Values(row).to_str(db)
757
    
758
    return insert_select(db, table, cols, query, *args, **kw_args)
759

    
760
def mk_update(db, table, changes=None, cond=None, in_place=False):
761
    '''
762
    @param changes [(col, new_value),...]
763
        * container can be any iterable type
764
        * col: sql_gen.Code|str (for col name)
765
        * new_value: sql_gen.Code|literal value
766
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
767
    @param in_place If set, locks the table and updates rows in place.
768
        This avoids creating dead rows in PostgreSQL.
769
        * cond must be None
770
    @return str query
771
    '''
772
    table = sql_gen.as_Table(table)
773
    changes = [(sql_gen.to_name_only_col(c, table), sql_gen.as_Value(v))
774
        for c, v in changes]
775
    
776
    if in_place:
777
        assert cond == None
778
        
779
        query = 'ALTER TABLE '+table.to_str(db)+'\n'
780
        query += ',\n'.join(('ALTER COLUMN '+c.to_str(db)+' TYPE '
781
            +db.col_info(sql_gen.with_default_table(c, table)).type
782
            +'\nUSING '+v.to_str(db) for c, v in changes))
783
    else:
784
        query = 'UPDATE '+table.to_str(db)+'\nSET\n'
785
        query += ',\n'.join((c.to_str(db)+' = '+v.to_str(db)
786
            for c, v in changes))
787
        if cond != None: query += '\nWHERE\n'+cond.to_str(db)
788
    
789
    return query
790

    
791
def update(db, *args, **kw_args):
792
    '''For params, see mk_update() and run_query()'''
793
    recover = kw_args.pop('recover', None)
794
    cacheable = kw_args.pop('cacheable', False)
795
    log_level = kw_args.pop('log_level', 2)
796
    
797
    return run_query(db, mk_update(db, *args, **kw_args), recover, cacheable,
798
        log_level=log_level)
799

    
800
def last_insert_id(db):
801
    module = util.root_module(db.db)
802
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
803
    elif module == 'MySQLdb': return db.insert_id()
804
    else: return None
805

    
806
def mk_flatten_mapping(db, into, cols, preserve=[], as_items=False):
807
    '''Creates a mapping from original column names (which may have collisions)
808
    to names that will be distinct among the columns' tables.
809
    This is meant to be used for several tables that are being joined together.
810
    @param cols The columns to combine. Duplicates will be removed.
811
    @param into The table for the new columns.
812
    @param preserve [sql_gen.Col...] Columns not to rename. Note that these
813
        columns will be included in the mapping even if they are not in cols.
814
        The tables of the provided Col objects will be changed to into, so make
815
        copies of them if you want to keep the original tables.
816
    @param as_items Whether to return a list of dict items instead of a dict
817
    @return dict(orig_col=new_col, ...)
818
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
819
        * new_col: sql_gen.Col(orig_col_name, into)
820
        * All mappings use the into table so its name can easily be
821
          changed for all columns at once
822
    '''
823
    cols = lists.uniqify(cols)
824
    
825
    items = []
826
    for col in preserve:
827
        orig_col = copy.copy(col)
828
        col.table = into
829
        items.append((orig_col, col))
830
    preserve = set(preserve)
831
    for col in cols:
832
        if col not in preserve:
833
            items.append((col, sql_gen.Col(str(col), into, col.srcs)))
834
    
835
    if not as_items: items = dict(items)
836
    return items
837

    
838
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
839
    '''For params, see mk_flatten_mapping()
840
    @return See return value of mk_flatten_mapping()
841
    '''
842
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
843
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
844
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
845
        into=into, add_indexes_=True)
846
    return dict(items)
847

    
848
def track_data_error(db, errors_table, cols, value, error_code, error):
849
    '''
850
    @param errors_table If None, does nothing.
851
    '''
852
    if errors_table == None or cols == (): return
853
    
854
    for col in cols:
855
        try:
856
            insert(db, errors_table, dict(column=col.name, value=value,
857
                error_code=error_code, error=error), recover=True,
858
                cacheable=True, log_level=4)
859
        except DuplicateKeyException: pass
860

    
861
def cast(db, type_, col, errors_table=None):
862
    '''Casts an (unrenamed) column or value.
863
    If errors_table set and col has srcs, saves errors in errors_table (using
864
    col's srcs attr as the source columns) and converts errors to warnings.
865
    @param col str|sql_gen.Col|sql_gen.Literal
866
    @param errors_table None|sql_gen.Table|str
867
    '''
868
    col = sql_gen.as_Col(col)
869
    save_errors = (errors_table != None and isinstance(col, sql_gen.Col)
870
        and col.srcs != ())
871
    if not save_errors: return sql_gen.Cast(type_, col) # can't save errors
872
    
873
    assert not isinstance(col, sql_gen.NamedCol)
874
    
875
    errors_table = sql_gen.as_Table(errors_table)
876
    srcs = map(sql_gen.to_name_only_col, col.srcs)
877
    function_name = str(sql_gen.FunctionCall(type_, *srcs))
878
    function = db.TempFunction(function_name)
879
    
880
    while True:
881
        # Create function definition
882
        errors_table_cols = map(sql_gen.Col,
883
            ['column', 'value', 'error_code', 'error'])
884
        query = '''\
885
CREATE FUNCTION '''+function.to_str(db)+'''(value text)
886
RETURNS '''+type_+'''
887
LANGUAGE plpgsql
888
STRICT
889
AS $$
890
BEGIN
891
    /* The explicit cast to the return type is needed to make the cast happen
892
    inside the try block. (Implicit casts to the return type happen at the end
893
    of the function, outside any block.) */
894
    RETURN value::'''+type_+''';
895
EXCEPTION
896
    WHEN data_exception THEN
897
        -- Save error in errors table.
898
        DECLARE
899
            error_code text := SQLSTATE;
900
            error text := SQLERRM;
901
            "column" text;
902
        BEGIN
903
            -- Insert the value and error for *each* source column.
904
            FOR "column" IN
905
'''+mk_select(db, sql_gen.NamedValues('c', None, [[c.name] for c in srcs]),
906
    order_by=None, start=0)+'''
907
            LOOP
908
                BEGIN
909
'''+mk_insert_select(db, errors_table, errors_table_cols,
910
    sql_gen.Values(errors_table_cols).to_str(db))+''';
911
                EXCEPTION
912
                    WHEN unique_violation THEN NULL; -- continue to next row
913
                END;
914
            END LOOP;
915
        END;
916
        
917
        RAISE WARNING '%', SQLERRM;
918
        RETURN NULL;
919
END;
920
$$;
921
'''
922
        
923
        # Create function
924
        try:
925
            run_query(db, query, recover=True, cacheable=True,
926
                log_ignore_excs=(DuplicateException,))
927
            break # successful
928
        except DuplicateException:
929
            function.name = next_version(function.name)
930
            # try again with next version of name
931
    
932
    return sql_gen.FunctionCall(function, col)
933

    
934
##### Database structure queries
935

    
936
def table_row_count(db, table, recover=None):
937
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
938
        order_by=None, start=0), recover=recover, log_level=3))
939

    
940
def table_cols(db, table, recover=None):
941
    return list(col_names(select(db, table, limit=0, order_by=None,
942
        recover=recover, log_level=4)))
943

    
944
def pkey(db, table, recover=None):
945
    '''Assumed to be first column in table'''
946
    return table_cols(db, table, recover)[0]
947

    
948
not_null_col = 'not_null_col'
949

    
950
def table_not_null_col(db, table, recover=None):
951
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
952
    if not_null_col in table_cols(db, table, recover): return not_null_col
953
    else: return pkey(db, table, recover)
954

    
955
def index_cols(db, table, index):
956
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
957
    automatically created. When you don't know whether something is a UNIQUE
958
    constraint or a UNIQUE index, use this function.'''
959
    module = util.root_module(db.db)
960
    if module == 'psycopg2':
961
        return list(values(run_query(db, '''\
962
SELECT attname
963
FROM
964
(
965
        SELECT attnum, attname
966
        FROM pg_index
967
        JOIN pg_class index ON index.oid = indexrelid
968
        JOIN pg_class table_ ON table_.oid = indrelid
969
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
970
        WHERE
971
            table_.relname = '''+db.esc_value(table)+'''
972
            AND index.relname = '''+db.esc_value(index)+'''
973
    UNION
974
        SELECT attnum, attname
975
        FROM
976
        (
977
            SELECT
978
                indrelid
979
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
980
                    AS indkey
981
            FROM pg_index
982
            JOIN pg_class index ON index.oid = indexrelid
983
            JOIN pg_class table_ ON table_.oid = indrelid
984
            WHERE
985
                table_.relname = '''+db.esc_value(table)+'''
986
                AND index.relname = '''+db.esc_value(index)+'''
987
        ) s
988
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
989
) s
990
ORDER BY attnum
991
'''
992
            , cacheable=True, log_level=4)))
993
    else: raise NotImplementedError("Can't list index columns for "+module+
994
        ' database')
995

    
996
def constraint_cols(db, table, constraint):
997
    module = util.root_module(db.db)
998
    if module == 'psycopg2':
999
        return list(values(run_query(db, '''\
1000
SELECT attname
1001
FROM pg_constraint
1002
JOIN pg_class ON pg_class.oid = conrelid
1003
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
1004
WHERE
1005
    relname = '''+db.esc_value(table)+'''
1006
    AND conname = '''+db.esc_value(constraint)+'''
1007
ORDER BY attnum
1008
'''
1009
            )))
1010
    else: raise NotImplementedError("Can't list constraint columns for "+module+
1011
        ' database')
1012

    
1013
row_num_col = '_row_num'
1014

    
1015
def add_index(db, exprs, table=None, unique=False, ensure_not_null_=True):
1016
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
1017
    Currently, only function calls are supported as expressions.
1018
    @param ensure_not_null_ If set, translates NULL values to sentinel values.
1019
        This allows indexes to be used for comparisons where NULLs are equal.
1020
    '''
1021
    exprs = lists.mk_seq(exprs)
1022
    
1023
    # Parse exprs
1024
    old_exprs = exprs[:]
1025
    exprs = []
1026
    cols = []
1027
    for i, expr in enumerate(old_exprs):
1028
        expr = sql_gen.as_Col(expr, table)
1029
        
1030
        # Handle nullable columns
1031
        if ensure_not_null_:
1032
            try: expr = ensure_not_null(db, expr)
1033
            except KeyError: pass # unknown type, so just create plain index
1034
        
1035
        # Extract col
1036
        expr = copy.deepcopy(expr) # don't modify input!
1037
        if isinstance(expr, sql_gen.FunctionCall):
1038
            col = expr.args[0]
1039
            expr = sql_gen.Expr(expr)
1040
        else: col = expr
1041
        assert isinstance(col, sql_gen.Col)
1042
        
1043
        # Extract table
1044
        if table == None:
1045
            assert sql_gen.is_table_col(col)
1046
            table = col.table
1047
        
1048
        col.table = None
1049
        
1050
        exprs.append(expr)
1051
        cols.append(col)
1052
    
1053
    table = sql_gen.as_Table(table)
1054
    index = sql_gen.Table(str(sql_gen.Col(','.join(map(str, cols)), table)))
1055
    
1056
    # Add index
1057
    while True:
1058
        str_ = 'CREATE'
1059
        if unique: str_ += ' UNIQUE'
1060
        str_ += ' INDEX '+index.to_str(db)+' ON '+table.to_str(db)+' ('+(
1061
            ', '.join((v.to_str(db) for v in exprs)))+')'
1062
        
1063
        try:
1064
            run_query(db, str_, recover=True, cacheable=True, log_level=3,
1065
                log_ignore_excs=(DuplicateException,))
1066
            break
1067
        except DuplicateException:
1068
            index.name = next_version(index.name)
1069
            # try again with next version of name
1070

    
1071
def add_pkey(db, table, cols=None, recover=None):
1072
    '''Adds a primary key.
1073
    @param cols [sql_gen.Col,...] The columns in the primary key.
1074
        Defaults to the first column in the table.
1075
    @pre The table must not already have a primary key.
1076
    '''
1077
    table = sql_gen.as_Table(table)
1078
    if cols == None: cols = [pkey(db, table, recover)]
1079
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1080
    
1081
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1082
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1083
        log_ignore_excs=(DuplicateException,))
1084

    
1085
def add_not_null(db, col):
1086
    table = col.table
1087
    col = sql_gen.to_name_only_col(col)
1088
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1089
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1090

    
1091
def add_index_col(db, col, suffix, expr, nullable=True):
1092
    if sql_gen.index_col(col) != None: return # already has index col
1093
    
1094
    new_col = sql_gen.suffixed_col(col, suffix)
1095
    
1096
    # Add column
1097
    new_typed_col = sql_gen.TypedCol(new_col.name, db.col_info(col).type)
1098
    add_col(db, col.table, new_typed_col, comment='src: '+repr(col),
1099
        log_level=3)
1100
    new_col.name = new_typed_col.name # propagate any renaming
1101
    
1102
    update(db, col.table, [(new_col, expr)], in_place=True, cacheable=True,
1103
        log_level=3)
1104
    if not nullable: add_not_null(db, new_col)
1105
    add_index(db, new_col)
1106
    
1107
    col.table.index_cols[col.name] = new_col
1108

    
1109
# Controls when ensure_not_null() will use index columns
1110
not_null_index_cols_min_rows = 0 # rows; initially always use index columns
1111

    
1112
def ensure_not_null(db, col):
1113
    '''For params, see sql_gen.ensure_not_null()'''
1114
    expr = sql_gen.ensure_not_null(db, col)
1115
    
1116
    # If a nullable column in a temp table, add separate index column instead.
1117
    # Note that for small datasources, this adds 6-25% to the total import time.
1118
    if (sql_gen.is_temp_col(col) and isinstance(expr, sql_gen.EnsureNotNull)
1119
        and table_row_count(db, col.table) >= not_null_index_cols_min_rows):
1120
        add_index_col(db, col, '::NOT NULL', expr, nullable=False)
1121
        expr = sql_gen.index_col(col)
1122
    
1123
    return expr
1124

    
1125
already_indexed = object() # tells add_indexes() the pkey has already been added
1126

    
1127
def add_indexes(db, table, has_pkey=True):
1128
    '''Adds an index on all columns in a table.
1129
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1130
        index should be added on the first column.
1131
        * If already_indexed, the pkey is assumed to have already been added
1132
    '''
1133
    cols = table_cols(db, table)
1134
    if has_pkey:
1135
        if has_pkey is not already_indexed: add_pkey(db, table)
1136
        cols = cols[1:]
1137
    for col in cols: add_index(db, col, table)
1138

    
1139
def add_col(db, table, col, comment=None, **kw_args):
1140
    '''
1141
    @param col TypedCol Name may be versioned, so be sure to propagate any
1142
        renaming back to any source column for the TypedCol.
1143
    @param comment None|str SQL comment used to distinguish columns of the same
1144
        name from each other when they contain different data, to allow the
1145
        ADD COLUMN query to be cached. If not set, query will not be cached.
1146
    '''
1147
    assert isinstance(col, sql_gen.TypedCol)
1148
    
1149
    while True:
1150
        str_ = 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '+col.to_str(db)
1151
        if comment != None: str_ += ' '+sql_gen.esc_comment(comment)
1152
        
1153
        try:
1154
            run_query(db, str_, recover=True, cacheable=True, **kw_args)
1155
            break
1156
        except DuplicateException:
1157
            col.name = next_version(col.name)
1158
            # try again with next version of name
1159

    
1160
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1161
    constraints='PRIMARY KEY')
1162

    
1163
def add_row_num(db, table):
1164
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1165
    be the primary key.'''
1166
    add_col(db, table, row_num_typed_col, log_level=3)
1167

    
1168
def cast_temp_col(db, type_, col, errors_table=None):
1169
    '''Like cast(), but creates a new column with the cast values if the input
1170
    is a column.
1171
    @return The new column or cast value
1172
    '''
1173
    def cast_(col): return cast(db, type_, col, errors_table)
1174
    
1175
    try: col = sql_gen.underlying_col(col)
1176
    except sql_gen.NoUnderlyingTableException: return sql_gen.wrap(cast_, col)
1177
    
1178
    table = col.table
1179
    new_col = sql_gen.Col(sql_gen.concat(col.name, '::'+type_), table, col.srcs)
1180
    expr = cast_(col)
1181
    
1182
    # Add column
1183
    new_typed_col = sql_gen.TypedCol(new_col.name, type_)
1184
    add_col(db, table, new_typed_col, comment='src: '+repr(col))
1185
    new_col.name = new_typed_col.name # propagate any renaming
1186
    
1187
    update(db, table, [(new_col, expr)], in_place=True, cacheable=True)
1188
    add_index(db, new_col)
1189
    
1190
    return new_col
1191

    
1192
def drop_table(db, table):
1193
    table = sql_gen.as_Table(table)
1194
    return run_query(db, 'DROP TABLE IF EXISTS '+table.to_str(db)+' CASCADE')
1195

    
1196
def create_table(db, table, cols, has_pkey=True, col_indexes=True):
1197
    '''Creates a table.
1198
    @param cols [sql_gen.TypedCol,...] The column names and types
1199
    @param has_pkey If set, the first column becomes the primary key.
1200
    @param col_indexes bool|[ref]
1201
        * If True, indexes will be added on all non-pkey columns.
1202
        * If a list reference, [0] will be set to a function to do this.
1203
          This can be used to delay index creation until the table is populated.
1204
    '''
1205
    table = sql_gen.as_Table(table)
1206
    
1207
    if has_pkey:
1208
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1209
        pkey.constraints = 'PRIMARY KEY'
1210
    
1211
    str_ = 'CREATE TABLE '+table.to_str(db)+' (\n'
1212
    str_ += '\n, '.join(v.to_str(db) for v in cols)
1213
    str_ += '\n);\n'
1214
    run_query(db, str_, cacheable=True, log_level=2)
1215
    
1216
    # Add indexes
1217
    if has_pkey: has_pkey = already_indexed
1218
    def add_indexes_(): add_indexes(db, table, has_pkey)
1219
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1220
    elif col_indexes: add_indexes_() # add now
1221

    
1222
def analyze(db, table):
1223
    table = sql_gen.as_Table(table)
1224
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1225

    
1226
def vacuum(db, table):
1227
    table = sql_gen.as_Table(table)
1228
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1229
        log_level=3))
1230

    
1231
def truncate(db, table, schema='public', **kw_args):
1232
    '''For params, see run_query()'''
1233
    table = sql_gen.as_Table(table, schema)
1234
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1235

    
1236
def empty_temp(db, tables):
1237
    if db.debug_temp: return # leave temp tables there for debugging
1238
    tables = lists.mk_seq(tables)
1239
    for table in tables: truncate(db, table, log_level=3)
1240

    
1241
def tables(db, schema_like='public', table_like='%', exact=False):
1242
    if exact: compare = '='
1243
    else: compare = 'LIKE'
1244
    
1245
    module = util.root_module(db.db)
1246
    if module == 'psycopg2':
1247
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1248
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1249
        return values(select(db, 'pg_tables', ['tablename'], conds,
1250
            order_by='tablename', log_level=4))
1251
    elif module == 'MySQLdb':
1252
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1253
            , cacheable=True, log_level=4))
1254
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1255

    
1256
def table_exists(db, table):
1257
    table = sql_gen.as_Table(table)
1258
    return list(tables(db, table.schema, table.name, exact=True)) != []
1259

    
1260
def function_exists(db, function):
1261
    function = sql_gen.as_Function(function)
1262
    
1263
    info_table = sql_gen.Table('routines', 'information_schema')
1264
    conds = [('routine_name', function.name)]
1265
    schema = function.schema
1266
    if schema != None: conds.append(('routine_schema', schema))
1267
    # Exclude trigger functions, since they cannot be called directly
1268
    conds.append(('data_type', sql_gen.CompareCond('trigger', '!=')))
1269
    
1270
    return list(values(select(db, info_table, ['routine_name'], conds,
1271
        order_by='routine_schema', limit=1, log_level=4))) != []
1272
        # TODO: order_by search_path schema order
1273

    
1274
def errors_table(db, table, if_exists=True):
1275
    '''
1276
    @param if_exists If set, returns None if the errors table doesn't exist
1277
    @return None|sql_gen.Table
1278
    '''
1279
    table = sql_gen.as_Table(table)
1280
    if table.srcs != (): table = table.srcs[0]
1281
    
1282
    errors_table = sql_gen.suffixed_table(table, '.errors')
1283
    if if_exists and not table_exists(db, errors_table): return None
1284
    return errors_table
1285

    
1286
##### Database management
1287

    
1288
def empty_db(db, schema='public', **kw_args):
1289
    '''For kw_args, see tables()'''
1290
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1291

    
1292
##### Heuristic queries
1293

    
1294
def put(db, table, row, pkey_=None, row_ct_ref=None):
1295
    '''Recovers from errors.
1296
    Only works under PostgreSQL (uses INSERT RETURNING).
1297
    '''
1298
    row = sql_gen.ColDict(db, table, row)
1299
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
1300
    
1301
    try:
1302
        cur = insert(db, table, row, pkey_, recover=True)
1303
        if row_ct_ref != None and cur.rowcount >= 0:
1304
            row_ct_ref[0] += cur.rowcount
1305
        return value(cur)
1306
    except DuplicateKeyException, e:
1307
        row = sql_gen.ColDict(db, table,
1308
            util.dict_subset_right_join(row, e.cols))
1309
        return value(select(db, table, [pkey_], row, recover=True))
1310

    
1311
def get(db, table, row, pkey, row_ct_ref=None, create=False):
1312
    '''Recovers from errors'''
1313
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
1314
    except StopIteration:
1315
        if not create: raise
1316
        return put(db, table, row, pkey, row_ct_ref) # insert new row
1317

    
1318
def is_func_result(col):
1319
    return col.table.name.find('(') >= 0 and col.name == 'result'
1320

    
1321
def into_table_name(out_table, in_tables0, mapping, is_func):
1322
    def in_col_str(in_col):
1323
        in_col = sql_gen.remove_col_rename(in_col)
1324
        if isinstance(in_col, sql_gen.Col):
1325
            table = in_col.table
1326
            if table == in_tables0:
1327
                in_col = sql_gen.to_name_only_col(in_col)
1328
            elif is_func_result(in_col): in_col = table # omit col name
1329
        return str(in_col)
1330
    
1331
    str_ = str(out_table)
1332
    if is_func:
1333
        str_ += '('
1334
        
1335
        try: value_in_col = mapping['value']
1336
        except KeyError:
1337
            str_ += ', '.join((str(k)+'='+in_col_str(v)
1338
                for k, v in mapping.iteritems()))
1339
        else: str_ += in_col_str(value_in_col)
1340
        
1341
        str_ += ')'
1342
    else:
1343
        out_col = 'rank'
1344
        try: in_col = mapping[out_col]
1345
        except KeyError: str_ += '_pkeys'
1346
        else: # has a rank column, so hierarchical
1347
            str_ += '['+str(out_col)+'='+in_col_str(in_col)+']'
1348
    return str_
1349

    
1350
def put_table(db, out_table, in_tables, mapping, row_ct_ref=None, into=None,
1351
    default=None, is_func=False, on_error=exc.raise_):
1352
    '''Recovers from errors.
1353
    Only works under PostgreSQL (uses INSERT RETURNING).
1354
    IMPORTANT: Must be run at the *beginning* of a transaction.
1355
    @param in_tables The main input table to select from, followed by a list of
1356
        tables to join with it using the main input table's pkey
1357
    @param mapping dict(out_table_col=in_table_col, ...)
1358
        * out_table_col: str (*not* sql_gen.Col)
1359
        * in_table_col: sql_gen.Col|literal-value
1360
    @param into The table to contain the output and input pkeys.
1361
        Defaults to `out_table.name+'_pkeys'`.
1362
    @param default The *output* column to use as the pkey for missing rows.
1363
        If this output column does not exist in the mapping, uses None.
1364
    @param is_func Whether out_table is the name of a SQL function, not a table
1365
    @return sql_gen.Col Where the output pkeys are made available
1366
    '''
1367
    out_table = sql_gen.as_Table(out_table)
1368
    
1369
    def log_debug(msg): db.log_debug(msg, level=1.5)
1370
    def col_ustr(str_):
1371
        return strings.repr_no_u(sql_gen.remove_col_rename(str_))
1372
    
1373
    log_debug('********** New iteration **********')
1374
    log_debug('Inserting these input columns into '+strings.as_tt(
1375
        out_table.to_str(db))+':\n'+strings.as_table(mapping, ustr=col_ustr))
1376
    
1377
    is_function = function_exists(db, out_table)
1378
    
1379
    if is_function: out_pkey = 'result'
1380
    else: out_pkey = pkey(db, out_table, recover=True)
1381
    out_pkey_col = sql_gen.as_Col(out_pkey, out_table)
1382
    
1383
    if mapping == {}: # need at least one column for INSERT SELECT
1384
        mapping = {out_pkey: None} # ColDict will replace with default value
1385
    
1386
    # Create input joins from list of input tables
1387
    in_tables_ = in_tables[:] # don't modify input!
1388
    in_tables0 = in_tables_.pop(0) # first table is separate
1389
    errors_table_ = errors_table(db, in_tables0)
1390
    in_pkey = pkey(db, in_tables0, recover=True)
1391
    in_pkey_col = sql_gen.as_Col(in_pkey, in_tables0)
1392
    input_joins = [in_tables0]+[sql_gen.Join(v,
1393
        {in_pkey: sql_gen.join_same_not_null}) for v in in_tables_]
1394
    
1395
    if into == None:
1396
        into = into_table_name(out_table, in_tables0, mapping, is_func)
1397
    into = sql_gen.as_Table(into)
1398
    
1399
    # Set column sources
1400
    in_cols = filter(sql_gen.is_table_col, mapping.values())
1401
    for col in in_cols:
1402
        if col.table == in_tables0: col.set_srcs(sql_gen.src_self)
1403
    
1404
    log_debug('Joining together input tables into temp table')
1405
    # Place in new table for speed and so don't modify input if values edited
1406
    in_table = sql_gen.Table('in')
1407
    mapping = dicts.join(mapping, flatten(db, in_table, input_joins, in_cols,
1408
        preserve=[in_pkey_col], start=0))
1409
    input_joins = [in_table]
1410
    db.log_debug('Temp table: '+strings.as_tt(in_table.to_str(db)), level=2)
1411
    
1412
    mapping = sql_gen.ColDict(db, out_table, mapping)
1413
        # after applying dicts.join() because that returns a plain dict
1414
    
1415
    # Resolve default value column
1416
    if default != None:
1417
        try: default = mapping[default]
1418
        except KeyError:
1419
            db.log_debug('Default value column '
1420
                +strings.as_tt(strings.repr_no_u(default))
1421
                +' does not exist in mapping, falling back to None', level=2.1)
1422
            default = None
1423
    
1424
    pkeys_names = [in_pkey, out_pkey]
1425
    pkeys_cols = [in_pkey_col, out_pkey_col]
1426
    
1427
    pkeys_table_exists_ref = [False]
1428
    def insert_into_pkeys(joins, cols, distinct=False):
1429
        kw_args = {}
1430
        if distinct: kw_args.update(dict(distinct_on=[in_pkey_col]))
1431
        query = mk_select(db, joins, cols, order_by=None, start=0, **kw_args)
1432
        
1433
        if pkeys_table_exists_ref[0]:
1434
            insert_select(db, into, pkeys_names, query)
1435
        else:
1436
            run_query_into(db, query, into=into)
1437
            pkeys_table_exists_ref[0] = True
1438
    
1439
    limit_ref = [None]
1440
    conds = set()
1441
    distinct_on = sql_gen.ColDict(db, out_table)
1442
    def mk_main_select(joins, cols):
1443
        distinct_on_cols = [c.to_Col() for c in distinct_on.values()]
1444
        return mk_select(db, joins, cols, conds, distinct_on_cols,
1445
            limit=limit_ref[0], start=0)
1446
    
1447
    exc_strs = set()
1448
    def log_exc(e):
1449
        e_str = exc.str_(e, first_line_only=True)
1450
        log_debug('Caught exception: '+e_str)
1451
        assert e_str not in exc_strs # avoid infinite loops
1452
        exc_strs.add(e_str)
1453
    
1454
    def remove_all_rows():
1455
        log_debug('Ignoring all rows')
1456
        limit_ref[0] = 0 # just create an empty pkeys table
1457
    
1458
    def ignore(in_col, value, e):
1459
        track_data_error(db, errors_table_, in_col.srcs, value, e.cause.pgcode,
1460
            e.cause.pgerror)
1461
        log_debug('Ignoring rows with '+strings.as_tt(repr(in_col))+' = '
1462
            +strings.as_tt(repr(value)))
1463
    
1464
    def remove_rows(in_col, value, e):
1465
        ignore(in_col, value, e)
1466
        cond = (in_col, sql_gen.CompareCond(value, '!='))
1467
        assert cond not in conds # avoid infinite loops
1468
        conds.add(cond)
1469
    
1470
    def invalid2null(in_col, value, e):
1471
        ignore(in_col, value, e)
1472
        update(db, in_table, [(in_col, None)],
1473
            sql_gen.ColValueCond(in_col, value))
1474
    
1475
    def insert_pkeys_table(which):
1476
        return sql_gen.Table(sql_gen.concat(in_table.name,
1477
            '_insert_'+which+'_pkeys'))
1478
    insert_out_pkeys = insert_pkeys_table('out')
1479
    insert_in_pkeys = insert_pkeys_table('in')
1480
    
1481
    # Do inserts and selects
1482
    join_cols = sql_gen.ColDict(db, out_table)
1483
    while True:
1484
        if limit_ref[0] == 0: # special case
1485
            log_debug('Creating an empty pkeys table')
1486
            cur = run_query_into(db, mk_select(db, out_table, [out_pkey],
1487
                limit=limit_ref[0]), into=insert_out_pkeys)
1488
            break # don't do main case
1489
        
1490
        has_joins = join_cols != {}
1491
        
1492
        log_debug('Trying to insert new rows')
1493
        
1494
        # Prepare to insert new rows
1495
        insert_joins = input_joins[:] # don't modify original!
1496
        insert_args = dict(recover=True, cacheable=False)
1497
        if has_joins:
1498
            insert_args.update(dict(ignore=True))
1499
        else:
1500
            insert_args.update(dict(returning=out_pkey, into=insert_out_pkeys))
1501
        main_select = mk_main_select(insert_joins, mapping.values())
1502
        
1503
        def main_insert():
1504
            if is_function:
1505
                log_debug('Calling function on input rows')
1506
                args = dict(((k.name, v) for k, v in mapping.iteritems()))
1507
                func_call = sql_gen.NamedCol(out_pkey,
1508
                    sql_gen.FunctionCall(out_table, **args))
1509
                insert_into_pkeys(input_joins, [in_pkey_col, func_call])
1510
                return None
1511
            else:
1512
                return insert_select(db, out_table, mapping.keys(), main_select,
1513
                    **insert_args)
1514
        
1515
        try:
1516
            cur = with_savepoint(db, main_insert)
1517
            break # insert successful
1518
        except MissingCastException, e:
1519
            log_exc(e)
1520
            
1521
            out_col = e.col
1522
            type_ = e.type
1523
            
1524
            log_debug('Casting '+strings.as_tt(out_col)+' input to '
1525
                +strings.as_tt(type_))
1526
            mapping[out_col] = cast_temp_col(db, type_, mapping[out_col],
1527
                errors_table_)
1528
        except DuplicateKeyException, e:
1529
            log_exc(e)
1530
            
1531
            old_join_cols = join_cols.copy()
1532
            distinct_on.update(util.dict_subset(mapping, e.cols))
1533
            join_cols.update(util.dict_subset_right_join(mapping, e.cols))
1534
            log_debug('Ignoring existing rows, comparing on these columns:\n'
1535
                +strings.as_inline_table(join_cols, ustr=col_ustr))
1536
            assert join_cols != old_join_cols # avoid infinite loops
1537
        except NullValueException, e:
1538
            log_exc(e)
1539
            
1540
            out_col, = e.cols
1541
            try: in_col = mapping[out_col]
1542
            except KeyError:
1543
                log_debug('Missing mapping for NOT NULL column '+out_col)
1544
                remove_all_rows()
1545
            else: remove_rows(in_col, None, e)
1546
        except FunctionValueException, e:
1547
            log_exc(e)
1548
            
1549
            func_name = e.name
1550
            value = e.value
1551
            for out_col, in_col in mapping.iteritems():
1552
                in_col = sql_gen.unwrap_func_call(in_col, func_name)
1553
                invalid2null(in_col, value, e)
1554
        except DatabaseErrors, e:
1555
            log_exc(e)
1556
            
1557
            log_debug('No handler for exception')
1558
            on_error(e)
1559
            remove_all_rows()
1560
        # after exception handled, rerun loop with additional constraints
1561
    
1562
    if cur != None and row_ct_ref != None and cur.rowcount >= 0:
1563
        row_ct_ref[0] += cur.rowcount
1564
    
1565
    if is_function: pass # pkeys table already created
1566
    elif has_joins:
1567
        select_joins = input_joins+[sql_gen.Join(out_table, join_cols)]
1568
        log_debug('Getting output table pkeys of existing/inserted rows')
1569
        insert_into_pkeys(select_joins, pkeys_cols, distinct=True)
1570
    else:
1571
        add_row_num(db, insert_out_pkeys) # for joining with input pkeys
1572
        
1573
        log_debug('Getting input table pkeys of inserted rows')
1574
        run_query_into(db, mk_main_select(input_joins, [in_pkey]),
1575
            into=insert_in_pkeys)
1576
        add_row_num(db, insert_in_pkeys) # for joining with output pkeys
1577
        
1578
        assert table_row_count(db, insert_out_pkeys) == table_row_count(db,
1579
            insert_in_pkeys)
1580
        
1581
        log_debug('Combining output and input pkeys in inserted order')
1582
        pkey_joins = [insert_in_pkeys, sql_gen.Join(insert_out_pkeys,
1583
            {row_num_col: sql_gen.join_same_not_null})]
1584
        insert_into_pkeys(pkey_joins, pkeys_names)
1585
        
1586
        empty_temp(db, [insert_out_pkeys, insert_in_pkeys])
1587
    
1588
    db.log_debug('Adding pkey on pkeys table to enable fast joins', level=2.5)
1589
    add_pkey(db, into)
1590
    
1591
    log_debug('Setting pkeys of missing rows to '+strings.as_tt(repr(default)))
1592
    missing_rows_joins = input_joins+[sql_gen.Join(into,
1593
        {in_pkey: sql_gen.join_same_not_null}, sql_gen.filter_out)]
1594
        # must use join_same_not_null or query will take forever
1595
    insert_into_pkeys(missing_rows_joins,
1596
        [in_pkey_col, sql_gen.NamedCol(out_pkey, default)])
1597
    
1598
    assert table_row_count(db, into) == table_row_count(db, in_table)
1599
    
1600
    empty_temp(db, in_table)
1601
    
1602
    srcs = []
1603
    if is_func: srcs = sql_gen.cols_srcs(in_cols)
1604
    return sql_gen.Col(out_pkey, into, srcs)
1605

    
1606
##### Data cleanup
1607

    
1608
def cleanup_table(db, table, cols):
1609
    table = sql_gen.as_Table(table)
1610
    cols = map(sql_gen.as_Col, cols)
1611
    
1612
    expr = ('nullif(nullif(trim(both from %s), '+db.esc_value('')+'), '
1613
        +db.esc_value(r'\N')+')')
1614
    changes = [(v, sql_gen.CustomCode(expr % v.to_str(db)))
1615
        for v in cols]
1616
    
1617
    update(db, table, changes, in_place=True)
(24-24/36)