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

    
414
connect = DbConn
415

    
416
##### Recoverable querying
417

    
418
def with_savepoint(db, func): return db.with_savepoint(func)
419

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

    
480
##### Basic queries
481

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

    
490
def lock_table(db, table, mode):
491
    table = sql_gen.as_Table(table)
492
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
493

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

    
529
order_by_pkey = object() # tells mk_select() to order by the pkey
530

    
531
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
532

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

    
614
def select(db, *args, **kw_args):
615
    '''For params, see mk_select() and run_query()'''
616
    recover = kw_args.pop('recover', None)
617
    cacheable = kw_args.pop('cacheable', True)
618
    log_level = kw_args.pop('log_level', 2)
619
    
620
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
621
        log_level=log_level)
622

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

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

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

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

    
761
def mk_update(db, table, changes=None, cond=None):
762
    '''
763
    @param changes [(col, new_value),...]
764
        * container can be any iterable type
765
        * col: sql_gen.Code|str (for col name)
766
        * new_value: sql_gen.Code|literal value
767
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
768
    @return str query
769
    '''
770
    query = 'UPDATE '+sql_gen.as_Table(table).to_str(db)+'\nSET\n'
771
    query += ',\n'.join((sql_gen.to_name_only_col(col, table).to_str(db)+' = '
772
        +sql_gen.as_Value(new_value).to_str(db) for col, new_value in changes))
773
    if cond != None: query += '\nWHERE\n'+cond.to_str(db)
774
    
775
    return query
776

    
777
def update(db, *args, **kw_args):
778
    '''For params, see mk_update() and run_query()'''
779
    recover = kw_args.pop('recover', None)
780
    
781
    return run_query(db, mk_update(db, *args, **kw_args), recover)
782

    
783
def last_insert_id(db):
784
    module = util.root_module(db.db)
785
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
786
    elif module == 'MySQLdb': return db.insert_id()
787
    else: return None
788

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

    
821
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
822
    '''For params, see mk_flatten_mapping()
823
    @return See return value of mk_flatten_mapping()
824
    '''
825
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
826
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
827
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
828
        into=into, add_indexes_=True)
829
    return dict(items)
830

    
831
def mk_track_data_error(db, errors_table, cols, value, error_code, error):
832
    assert cols != ()
833
    
834
    cols = map(sql_gen.to_name_only_col, cols)
835
    
836
    columns_cols = ['column']
837
    columns = sql_gen.NamedValues('columns', columns_cols,
838
        [[c.name] for c in cols])
839
    values_cols = ['value', 'error_code', 'error']
840
    values = sql_gen.NamedValues('values', values_cols,
841
        [value, error_code, error])
842
    
843
    select_cols = columns_cols+values_cols
844
    name_only_cols = map(sql_gen.to_name_only_col, select_cols)
845
    errors_table = sql_gen.NamedTable('errors', errors_table)
846
    joins = [columns, sql_gen.Join(values, type_='CROSS'),
847
        sql_gen.Join(errors_table, dict(zip(name_only_cols, select_cols)),
848
        sql_gen.filter_out)]
849
    
850
    return mk_insert_select(db, errors_table, name_only_cols,
851
        mk_select(db, joins, select_cols, order_by=None))
852

    
853
def track_data_error(db, errors_table, cols, *args, **kw_args):
854
    '''
855
    @param errors_table If None, does nothing.
856
    '''
857
    if errors_table == None or cols == (): return
858
    run_query(db, mk_track_data_error(db, errors_table, cols, *args, **kw_args),
859
        cacheable=True, log_level=4)
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
        query = '''\
883
CREATE FUNCTION '''+function.to_str(db)+'''(value text)
884
RETURNS '''+type_+'''
885
LANGUAGE plpgsql
886
STRICT
887
AS $$
888
BEGIN
889
    /* The explicit cast to the return type is needed to make the cast happen
890
    inside the try block. (Implicit casts to the return type happen at the end
891
    of the function, outside any block.) */
892
    RETURN value::'''+type_+''';
893
EXCEPTION
894
    WHEN data_exception THEN
895
        -- Save error in errors table.
896
        -- Insert the value and error for *each* source column.
897
'''+mk_track_data_error(db, errors_table, srcs,
898
    *map(sql_gen.CustomCode, ['value', 'SQLSTATE', 'SQLERRM']))+''';
899
        
900
        RAISE WARNING '%', SQLERRM;
901
        RETURN NULL;
902
END;
903
$$;
904
'''
905
        
