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
        cols = ['data_type', 'column_default',
398
            cast(self, 'boolean', 'is_nullable')]
399
        
400
        conds = [('table_name', col.table.name), ('column_name', col.name)]
401
        schema = col.table.schema
402
        if schema != None: conds.append(('table_schema', schema))
403
        
404
        type_, default, nullable = row(select(self, table, cols, conds,
405
            order_by='table_schema', limit=1, log_level=4))
406
            # TODO: order_by search_path schema order
407
        default = sql_gen.as_Code(default, self)
408
        
409
        return sql_gen.TypedCol(col.name, type_, default, nullable)
410
    
411
    def TempFunction(self, name):
412
        if self.debug_temp: schema = None
413
        else: schema = 'pg_temp'
414
        return sql_gen.Function(name, schema)
415

    
416
connect = DbConn
417

    
418
##### Recoverable querying
419

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

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

    
483
##### Basic queries
484

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

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

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

    
532
order_by_pkey = object() # tells mk_select() to order by the pkey
533

    
534
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
535

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

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

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

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

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

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

    
758
def mk_update(db, table, changes=None, cond=None, in_place=False):
759
    '''
760
    @param changes [(col, new_value),...]
761
        * container can be any iterable type
762
        * col: sql_gen.Code|str (for col name)
763
        * new_value: sql_gen.Code|literal value
764
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
765
    @param in_place If set, locks the table and updates rows in place.
766
        This avoids creating dead rows in PostgreSQL.
767
        * changes may only change one column
768
        * cond must be None
769
    @return str query
770
    '''
771
    if in_place:
772
        assert len(changes) == 1
773
        assert cond == None
774
    
775
    query = 'UPDATE '+sql_gen.as_Table(table).to_str(db)+'\nSET\n'
776
    query += ',\n'.join((sql_gen.to_name_only_col(col, table).to_str(db)+' = '
777
        +sql_gen.as_Value(new_value).to_str(db) for col, new_value in changes))
778
    if cond != None: query += '\nWHERE\n'+cond.to_str(db)
779
    
780
    return query
781

    
782
def update(db, *args, **kw_args):
783
    '''For params, see mk_update() and run_query()'''
784
    recover = kw_args.pop('recover', None)
785
    cacheable = kw_args.pop('cacheable', False)
786
    log_level = kw_args.pop('log_level', 2)
787
    
788
    return run_query(db, mk_update(db, *args, **kw_args), recover, cacheable,
789
        log_level=log_level)
790

    
791
def last_insert_id(db):
792
    module = util.root_module(db.db)
793
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
794
    elif module == 'MySQLdb': return db.insert_id()
795
    else: return None
796

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

    
829
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
830
    '''For params, see mk_flatten_mapping()
831
    @return See return value of mk_flatten_mapping()
832
    '''
833
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
834
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
835
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
836
        into=into, add_indexes_=True)
837
    return dict(items)
838

    
839
def track_data_error(db, errors_table, cols, value, error_code, error):
840
    '''
841
    @param errors_table If None, does nothing.
842
    '''
843
    if errors_table == None or cols == (): return
844
    
845
    for col in cols:
846
        try:
847
            insert(db, errors_table, dict(column=col.name, value=value,
848
                error_code=error_code, error=error), recover=True,
849
                cacheable=True, log_level=4)
850
        except DuplicateKeyException: pass
851

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

    
925
##### Database structure queries
926

    
927
def table_row_count(db, table, recover=None):
928
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
929
        order_by=None, start=0), recover=recover, log_level=3))
930

    
931
def table_cols(db, table, recover=None):
932
    return list(col_names(select(db, table, limit=0, order_by=None,
933
        recover=recover, log_level=4)))
934

    
935
def pkey(db, table, recover=None):
936
    '''Assumed to be first column in table'''
937
    return table_cols(db, table, recover)[0]
938

    
939
not_null_col = 'not_null_col'
940

    
941
def table_not_null_col(db, table, recover=None):
942
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
943
    if not_null_col in table_cols(db, table, recover): return not_null_col
944
    else: return pkey(db, table, recover)
945

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

    
987
def constraint_cols(db, table, constraint):
988
    module = util.root_module(db.db)
989
    if module == 'psycopg2':
990
        return list(values(run_query(db, '''\
991
SELECT attname
992
FROM pg_constraint
993
JOIN pg_class ON pg_class.oid = conrelid
994
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
995
WHERE
996
    relname = '''+db.esc_value(table)+'''
997
    AND conname = '''+db.esc_value(constraint)+'''
998
ORDER BY attnum
999
'''
1000
            )))
1001
    else: raise NotImplementedError("Can't list constraint columns for "+module+
1002
        ' database')
1003

    
1004
row_num_col = '_row_num'
1005

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

    
1062
def add_pkey(db, table, cols=None, recover=None):
1063
    '''Adds a primary key.
1064
    @param cols [sql_gen.Col,...] The columns in the primary key.
1065
        Defaults to the first column in the table.
1066
    @pre The table must not already have a primary key.
1067
    '''
