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
            msg = exc.str_(e)
440
            
441
            match = re.search(r'duplicate key value violates unique constraint '
442
                r'"((_?[^\W_]+)_.+?)"', msg)
443
            if match:
444
                constraint, table = match.groups()
445
                cols = []
446
                if recover: # need auto-rollback to run index_cols()
447
                    try: cols = index_cols(db, table, constraint)
448
                    except NotImplementedError: pass
449
                raise DuplicateKeyException(constraint, cols, e)
450
            
451
            match = re.search(r'null value in column "(.+?)" violates not-null'
452
                r' constraint', msg)
453
            if match: raise NullValueException('NOT NULL', [match.group(1)], e)
454
            
455
            match = re.search(r'\b(?:invalid input (?:syntax|value)\b.*?'
456
                r'|date/time field value out of range): "(.+?)"\n'
457
                r'(?:(?s).*?)\bfunction "(.+?)"', msg)
458
            if match:
459
                value, name = match.groups()
460
                raise FunctionValueException(name, strings.to_unicode(value), e)
461
            
462
            match = re.search(r'column "(.+?)" is of type (.+?) but expression '
463
                r'is of type', msg)
464
            if match:
465
                col, type_ = match.groups()
466
                raise MissingCastException(type_, col, e)
467
            
468
            match = re.search(r'\b(\S+) "(.+?)".*? already exists', msg)
469
            if match:
470
                type_, name = match.groups()
471
                raise DuplicateException(type_, name, e)
472
            
473
            raise # no specific exception raised
474
    except log_ignore_excs:
475
        log_level += 2
476
        raise
477
    finally:
478
        if debug_msg_ref != None and debug_msg_ref[0] != None:
479
            db.log_debug(debug_msg_ref[0], log_level)
480

    
481
##### Basic queries
482

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

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

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

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

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

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

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

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

    
742
def insert_select(db, *args, **kw_args):
743
    '''For params, see mk_insert_select() and run_query_into()
744
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
745
        values in
746
    '''
747
    into = kw_args.pop('into', None)
748
    if into != None: kw_args['embeddable'] = True
749
    recover = kw_args.pop('recover', None)
750
    if kw_args.get('ignore', False): recover = True
751
    cacheable = kw_args.pop('cacheable', True)
752
    log_level = kw_args.pop('log_level', 2)
753
    
754
    return run_query_into(db, mk_insert_select(db, *args, **kw_args), into,
755
        recover=recover, cacheable=cacheable, log_level=log_level)
756

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

    
759
def insert(db, table, row, *args, **kw_args):
760
    '''For params, see insert_select()'''
761
    if lists.is_seq(row): cols = None
762
    else:
763
        cols = row.keys()
764
        row = row.values()
765
    row = list(row) # ensure that "== []" works
766
    
767
    if row == []: query = None
768
    else: query = sql_gen.Values(row).to_str(db)
769
    
770
    return insert_select(db, table, cols, query, *args, **kw_args)
771

    
772
def mk_update(db, table, changes=None, cond=None):
773
    '''
774
    @param changes [(col, new_value),...]
775
        * container can be any iterable type
776
        * col: sql_gen.Code|str (for col name)
777
        * new_value: sql_gen.Code|literal value
778
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
779
    @return str query
780
    '''
781
    query = 'UPDATE '+sql_gen.as_Table(table).to_str(db)+'\nSET\n'
782
    query += ',\n'.join((sql_gen.to_name_only_col(col, table).to_str(db)+' = '
783
        +sql_gen.as_Value(new_value).to_str(db) for col, new_value in changes))
784
    if cond != None: query += '\nWHERE\n'+cond.to_str(db)
785
    
786
    return query
787

    
788
def update(db, *args, **kw_args):
789
    '''For params, see mk_update() and run_query()'''
790
    recover = kw_args.pop('recover', None)
791
    
792
    return run_query(db, mk_update(db, *args, **kw_args), recover)
793

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

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

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

    
842
def mk_track_data_error(db, errors_table, cols, value, error_code, error):
843
    assert cols != ()
844
    
845
    cols = map(sql_gen.to_name_only_col, cols)
846
    
847
    columns_cols = ['column']
848
    columns = sql_gen.NamedValues('columns', columns_cols,
849
        [[c.name] for c in cols])
850
    values_cols = ['value', 'error_code', 'error']
851
    values = sql_gen.NamedValues('values', values_cols,
852
        [value, error_code, error])
853
    
854
    select_cols = columns_cols+values_cols
855
    name_only_cols = map(sql_gen.to_name_only_col, select_cols)
856
    errors_table = sql_gen.NamedTable('errors', errors_table)
857
    joins = [columns, sql_gen.Join(values, type_='CROSS'),
858
        sql_gen.Join(errors_table, dict(zip(name_only_cols, select_cols)),
859
        sql_gen.filter_out)]