906
        # Create function
907
        try:
908
            run_query(db, query, recover=True, cacheable=True,
909
                log_ignore_excs=(DuplicateException,))
910
            break # successful
911
        except DuplicateException:
912
            function.name = next_version(function.name)
913
            # try again with next version of name
914
    
915
    return sql_gen.FunctionCall(function, col)
916

    
917
##### Database structure queries
918

    
919
def table_row_count(db, table, recover=None):
920
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
921
        order_by=None, start=0), recover=recover, log_level=3))
922

    
923
def table_cols(db, table, recover=None):
924
    return list(col_names(select(db, table, limit=0, order_by=None,
925
        recover=recover, log_level=4)))
926

    
927
def pkey(db, table, recover=None):
928
    '''Assumed to be first column in table'''
929
    return table_cols(db, table, recover)[0]
930

    
931
not_null_col = 'not_null_col'
932

    
933
def table_not_null_col(db, table, recover=None):
934
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
935
    if not_null_col in table_cols(db, table, recover): return not_null_col
936
    else: return pkey(db, table, recover)
937

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

    
979
def constraint_cols(db, table, constraint):
980
    module = util.root_module(db.db)
981
    if module == 'psycopg2':
982
        return list(values(run_query(db, '''\
983
SELECT attname
984
FROM pg_constraint
985
JOIN pg_class ON pg_class.oid = conrelid
986
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
987
WHERE
988
    relname = '''+db.esc_value(table)+'''
989
    AND conname = '''+db.esc_value(constraint)+'''
990
ORDER BY attnum
991
'''
992
            )))
993
    else: raise NotImplementedError("Can't list constraint columns for "+module+
994
        ' database')
995

    
996
row_num_col = '_row_num'
997

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

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

    
1068
def add_not_null(db, col):
1069
    table = col.table
1070
    col = sql_gen.to_name_only_col(col)
1071
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1072
        +col.to_str(db)+' SET NOT NULL', cacheable=True)
1073

    
1074
def add_index_col(db, col, suffix, expr, nullable=True):
1075
    if sql_gen.index_col(col) != None: return # already has index col
1076
    
1077
    new_col = sql_gen.suffixed_col(col, suffix)
1078
    
1079
    # Add column
1080
    while True:
1081
        new_typed_col = sql_gen.TypedCol(new_col.name, db.col_info(col).type)
1082
        try:
1083
            add_col(db, col.table, new_typed_col,
1084
                log_ignore_excs=(DuplicateException,))
1085
            break
1086
        except DuplicateException:
1087
            new_col.name = next_version(new_col.name)
1088
            # try again with next version of name
1089
    
1090
    update(db, col.table, [(new_col, expr)])
1091
    if not nullable: add_not_null(db, new_col)
1092
    add_index(db, new_col)
1093
    
1094
    col.table.index_cols[col.name] = new_col
1095

    
1096
def ensure_not_null(db, col):
1097
    '''For params, see sql_gen.ensure_not_null()'''
1098
    expr = sql_gen.ensure_not_null(db, col)
1099
    
1100
    # If nullable column in a temp table, add separate column instead
1101
    if sql_gen.is_temp_col(col) and isinstance(expr, sql_gen.EnsureNotNull):
1102
        add_index_col(db, col, '::NOT NULL', expr, nullable=False)
1103
        expr = sql_gen.index_col(col)
1104
    
1105
    return expr
1106

    
1107
already_indexed = object() # tells add_indexes() the pkey has already been added
1108

    
1109
def add_indexes(db, table, has_pkey=True):
1110
    '''Adds an index on all columns in a table.
1111
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1112
        index should be added on the first column.
1113
        * If already_indexed, the pkey is assumed to have already been added
1114
    '''
1115
    cols = table_cols(db, table)
1116
    if has_pkey:
1117
        if has_pkey is not already_indexed: add_pkey(db, table)
1118
        cols = cols[1:]