1068
    table = sql_gen.as_Table(table)
1069
    if cols == None: cols = [pkey(db, table, recover)]
1070
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1071
    
1072
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1073
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1074
        log_ignore_excs=(DuplicateException,))
1075

    
1076
def add_not_null(db, col):
1077
    table = col.table
1078
    col = sql_gen.to_name_only_col(col)
1079
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1080
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1081

    
1082
def add_index_col(db, col, suffix, expr, nullable=True):
1083
    if sql_gen.index_col(col) != None: return # already has index col
1084
    
1085
    new_col = sql_gen.suffixed_col(col, suffix)
1086
    
1087
    # Add column
1088
    new_typed_col = sql_gen.TypedCol(new_col.name, db.col_info(col).type)
1089
    add_col(db, col.table, new_typed_col, comment='src: '+repr(col),
1090
        log_level=3)
1091
    new_col.name = new_typed_col.name # propagate any renaming
1092
    
1093
    update(db, col.table, [(new_col, expr)], cacheable=True, log_level=3)
1094
    if not nullable: add_not_null(db, new_col)
1095
    add_index(db, new_col)
1096
    
1097
    col.table.index_cols[col.name] = new_col
1098

    
1099
# Controls when ensure_not_null() will use index columns
1100
not_null_index_cols_min_rows = 0 # rows; initially always use index columns
1101

    
1102
def ensure_not_null(db, col):
1103
    '''For params, see sql_gen.ensure_not_null()'''
1104
    expr = sql_gen.ensure_not_null(db, col)
1105
    
1106
    # If a nullable column in a temp table, add separate index column instead.
1107
    # Note that for small datasources, this adds 6-25% to the total import time.
1108
    if (sql_gen.is_temp_col(col) and isinstance(expr, sql_gen.EnsureNotNull)
1109
        and table_row_count(db, col.table) >= not_null_index_cols_min_rows):
1110
        add_index_col(db, col, '::NOT NULL', expr, nullable=False)
1111
        expr = sql_gen.index_col(col)
1112
    
1113
    return expr
1114

    
1115
already_indexed = object() # tells add_indexes() the pkey has already been added
1116

    
1117
def add_indexes(db, table, has_pkey=True):
1118
    '''Adds an index on all columns in a table.
1119
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1120
        index should be added on the first column.
1121
        * If already_indexed, the pkey is assumed to have already been added
1122
    '''
1123
    cols = table_cols(db, table)
1124
    if has_pkey:
1125
        if has_pkey is not already_indexed: add_pkey(db, table)
1126
        cols = cols[1:]
1127
    for col in cols: add_index(db, col, table)
1128

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

    
1150
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1151
    constraints='PRIMARY KEY')
1152

    
1153
def add_row_num(db, table):
1154
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1155
    be the primary key.'''
1156
    add_col(db, table, row_num_typed_col, log_level=3)
1157

    
1158
def cast_temp_col(db, type_, col, errors_table=None):
1159
    '''Like cast(), but creates a new column with the cast values if the input
1160
    is a column.
1161
    @return The new column or cast value
1162
    '''
1163
    def cast_(col): return cast(db, type_, col, errors_table)
1164
    
1165
    try: col = sql_gen.underlying_col(col)
1166
    except sql_gen.NoUnderlyingTableException: return sql_gen.wrap(cast_, col)
1167
    
1168
    table = col.table
1169
    new_col = sql_gen.Col(sql_gen.concat(col.name, '::'+type_), table, col.srcs)
1170
    expr = cast_(col)
1171
    
1172
    # Add column
1173
    new_typed_col = sql_gen.TypedCol(new_col.name, type_)
1174
    add_col(db, table, new_typed_col, comment='src: '+repr(col))
1175
    new_col.name = new_typed_col.name # propagate any renaming
1176
    
1177
    update(db, table, [(new_col, expr)], cacheable=True)
1178
    add_index(db, new_col)
1179
    
1180
    return new_col
1181

    
1182
def drop_table(db, table):
1183
    table = sql_gen.as_Table(table)
1184
    return run_query(db, 'DROP TABLE IF EXISTS '+table.to_str(db)+' CASCADE')
1185

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

    
1212
def vacuum(db, table):
1213
    table = sql_gen.as_Table(table)
1214
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1215
        log_level=3))
1216

    
1217
def truncate(db, table, schema='public', **kw_args):
1218
    '''For params, see run_query()'''
1219
    table = sql_gen.as_Table(table, schema)
1220
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1221

    
1222
def empty_temp(db, tables):
1223
    if db.debug_temp: return # leave temp tables there for debugging
1224
    tables = lists.mk_seq(tables)
1225
    for table in tables: truncate(db, table, log_level=3)
1226

    
1227
def tables(db, schema_like='public', table_like='%', exact=False):
1228
    if exact: compare = '='
1229
    else: compare = 'LIKE'
1230
    
1231
    module = util.root_module(db.db)
1232
    if module == 'psycopg2':
1233
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1234
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1235
        return values(select(db, 'pg_tables', ['tablename'], conds,
1236
            order_by='tablename', log_level=4))
1237
    elif module == 'MySQLdb':
1238
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1239
            , cacheable=True, log_level=4))
1240
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1241

    
1242
def table_exists(db, table):
1243
    table = sql_gen.as_Table(table)
1244
    return list(tables(db, table.schema, table.name, exact=True)) != []
1245

    
1246
def function_exists(db, function):
1247
    function = sql_gen.as_Function(function)
1248
    
1249
    info_table = sql_gen.Table('routines', 'information_schema')
1250
    conds = [('routine_name', function.name)]
1251
    schema = function.schema
1252
    if schema != None: conds.append(('routine_schema', schema))
1253
    # Exclude trigger functions, since they cannot be called directly
1254
    conds.append(('data_type', sql_gen.CompareCond('trigger', '!=')))
1255
    
1256
    return list(values(select(db, info_table, ['routine_name'], conds,
1257
        order_by='routine_schema', limit=1, log_level=4))) != []
1258
        # TODO: order_by search_path schema order
1259

    
1260
def errors_table(db, table, if_exists=True):
1261
    '''