860
    
861
    return mk_insert_select(db, errors_table, name_only_cols,
862
        mk_select(db, joins, select_cols, order_by=None))
863

    
864
def track_data_error(db, errors_table, cols, *args, **kw_args):
865
    '''
866
    @param errors_table If None, does nothing.
867
    '''
868
    if errors_table == None or cols == (): return
869
    run_query(db, mk_track_data_error(db, errors_table, cols, *args, **kw_args),
870
        cacheable=True, log_level=4)
871

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

    
928
##### Database structure queries
929

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

    
934
def table_cols(db, table, recover=None):
935
    return list(col_names(select(db, table, limit=0, order_by=None,
936
        recover=recover, log_level=4)))
937

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

    
942
not_null_col = 'not_null_col'
943

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

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

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

    
1007
row_num_col = '_row_num'
1008

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

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

    
1079
def add_not_null(db, col):
1080
    table = col.table
1081
    col = sql_gen.to_name_only_col(col)
1082
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1083
        +col.to_str(db)+' SET NOT NULL', cacheable=True)
1084

    
1085
def add_index_col(db, col, suffix, expr, nullable=True):
1086
    if sql_gen.index_col(col) != None: return # already has index col
1087
    
1088
    new_col = sql_gen.suffixed_col(col, suffix)
1089
    
1090
    # Add column
1091
    while True:
1092
        new_typed_col = sql_gen.TypedCol(new_col.name, db.col_info(col).type)
1093
        try:
1094
            add_col(db, col.table, new_typed_col,
1095
                log_ignore_excs=(DuplicateException,))
1096
            break
1097
        except DuplicateException:
1098
            new_col.name = next_version(new_col.name)
1099
            # try again with next version of name
1100
    
1101
    update(db, col.table, [(new_col, expr)])
1102
    if not nullable: add_not_null(db, new_col)
1103
    add_index(db, new_col)
1104
    
1105
    col.table.index_cols[col.name] = new_col
1106

    
1107
def ensure_not_null(db, col):
1108
    '''For params, see sql_gen.ensure_not_null()'''
1109
    expr = sql_gen.ensure_not_null(db, col)
1110
    
1111
    # If nullable column in a temp table, add separate column instead
1112
    if sql_gen.is_temp_col(col) and isinstance(expr, sql_gen.EnsureNotNull):
1113
        add_index_col(db, col, '::NOT NULL', expr, nullable=False)
1114
        expr = sql_gen.index_col(col)
1115
    
1116
    return expr
1117

    
1118
already_indexed = object() # tells add_indexes() the pkey has already been added
1119

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

    
1132
def add_col(db, table, col, **kw_args):
1133
    assert isinstance(col, sql_gen.TypedCol)
1134
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '
1135
        +col.to_str(db), recover=True, cacheable=True, **kw_args)
1136

    
1137
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1138
    constraints='PRIMARY KEY')
1139

    
1140
def add_row_num(db, table):
1141
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1142
    be the primary key.'''
1143
    add_col(db, table, row_num_typed_col, log_level=3)
1144

    
1145
def cast_temp_col(db, type_, col, errors_table=None):
1146
    '''Like cast(), but creates a new column with the cast values if the input
1147
    is a column.
1148
    @return The new column or cast value
1149
    '''
1150
    def cast_(col): return cast(db, type_, col, errors_table)
1151
    
1152
    try: col = sql_gen.underlying_col(col)
1153
    except sql_gen.NoUnderlyingTableException: return sql_gen.wrap(cast_, col)
1154
    
1155
    table = col.table
1156
    new_col = sql_gen.Col(sql_gen.concat(col.name, '::'+type_), table, col.srcs)
1157
    expr = cast_(col)
1158
    add_col(db, table, sql_gen.TypedCol(new_col.name, type_))
1159
    update(db, table, [(new_col, expr)])
1160
    add_index(db, new_col)
1161
    
1162
    return new_col
1163

    
1164
def drop_table(db, table):
1165
    table = sql_gen.as_Table(table)
1166
    return run_query(db, 'DROP TABLE IF EXISTS '+table.to_str(db)+' CASCADE')
1167

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

    
1194
def vacuum(db, table):
1195
    table = sql_gen.as_Table(table)
1196
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1197
        log_level=3))
1198

    
1199
def truncate(db, table, schema='public', **kw_args):
1200
    '''For params, see run_query()'''
1201
    table = sql_gen.as_Table(table, schema)
1202
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1203

    
1204
def empty_temp(db, tables):
1205
    if db.debug_temp: return # leave temp tables there for debugging
1206
    tables = lists.mk_seq(tables)
1207
    for table in tables: truncate(db, table, log_level=3)
1208

    
1209
def tables(db, schema_like='public', table_like='%', exact=False):
1210
    if exact: compare = '='
1211
    else: compare = 'LIKE'
1212
    
1213
    module = util.root_module(db.db)
1214
    if module == 'psycopg2':
1215
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1216
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1217
        return values(select(db, 'pg_tables', ['tablename'], conds,
1218
            order_by='tablename', log_level=4))
1219
    elif module == 'MySQLdb':
1220
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1221
            , cacheable=True, log_level=4))
1222
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1223

    
1224
def table_exists(db, table):
1225
    table = sql_gen.as_Table(table)
1226
    return list(tables(db, table.schema, table.name, exact=True)) != []
1227

    
1228
def function_exists(db, function):
1229
    function = sql_gen.as_Function(function)
1230
    
1231
    info_table = sql_gen.Table('routines', 'information_schema')
1232
    conds = [('routine_name', function.name)]
1233
    schema = function.schema
1234
    if schema != None: conds.append(('routine_schema', schema))
1235
    # Exclude trigger functions, since they cannot be called directly
1236
    conds.append(('data_type', sql_gen.CompareCond('trigger', '!=')))
1237
    
1238
    return list(values(select(db, info_table, ['routine_name'], conds,
1239
        order_by='routine_schema', limit=1, log_level=4))) != []
1240
        # TODO: order_by search_path schema order
1241

    
1242
def errors_table(db, table, if_exists=True):
1243
    '''