1119
    for col in cols: add_index(db, col, table)
1120

    
1121
def add_col(db, table, col, **kw_args):
1122
    assert isinstance(col, sql_gen.TypedCol)
1123
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '
1124
        +col.to_str(db), recover=True, cacheable=True, **kw_args)
1125

    
1126
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1127
    constraints='PRIMARY KEY')
1128

    
1129
def add_row_num(db, table):
1130
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1131
    be the primary key.'''
1132
    add_col(db, table, row_num_typed_col, log_level=3)
1133

    
1134
def cast_temp_col(db, type_, col, errors_table=None):
1135
    '''Like cast(), but creates a new column with the cast values if the input
1136
    is a column.
1137
    @return The new column or cast value
1138
    '''
1139
    def cast_(col): return cast(db, type_, col, errors_table)
1140
    
1141
    try: col = sql_gen.underlying_col(col)
1142
    except sql_gen.NoUnderlyingTableException: return sql_gen.wrap(cast_, col)
1143
    
1144
    table = col.table
1145
    new_col = sql_gen.Col(sql_gen.concat(col.name, '::'+type_), table, col.srcs)
1146
    expr = cast_(col)
1147
    add_col(db, table, sql_gen.TypedCol(new_col.name, type_))
1148
    update(db, table, [(new_col, expr)])
1149
    add_index(db, new_col)
1150
    
1151
    return new_col
1152

    
1153
def drop_table(db, table):
1154
    table = sql_gen.as_Table(table)
1155
    return run_query(db, 'DROP TABLE IF EXISTS '+table.to_str(db)+' CASCADE')
1156

    
1157
def create_table(db, table, cols, has_pkey=True, col_indexes=True):
1158
    '''Creates a table.
1159
    @param cols [sql_gen.TypedCol,...] The column names and types
1160
    @param has_pkey If set, the first column becomes the primary key.
1161
    @param col_indexes bool|[ref]
1162
        * If True, indexes will be added on all non-pkey columns.
1163
        * If a list reference, [0] will be set to a function to do this.
1164
          This can be used to delay index creation until the table is populated.
1165
    '''
1166
    table = sql_gen.as_Table(table)
1167
    
1168
    if has_pkey:
1169
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1170
        pkey.constraints = 'PRIMARY KEY'
1171
    
1172
    str_ = 'CREATE TABLE '+table.to_str(db)+' (\n'
1173
    str_ += '\n, '.join(v.to_str(db) for v in cols)
1174
    str_ += '\n);\n'
1175
    run_query(db, str_, cacheable=True, log_level=2)
1176
    
1177
    # Add indexes
1178
    if has_pkey: has_pkey = already_indexed
1179
    def add_indexes_(): add_indexes(db, table, has_pkey)
1180
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1181
    elif col_indexes: add_indexes_() # add now
1182

    
1183
def vacuum(db, table):
1184
    table = sql_gen.as_Table(table)
1185
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1186
        log_level=3))
1187

    
1188
def truncate(db, table, schema='public', **kw_args):
1189
    '''For params, see run_query()'''
1190
    table = sql_gen.as_Table(table, schema)
1191
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1192

    
1193
def empty_temp(db, tables):
1194
    if db.debug_temp: return # leave temp tables there for debugging
1195
    tables = lists.mk_seq(tables)
1196
    for table in tables: truncate(db, table, log_level=3)
1197

    
1198
def tables(db, schema_like='public', table_like='%', exact=False):
1199
    if exact: compare = '='
1200
    else: compare = 'LIKE'
1201
    
1202
    module = util.root_module(db.db)
1203
    if module == 'psycopg2':
1204
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1205
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1206
        return values(select(db, 'pg_tables', ['tablename'], conds,
1207
            order_by='tablename', log_level=4))
1208
    elif module == 'MySQLdb':
1209
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1210
            , cacheable=True, log_level=4))
1211
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1212

    
1213
def table_exists(db, table):
1214
    table = sql_gen.as_Table(table)
1215
    return list(tables(db, table.schema, table.name, exact=True)) != []
1216

    
1217
def function_exists(db, function):
1218
    function = sql_gen.as_Function(function)
1219
    
1220
    info_table = sql_gen.Table('routines', 'information_schema')
1221
    conds = [('routine_name', function.name)]
1222
    schema = function.schema
1223
    if schema != None: conds.append(('routine_schema', schema))
1224
    # Exclude trigger functions, since they cannot be called directly
1225
    conds.append(('data_type', sql_gen.CompareCond('trigger', '!=')))
1226
    
1227
    return list(values(select(db, info_table, ['routine_name'], conds,
1228
        order_by='routine_schema', limit=1, log_level=4))) != []
1229
        # TODO: order_by search_path schema order
1230

    
1231
def errors_table(db, table, if_exists=True):
1232
    '''