1262
    @param if_exists If set, returns None if the errors table doesn't exist
1263
    @return None|sql_gen.Table
1264
    '''
1265
    table = sql_gen.as_Table(table)
1266
    if table.srcs != (): table = table.srcs[0]
1267
    
1268
    errors_table = sql_gen.suffixed_table(table, '.errors')
1269
    if if_exists and not table_exists(db, errors_table): return None
1270
    return errors_table
1271

    
1272
##### Database management
1273

    
1274
def empty_db(db, schema='public', **kw_args):
1275
    '''For kw_args, see tables()'''
1276
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1277

    
1278
##### Heuristic queries
1279

    
1280
def put(db, table, row, pkey_=None, row_ct_ref=None):
1281
    '''Recovers from errors.
1282
    Only works under PostgreSQL (uses INSERT RETURNING).
1283
    '''
1284
    row = sql_gen.ColDict(db, table, row)
1285
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
1286
    
1287
    try:
1288
        cur = insert(db, table, row, pkey_, recover=True)
1289
        if row_ct_ref != None and cur.rowcount >= 0:
1290
            row_ct_ref[0] += cur.rowcount
1291
        return value(cur)
1292
    except DuplicateKeyException, e:
1293
        row = sql_gen.ColDict(db, table,
1294
            util.dict_subset_right_join(row, e.cols))
1295
        return value(select(db, table, [pkey_], row, recover=True))
1296

    
1297
def get(db, table, row, pkey, row_ct_ref=None, create=False):
1298
    '''Recovers from errors'''
1299
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
1300
    except StopIteration:
1301
        if not create: raise
1302
        return put(db, table, row, pkey, row_ct_ref) # insert new row
1303

    
1304
def is_func_result(col):
1305
    return col.table.name.find('(') >= 0 and col.name == 'result'
1306

    
1307
def into_table_name(out_table, in_tables0, mapping, is_func):
1308
    def in_col_str(in_col):
1309
        in_col = sql_gen.remove_col_rename(in_col)
1310
        if isinstance(in_col, sql_gen.Col):
1311
            table = in_col.table
1312
            if table == in_tables0:
1313
                in_col = sql_gen.to_name_only_col(in_col)
1314
            elif is_func_result(in_col): in_col = table # omit col name
1315
        return str(in_col)
1316
    
1317
    str_ = str(out_table)
1318
    if is_func:
1319
        str_ += '('
1320
        
1321
        try: value_in_col = mapping['value']
1322
        except KeyError:
1323
            str_ += ', '.join((str(k)+'='+in_col_str(v)
1324
                for k, v in mapping.iteritems()))
1325
        else: str_ += in_col_str(value_in_col)
1326
        
1327
        str_ += ')'
1328
    else:
1329
        out_col = 'rank'
1330
        try: in_col = mapping[out_col]
1331
        except KeyError: str_ += '_pkeys'
1332
        else: # has a rank column, so hierarchical
1333
            str_ += '['+str(out_col)+'='+in_col_str(in_col)+']'
1334
    return str_
1335

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

    
1592
##### Data cleanup
1593

    
1594
def cleanup_table(db, table, cols):
1595
    table = sql_gen.as_Table(table)
1596
    cols = map(sql_gen.as_Col, cols)
1597
    
1598
    expr = ('nullif(nullif(trim(both from %s), '+db.esc_value('')+'), '
1599
        +db.esc_value(r'\N')+')')
1600
    changes = [(v, sql_gen.CustomCode(expr % v.to_str(db)))
1601
        for v in cols]
1602
    
1603
    update(db, table, changes)
(24-24/36)