1244
    @param if_exists If set, returns None if the errors table doesn't exist
1245
    @return None|sql_gen.Table
1246
    '''
1247
    table = sql_gen.as_Table(table)
1248
    if table.srcs != (): table = table.srcs[0]
1249
    
1250
    errors_table = sql_gen.suffixed_table(table, '.errors')
1251
    if if_exists and not table_exists(db, errors_table): return None
1252
    return errors_table
1253

    
1254
##### Database management
1255

    
1256
def empty_db(db, schema='public', **kw_args):
1257
    '''For kw_args, see tables()'''
1258
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1259

    
1260
##### Heuristic queries
1261

    
1262
def put(db, table, row, pkey_=None, row_ct_ref=None):
1263
    '''Recovers from errors.
1264
    Only works under PostgreSQL (uses INSERT RETURNING).
1265
    '''
1266
    row = sql_gen.ColDict(db, table, row)
1267
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
1268
    
1269
    try:
1270
        cur = insert(db, table, row, pkey_, recover=True)
1271
        if row_ct_ref != None and cur.rowcount >= 0:
1272
            row_ct_ref[0] += cur.rowcount
1273
        return value(cur)
1274
    except DuplicateKeyException, e:
1275
        row = sql_gen.ColDict(db, table,
1276
            util.dict_subset_right_join(row, e.cols))
1277
        return value(select(db, table, [pkey_], row, recover=True))
1278

    
1279
def get(db, table, row, pkey, row_ct_ref=None, create=False):
1280
    '''Recovers from errors'''
1281
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
1282
    except StopIteration:
1283
        if not create: raise
1284
        return put(db, table, row, pkey, row_ct_ref) # insert new row
1285

    
1286
def is_func_result(col):
1287
    return col.table.name.find('(') >= 0 and col.name == 'result'
1288

    
1289
def into_table_name(out_table, in_tables0, mapping, is_func):
1290
    def in_col_str(in_col):
1291
        in_col = sql_gen.remove_col_rename(in_col)
1292
        if isinstance(in_col, sql_gen.Col):
1293
            table = in_col.table
1294
            if table == in_tables0:
1295
                in_col = sql_gen.to_name_only_col(in_col)
1296
            elif is_func_result(in_col): in_col = table # omit col name
1297
        return str(in_col)
1298
    
1299
    str_ = str(out_table)
1300
    if is_func:
1301
        str_ += '('
1302
        
1303
        try: value_in_col = mapping['value']
1304
        except KeyError:
1305
            str_ += ', '.join((str(k)+'='+in_col_str(v)
1306
                for k, v in mapping.iteritems()))
1307
        else: str_ += in_col_str(value_in_col)
1308
        
1309
        str_ += ')'
1310
    else:
1311
        out_col = 'rank'
1312
        try: in_col = mapping[out_col]
1313
        except KeyError: str_ += '_pkeys'
1314
        else: # has a rank column, so hierarchical
1315
            str_ += '['+str(out_col)+'='+in_col_str(in_col)+']'
1316
    return str_
1317

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

    
1575
##### Data cleanup
1576

    
1577
def cleanup_table(db, table, cols):
1578
    table = sql_gen.as_Table(table)
1579
    cols = map(sql_gen.as_Col, cols)
1580
    
1581
    expr = ('nullif(nullif(trim(both from %s), '+db.esc_value('')+'), '
1582
        +db.esc_value(r'\N')+')')
1583
    changes = [(v, sql_gen.CustomCode(expr % v.to_str(db)))
1584
        for v in cols]
1585
    
1586
    update(db, table, changes)
(24-24/36)