1233
    @param if_exists If set, returns None if the errors table doesn't exist
1234
    @return None|sql_gen.Table
1235
    '''
1236
    table = sql_gen.as_Table(table)
1237
    if table.srcs != (): table = table.srcs[0]
1238
    
1239
    errors_table = sql_gen.suffixed_table(table, '.errors')
1240
    if if_exists and not table_exists(db, errors_table): return None
1241
    return errors_table
1242

    
1243
##### Database management
1244

    
1245
def empty_db(db, schema='public', **kw_args):
1246
    '''For kw_args, see tables()'''
1247
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1248

    
1249
##### Heuristic queries
1250

    
1251
def put(db, table, row, pkey_=None, row_ct_ref=None):
1252
    '''Recovers from errors.
1253
    Only works under PostgreSQL (uses INSERT RETURNING).
1254
    '''
1255
    row = sql_gen.ColDict(db, table, row)
1256
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
1257
    
1258
    try:
1259
        cur = insert(db, table, row, pkey_, recover=True)
1260
        if row_ct_ref != None and cur.rowcount >= 0:
1261
            row_ct_ref[0] += cur.rowcount
1262
        return value(cur)
1263
    except DuplicateKeyException, e:
1264
        row = sql_gen.ColDict(db, table,
1265
            util.dict_subset_right_join(row, e.cols))
1266
        return value(select(db, table, [pkey_], row, recover=True))
1267

    
1268
def get(db, table, row, pkey, row_ct_ref=None, create=False):
1269
    '''Recovers from errors'''
1270
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
1271
    except StopIteration:
1272
        if not create: raise
1273
        return put(db, table, row, pkey, row_ct_ref) # insert new row
1274

    
1275
def is_func_result(col):
1276
    return col.table.name.find('(') >= 0 and col.name == 'result'
1277

    
1278
def into_table_name(out_table, in_tables0, mapping, is_func):
1279
    def in_col_str(in_col):
1280
        in_col = sql_gen.remove_col_rename(in_col)
1281
        if isinstance(in_col, sql_gen.Col):
1282
            table = in_col.table
1283
            if table == in_tables0:
1284
                in_col = sql_gen.to_name_only_col(in_col)
1285
            elif is_func_result(in_col): in_col = table # omit col name
1286
        return str(in_col)
1287
    
1288
    str_ = str(out_table)
1289
    if is_func:
1290
        str_ += '('
1291
        
1292
        try: value_in_col = mapping['value']
1293
        except KeyError:
1294
            str_ += ', '.join((str(k)+'='+in_col_str(v)
1295
                for k, v in mapping.iteritems()))
1296
        else: str_ += in_col_str(value_in_col)
1297
        
1298
        str_ += ')'
1299
    else:
1300
        out_col = 'rank'
1301
        try: in_col = mapping[out_col]
1302
        except KeyError: str_ += '_pkeys'
1303
        else: # has a rank column, so hierarchical
1304
            str_ += '['+str(out_col)+'='+in_col_str(in_col)+']'
1305
    return str_
1306

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

    
1565
##### Data cleanup
1566

    
1567
def cleanup_table(db, table, cols):
1568
    table = sql_gen.as_Table(table)
1569
    cols = map(sql_gen.as_Col, cols)
1570
    
1571
    expr = ('nullif(nullif(trim(both from %s), '+db.esc_value('')+'), '
1572
        +db.esc_value(r'\N')+')')
1573
    changes = [(v, sql_gen.CustomCode(expr % v.to_str(db)))
1574
        for v in cols]
1575
    
1576
    update(db, table, changes)
(24-24/36)