Project

General

Profile

1
# Database access
2

    
3
import copy
4
import re
5
import time
6
import warnings
7

    
8
import exc
9
import dicts
10
import iters
11
import lists
12
import profiling
13
from Proxy import Proxy
14
import rand
15
import sql_gen
16
import strings
17
import util
18

    
19
##### Exceptions
20

    
21
def get_cur_query(cur, input_query=None):
22
    raw_query = None
23
    if hasattr(cur, 'query'): raw_query = cur.query
24
    elif hasattr(cur, '_last_executed'): raw_query = cur._last_executed
25
    
26
    if raw_query != None: return raw_query
27
    else: return '[input] '+strings.ustr(input_query)
28

    
29
def _add_cursor_info(e, *args, **kw_args):
30
    '''For params, see get_cur_query()'''
31
    exc.add_msg(e, 'query: '+strings.ustr(get_cur_query(*args, **kw_args)))
32

    
33
class DbException(exc.ExceptionWithCause):
34
    def __init__(self, msg, cause=None, cur=None):
35
        exc.ExceptionWithCause.__init__(self, msg, cause, cause_newline=True)
36
        if cur != None: _add_cursor_info(self, cur)
37

    
38
class ExceptionWithName(DbException):
39
    def __init__(self, name, cause=None):
40
        DbException.__init__(self, 'for name: '
41
            +strings.as_tt(strings.ustr(name)), cause)
42
        self.name = name
43

    
44
class ExceptionWithValue(DbException):
45
    def __init__(self, value, cause=None):
46
        DbException.__init__(self, 'for value: '
47
            +strings.as_tt(strings.urepr(value)), cause)
48
        self.value = value
49

    
50
class ExceptionWithNameType(DbException):
51
    def __init__(self, type_, name, cause=None):
52
        DbException.__init__(self, 'for type: '+strings.as_tt(strings.ustr(
53
            type_))+'; name: '+strings.as_tt(name), cause)
54
        self.type = type_
55
        self.name = name
56

    
57
class ConstraintException(DbException):
58
    def __init__(self, name, cond, cols, cause=None):
59
        msg = 'Violated '+strings.as_tt(name)+' constraint'
60
        if cond != None: msg += ' with condition '+strings.as_tt(cond)
61
        if cols != []: msg += ' on columns: '+strings.as_tt(', '.join(cols))
62
        DbException.__init__(self, msg, cause)
63
        self.name = name
64
        self.cond = cond
65
        self.cols = cols
66

    
67
class MissingCastException(DbException):
68
    def __init__(self, type_, col=None, cause=None):
69
        msg = 'Missing cast to type '+strings.as_tt(type_)
70
        if col != None: msg += ' on column: '+strings.as_tt(col)
71
        DbException.__init__(self, msg, cause)
72
        self.type = type_
73
        self.col = col
74

    
75
class EncodingException(ExceptionWithName): pass
76

    
77
class DuplicateKeyException(ConstraintException): pass
78

    
79
class NullValueException(ConstraintException): pass
80

    
81
class CheckException(ConstraintException): pass
82

    
83
class InvalidValueException(ExceptionWithValue): pass
84

    
85
class InvalidTypeException(ExceptionWithNameType): pass
86

    
87
class DuplicateException(ExceptionWithNameType): pass
88

    
89
class DoesNotExistException(ExceptionWithNameType): pass
90

    
91
class EmptyRowException(DbException): pass
92

    
93
##### Warnings
94

    
95
class DbWarning(UserWarning): pass
96

    
97
##### Result retrieval
98

    
99
def col_names(cur): return (col[0] for col in cur.description)
100

    
101
def rows(cur): return iter(lambda: cur.fetchone(), None)
102

    
103
def consume_rows(cur):
104
    '''Used to fetch all rows so result will be cached'''
105
    iters.consume_iter(rows(cur))
106

    
107
def next_row(cur): return rows(cur).next()
108

    
109
def row(cur):
110
    row_ = next_row(cur)
111
    consume_rows(cur)
112
    return row_
113

    
114
def next_value(cur): return next_row(cur)[0]
115

    
116
def value(cur): return row(cur)[0]
117

    
118
def values(cur): return iters.func_iter(lambda: next_value(cur))
119

    
120
def value_or_none(cur):
121
    try: return value(cur)
122
    except StopIteration: return None
123

    
124
##### Escaping
125

    
126
def esc_name_by_module(module, name):
127
    if module == 'psycopg2' or module == None: quote = '"'
128
    elif module == 'MySQLdb': quote = '`'
129
    else: raise NotImplementedError("Can't escape name for "+module+' database')
130
    return sql_gen.esc_name(name, quote)
131

    
132
def esc_name_by_engine(engine, name, **kw_args):
133
    return esc_name_by_module(db_engines[engine][0], name, **kw_args)
134

    
135
def esc_name(db, name, **kw_args):
136
    return esc_name_by_module(util.root_module(db.db), name, **kw_args)
137

    
138
def qual_name(db, schema, table):
139
    def esc_name_(name): return esc_name(db, name)
140
    table = esc_name_(table)
141
    if schema != None: return esc_name_(schema)+'.'+table
142
    else: return table
143

    
144
##### Database connections
145

    
146
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
147

    
148
db_engines = {
149
    'MySQL': ('MySQLdb', {'password': 'passwd', 'database': 'db'}),
150
    'PostgreSQL': ('psycopg2', {}),
151
}
152

    
153
DatabaseErrors_set = set([DbException])
154
DatabaseErrors = tuple(DatabaseErrors_set)
155

    
156
def _add_module(module):
157
    DatabaseErrors_set.add(module.DatabaseError)
158
    global DatabaseErrors
159
    DatabaseErrors = tuple(DatabaseErrors_set)
160

    
161
def db_config_str(db_config):
162
    return db_config['engine']+' database '+db_config['database']
163

    
164
log_debug_none = lambda msg, level=2: None
165

    
166
class DbConn:
167
    def __init__(self, db_config, autocommit=True, caching=True,
168
        log_debug=log_debug_none, debug_temp=False, src=None):
169
        '''
170
        @param debug_temp Whether temporary objects should instead be permanent.
171
            This assists in debugging the internal objects used by the program.
172
        @param src In autocommit mode, will be included in a comment in every
173
            query, to help identify the data source in pg_stat_activity.
174
        '''
175
        self.db_config = db_config
176
        self.autocommit = autocommit
177
        self.caching = caching
178
        self.log_debug = log_debug
179
        self.debug = log_debug != log_debug_none
180
        self.debug_temp = debug_temp
181
        self.src = src
182
        self.autoanalyze = False
183
        self.autoexplain = False
184
        self.profile_row_ct = None
185
        
186
        self._savepoint = 0
187
        self._reset()
188
    
189
    def __getattr__(self, name):
190
        if name == '__dict__': raise Exception('getting __dict__')
191
        if name == 'db': return self._db()
192
        else: raise AttributeError()
193
    
194
    def __getstate__(self):
195
        state = copy.copy(self.__dict__) # shallow copy
196
        state['log_debug'] = None # don't pickle the debug callback
197
        state['_DbConn__db'] = None # don't pickle the connection
198
        return state
199
    
200
    def clear_cache(self): self.query_results = {}
201
    
202
    def _reset(self):
203
        self.clear_cache()
204
        assert self._savepoint == 0
205
        self._notices_seen = set()
206
        self.__db = None
207
    
208
    def connected(self): return self.__db != None
209
    
210
    def close(self):
211
        if not self.connected(): return
212
        
213
        # Record that the automatic transaction is now closed
214
        self._savepoint -= 1
215
        
216
        self.db.close()
217
        self._reset()
218
    
219
    def reconnect(self):
220
        # Do not do this in test mode as it would roll back everything
221
        if self.autocommit: self.close()
222
        # Connection will be reopened automatically on first query
223
    
224
    def _db(self):
225
        if self.__db == None:
226
            # Process db_config
227
            db_config = self.db_config.copy() # don't modify input!
228
            schemas = db_config.pop('schemas', None)
229
            module_name, mappings = db_engines[db_config.pop('engine')]
230
            module = __import__(module_name)
231
            _add_module(module)
232
            for orig, new in mappings.iteritems():
233
                try: util.rename_key(db_config, orig, new)
234
                except KeyError: pass
235
            
236
            # Connect
237
            self.__db = module.connect(**db_config)
238
            
239
            # Record that a transaction is already open
240
            self._savepoint += 1
241
            
242
            # Configure connection
243
            if hasattr(self.db, 'set_isolation_level'):
244
                import psycopg2.extensions
245
                self.db.set_isolation_level(
246
                    psycopg2.extensions.ISOLATION_LEVEL_READ_COMMITTED)
247
            if schemas != None:
248
                search_path = [self.esc_name(s) for s in schemas.split(',')]
249
                run_query(self, 'SET search_path TO '+(','.join(search_path)),
250
                    log_level=3)
251
        
252
        return self.__db
253
    
254
    class DbCursor(Proxy):
255
        def __init__(self, outer):
256
            Proxy.__init__(self, outer.db.cursor())
257
            self.outer = outer
258
            self.query_results = outer.query_results
259
            self.query_lookup = None
260
            self.result = []
261
        
262
        def execute(self, query):
263
            self._is_insert = query.startswith('INSERT')
264
            self.query_lookup = query
265
            try:
266
                try: cur = self.inner.execute(query)
267
                finally: self.query = get_cur_query(self.inner, query)
268
            except Exception, e:
269
                self.result = e # cache the exception as the result
270
                self._cache_result()
271
                raise
272
            
273
            # Always cache certain queries
274
            query = sql_gen.lstrip(query)
275
            if query.startswith('CREATE') or query.startswith('ALTER'):
276
                # structural changes
277
                # Rest of query must be unique in the face of name collisions,
278
                # so don't cache ADD COLUMN unless it has distinguishing comment
279
                if query.find('ADD COLUMN') < 0 or query.endswith('*/'):
280
                    self._cache_result()
281
            elif self.rowcount == 0 and query.startswith('SELECT'): # empty
282
                consume_rows(self) # fetch all rows so result will be cached
283
            
284
            return cur
285
        
286
        def fetchone(self):
287
            row = self.inner.fetchone()
288
            if row != None: self.result.append(row)
289
            # otherwise, fetched all rows
290
            else: self._cache_result()
291
            return row
292
        
293
        def _cache_result(self):
294
            # For inserts that return a result set, don't cache result set since
295
            # inserts are not idempotent. Other non-SELECT queries don't have
296
            # their result set read, so only exceptions will be cached (an
297
            # invalid query will always be invalid).
298
            if self.query_results != None and (not self._is_insert
299
                or isinstance(self.result, Exception)):
300
                
301
                assert self.query_lookup != None
302
                self.query_results[self.query_lookup] = self.CacheCursor(
303
                    util.dict_subset(dicts.AttrsDictView(self),
304
                    ['query', 'result', 'rowcount', 'description']))
305
        
306
        class CacheCursor:
307
            def __init__(self, cached_result): self.__dict__ = cached_result
308
            
309
            def execute(self, *args, **kw_args):
310
                if isinstance(self.result, Exception): raise self.result
311
                # otherwise, result is a rows list
312
                self.iter = iter(self.result)
313
            
314
            def fetchone(self):
315
                try: return self.iter.next()
316
                except StopIteration: return None
317
    
318
    def esc_value(self, value):
319
        try: str_ = self.mogrify('%s', [value])
320
        except NotImplementedError, e:
321
            module = util.root_module(self.db)
322
            if module == 'MySQLdb':
323
                import _mysql
324
                str_ = _mysql.escape_string(value)
325
            else: raise e
326
        return strings.to_unicode(str_)
327
    
328
    def esc_name(self, name): return esc_name(self, name) # calls global func
329
    
330
    def std_code(self, str_):
331
        '''Standardizes SQL code.
332
        * Ensures that string literals are prefixed by `E`
333
        '''
334
        if str_.startswith("'"): str_ = 'E'+str_
335
        return str_
336
    
337
    def can_mogrify(self):
338
        module = util.root_module(self.db)
339
        return module == 'psycopg2'
340
    
341
    def mogrify(self, query, params=None):
342
        if self.can_mogrify(): return self.db.cursor().mogrify(query, params)
343
        else: raise NotImplementedError("Can't mogrify query")
344
    
345
    def set_encoding(self, encoding):
346
        encoding_str = sql_gen.Literal(encoding)
347
        run_query(self, 'SET NAMES '+encoding_str.to_str(self))
348
    
349
    def print_notices(self):
350
        if hasattr(self.db, 'notices'):
351
            for msg in self.db.notices:
352
                if msg not in self._notices_seen:
353
                    self._notices_seen.add(msg)
354
                    self.log_debug(msg, level=2)
355
    
356
    def run_query(self, query, cacheable=False, log_level=2,
357
        debug_msg_ref=None):
358
        '''
359
        @param log_ignore_excs The log_level will be increased by 2 if the query
360
            throws one of these exceptions.
361
        @param debug_msg_ref If specified, the log message will be returned in
362
            this instead of being output. This allows you to filter log messages
363
            depending on the result of the query.
364
        '''
365
        assert query != None
366
        
367
        if self.autocommit and self.src != None:
368
            query = sql_gen.esc_comment(self.src)+'\t'+query
369
        
370
        if not self.caching: cacheable = False
371
        used_cache = False
372
        
373
        if self.debug:
374
            profiler = profiling.ItersProfiler(start_now=True, iter_text='row')
375
        try:
376
            # Get cursor
377
            if cacheable:
378
                try: cur = self.query_results[query]
379
                except KeyError: cur = self.DbCursor(self)
380
                else: used_cache = True
381
            else: cur = self.db.cursor()
382
            
383
            # Run query
384
            try: cur.execute(query)
385
            except Exception, e:
386
                _add_cursor_info(e, self, query)
387
                raise
388
            else: self.do_autocommit()
389
        finally:
390
            if self.debug:
391
                profiler.stop(self.profile_row_ct)
392
                
393
                ## Log or return query
394
                
395
                query = strings.ustr(get_cur_query(cur, query))
396
                # Put the src comment on a separate line in the log file
397
                query = query.replace('\t', '\n', 1)
398
                
399
                msg = 'DB query: '
400
                
401
                if used_cache: msg += 'cache hit'
402
                elif cacheable: msg += 'cache miss'
403
                else: msg += 'non-cacheable'
404
                
405
                msg += ':\n'+profiler.msg()+'\n'+strings.as_code(query, 'SQL')
406
                
407
                if debug_msg_ref != None: debug_msg_ref[0] = msg
408
                else: self.log_debug(msg, log_level)
409
                
410
                self.print_notices()
411
        
412
        return cur
413
    
414
    def is_cached(self, query): return query in self.query_results
415
    
416
    def with_autocommit(self, func):
417
        import psycopg2.extensions
418
        
419
        prev_isolation_level = self.db.isolation_level
420
        self.db.set_isolation_level(
421
            psycopg2.extensions.ISOLATION_LEVEL_AUTOCOMMIT)
422
        try: return func()
423
        finally: self.db.set_isolation_level(prev_isolation_level)
424
    
425
    def with_savepoint(self, func):
426
        top = self._savepoint == 0
427
        savepoint = 'level_'+str(self._savepoint)
428
        
429
        if self.debug:
430
            self.log_debug('Begin transaction', level=4)
431
            profiler = profiling.ItersProfiler(start_now=True, iter_text='row')
432
        
433
        # Must happen before running queries so they don't get autocommitted
434
        self._savepoint += 1
435
        
436
        if top: query = 'START TRANSACTION ISOLATION LEVEL READ COMMITTED'
437
        else: query = 'SAVEPOINT '+savepoint
438
        self.run_query(query, log_level=4)
439
        try:
440
            return func()
441
            if top: self.run_query('COMMIT', log_level=4)
442
        except:
443
            if top: query = 'ROLLBACK'
444
            else: query = 'ROLLBACK TO SAVEPOINT '+savepoint
445
            self.run_query(query, log_level=4)
446
            
447
            raise
448
        finally:
449
            # Always release savepoint, because after ROLLBACK TO SAVEPOINT,
450
            # "The savepoint remains valid and can be rolled back to again"
451
            # (http://www.postgresql.org/docs/8.3/static/sql-rollback-to.html).
452
            if not top:
453
                self.run_query('RELEASE SAVEPOINT '+savepoint, log_level=4)
454
            
455
            self._savepoint -= 1
456
            assert self._savepoint >= 0
457
            
458
            if self.debug:
459
                profiler.stop(self.profile_row_ct)
460
                self.log_debug('End transaction\n'+profiler.msg(), level=4)
461
            
462
            self.do_autocommit() # OK to do this after ROLLBACK TO SAVEPOINT
463
    
464
    def do_autocommit(self):
465
        '''Autocommits if outside savepoint'''
466
        assert self._savepoint >= 1
467
        if self.autocommit and self._savepoint == 1:
468
            self.log_debug('Autocommitting', level=4)
469
            self.db.commit()
470
    
471
    def col_info(self, col, cacheable=True):
472
        module = util.root_module(self.db)
473
        if module == 'psycopg2':
474
            qual_table = sql_gen.Literal(col.table.to_str(self))
475
            col_name_str = sql_gen.Literal(col.name)
476
            try:
477
                type_, is_array, default, nullable = row(run_query(self, '''\
478
SELECT
479
format_type(COALESCE(NULLIF(typelem, 0), pg_type.oid), -1) AS type
480
, typcategory = 'A' AS type_is_array
481
, pg_get_expr(pg_attrdef.adbin, attrelid, true) AS default
482
, NOT pg_attribute.attnotnull AS nullable
483
FROM pg_attribute
484
LEFT JOIN pg_type ON pg_type.oid = atttypid
485
LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
486
WHERE
487
attrelid = '''+qual_table.to_str(self)+'''::regclass
488
AND attname = '''+col_name_str.to_str(self)+'''
489
'''
490
                    , recover=True, cacheable=cacheable, log_level=4))
491
            except (DoesNotExistException, StopIteration):
492
                raise sql_gen.NoUnderlyingTableException(col)
493
            if is_array: type_ = sql_gen.ArrayType(type_)
494
        else:
495
            table = sql_gen.Table('columns', 'information_schema')
496
            cols = [sql_gen.Col('data_type'), sql_gen.Col('udt_name'),
497
                'column_default', sql_gen.Cast('boolean',
498
                sql_gen.Col('is_nullable'))]
499
            
500
            conds = [('table_name', col.table.name),
501
                ('column_name', strings.ustr(col.name))]
502
            schema = col.table.schema
503
            if schema != None: conds.append(('table_schema', schema))
504
            
505
            cur = select(self, table, cols, conds, order_by='table_schema',
506
                limit=1, cacheable=cacheable, log_level=4)
507
            try: type_, extra_type, default, nullable = row(cur)
508
            except StopIteration: raise sql_gen.NoUnderlyingTableException(col)
509
            if type_ == 'USER-DEFINED': type_ = extra_type
510
            elif type_ == 'ARRAY':
511
                type_ = sql_gen.ArrayType(strings.remove_prefix('_', extra_type,
512
                    require=True))
513
        
514
        if default != None: default = sql_gen.as_Code(default, self)
515
        return sql_gen.TypedCol(col.name, type_, default, nullable)
516
    
517
    def TempFunction(self, name):
518
        if self.debug_temp: schema = None
519
        else: schema = 'pg_temp'
520
        return sql_gen.Function(name, schema)
521

    
522
connect = DbConn
523

    
524
##### Recoverable querying
525

    
526
def parse_exception(db, e, recover=False):
527
    msg = strings.ustr(e.args[0])
528
    msg = re.sub(r'^(?:PL/Python: )?ValueError: ', r'', msg)
529
    
530
    match = re.match(r'^invalid byte sequence for encoding "(.+?)":', msg)
531
    if match:
532
        encoding, = match.groups()
533
        raise EncodingException(encoding, e)
534
    
535
    def make_DuplicateKeyException(constraint, e):
536
        cols = []
537
        cond = None
538
        if recover: # need auto-rollback to run index_cols()
539
            try:
540
                cols = index_cols(db, constraint)
541
                cond = index_cond(db, constraint)
542
            except NotImplementedError: pass
543
            except DatabaseErrors, e2: # e.g. "current transaction is aborted"
544
                exc.print_ex(e2)
545
                raise e
546
        return DuplicateKeyException(constraint, cond, cols, e)
547
    
548
    match = re.match(r'^duplicate key value violates unique constraint "(.+?)"',
549
        msg)
550
    if match:
551
        constraint, = match.groups()
552
        raise make_DuplicateKeyException(constraint, e)
553
    
554
    match = re.match(r'^could not create unique index "(.+?)"\n'
555
        r'DETAIL:  Key .+? is duplicated', msg)
556
    if match:
557
        constraint, = match.groups()
558
        raise DuplicateKeyException(constraint, None, [], e)
559
    
560
    match = re.match(r'^null value in column "(.+?)" violates not-null'
561
        r' constraint', msg)
562
    if match:
563
        col, = match.groups()
564
        raise NullValueException('NOT NULL', None, [col], e)
565
    
566
    match = re.match(r'^new row for relation "(.+?)" violates check '
567
        r'constraint "(.+?)"', msg)
568
    if match:
569
        table, constraint = match.groups()
570
        constraint = sql_gen.Col(constraint, table)
571
        cond = None
572
        if recover: # need auto-rollback to run constraint_cond()
573
            try: cond = constraint_cond(db, constraint)
574
            except NotImplementedError: pass
575
        raise CheckException(constraint.to_str(db), cond, [], e)
576
    
577
    match = re.match(r'^(?:invalid input (?:syntax|value)\b[^:]*'
578
        r'|.+? out of range)(?:: "(.+?)")?', msg)
579
    if match:
580
        value, = match.groups()
581
        value = util.do_ignore_none(strings.to_unicode, value)
582
        raise InvalidValueException(value, e)
583
    
584
    match = re.match(r'^column "(.+?)" is of type (.+?) but expression '
585
        r'is of type', msg)
586
    if match:
587
        col, type_ = match.groups()
588
        raise MissingCastException(type_, col, e)
589
    
590
    match = re.match(r'^could not determine polymorphic type because '
591
        r'input has type "unknown"', msg)
592
    if match: raise MissingCastException('text', None, e)
593
    
594
    # type mismatches
595
    match = re.match(r'^.+? types (.+?) and (.+?) cannot be matched', msg)
596
    if match:
597
        type0, type1 = match.groups()
598
        raise MissingCastException(type0, None, e)
599
    match = re.match(r'operator does not exist: (.+?) = (.+)', msg)
600
        # these appear when a staging table column is of the wrong type
601
    if match:
602
        type0, type1 = match.groups()
603
        raise MissingCastException(type0, None, e)
604
    
605
    match = re.match(r'^.*?\brelation "(.+?)" is not a (table)', msg)
606
    if match:
607
        name, type_ = match.groups()
608
        raise InvalidTypeException(type_, name, e)
609
    
610
    typed_name_re = r'^(\S+) ("?)(.+?)\2(?: of relation ".+?")?'
611
        # regexp must be followed with text for .*? to match properly
612
    
613
    match = re.match(typed_name_re+r'(?:\(.*?)? already exists', msg)
614
    if match:
615
        type_, quote, name = match.groups()
616
        raise DuplicateException(type_, name, e)
617
    
618
    match = re.match(r'more than one (\S+) named ""(.+?)""', msg)
619
    if match:
620
        type_, name = match.groups()
621
        raise DuplicateException(type_, name, e)
622
    
623
    # type mismatches which appear as "does not exist" errors
624
    match = re.match(typed_name_re+r' does not exist', msg)
625
    if match:
626
        type_, quote, name = match.groups()
627
        if type_ == 'function':
628
            match = re.match(r'^(.+?)\(.*\)$', name)
629
            if match: # includes params, so is call rather than cast to regproc
630
                function_name, = match.groups()
631
                func = sql_gen.Function(function_name)
632
                if function_exists(db, func) and msg.find('CAST') < 0:
633
                    # not found only because of a missing cast
634
                    try: type_ = function_param0_type(db, func)
635
                    except DuplicateException: type_ = 'text'
636
                    col = None
637
                    if type_ == 'anyelement': type_ = 'text'
638
                    elif type_ == 'hstore': # cast just the value param
639
                        type_ = 'text'
640
                        col = 'value'
641
                    raise MissingCastException(type_, col, e)
642
        raise DoesNotExistException(type_, name, e)
643
    
644
    raise # no specific exception raised
645

    
646
def with_savepoint(db, func): return db.with_savepoint(func)
647

    
648
def run_query(db, query, recover=None, cacheable=False, log_level=2,
649
    log_ignore_excs=None, **kw_args):
650
    '''For params, see DbConn.run_query()'''
651
    if recover == None: recover = False
652
    if log_ignore_excs == None: log_ignore_excs = ()
653
    log_ignore_excs = tuple(log_ignore_excs)
654
    debug_msg_ref = [None]
655
    
656
    query = with_explain_comment(db, query)
657
    
658
    try:
659
        try:
660
            def run(): return db.run_query(query, cacheable, log_level,
661
                debug_msg_ref, **kw_args)
662
            if recover and not db.is_cached(query):
663
                return with_savepoint(db, run)
664
            else: return run() # don't need savepoint if cached
665
        except Exception, e:
666
            # Give failed EXPLAIN approximately the log_level of its query
667
            if query.startswith('EXPLAIN'): log_level -= 1
668
            
669
            parse_exception(db, e, recover)
670
    except log_ignore_excs:
671
        log_level += 2
672
        raise
673
    finally:
674
        if debug_msg_ref[0] != None: db.log_debug(debug_msg_ref[0], log_level)
675

    
676
##### Basic queries
677

    
678
def is_explainable(query):
679
    # See <http://www.postgresql.org/docs/8.3/static/sql-explain.html#AEN57749>
680
    return re.match(r'^(?:SELECT|INSERT|UPDATE|DELETE|VALUES|EXECUTE|DECLARE)\b'
681
        , query)
682

    
683
def explain(db, query, **kw_args):
684
    '''
685
    For params, see run_query().
686
    '''
687
    kw_args.setdefault('log_level', 4)
688
    
689
    return strings.ustr(strings.join_lines(values(run_query(db,
690
        'EXPLAIN '+query, recover=True, cacheable=True, **kw_args))))
691
        # not a higher log_level because it's useful to see what query is being
692
        # run before it's executed, which EXPLAIN effectively provides
693

    
694
def has_comment(query): return query.endswith('*/')
695

    
696
def with_explain_comment(db, query, **kw_args):
697
    if db.autoexplain and not has_comment(query) and is_explainable(query):
698
        query += '\n'+sql_gen.esc_comment(' EXPLAIN:\n'
699
            +explain(db, query, **kw_args))
700
    return query
701

    
702
def next_version(name):
703
    version = 1 # first existing name was version 0
704
    match = re.match(r'^(.*)#(\d+)$', name)
705
    if match:
706
        name, version = match.groups()
707
        version = int(version)+1
708
    return sql_gen.concat(name, '#'+str(version))
709

    
710
def lock_table(db, table, mode):
711
    table = sql_gen.as_Table(table)
712
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
713

    
714
def run_query_into(db, query, into=None, add_pkey_=False, add_pkey_warn=True,
715
    **kw_args):
716
    '''Outputs a query to a temp table.
717
    For params, see run_query().
718
    '''
719
    if into == None: return run_query(db, query, **kw_args)
720
    
721
    assert isinstance(into, sql_gen.Table)
722
    
723
    into.is_temp = True
724
    # "temporary tables cannot specify a schema name", so remove schema
725
    into.schema = None
726
    
727
    kw_args['recover'] = True
728
    kw_args.setdefault('log_ignore_excs', (DuplicateException,))
729
    
730
    temp = not db.debug_temp # tables are permanent in debug_temp mode
731
    
732
    # Create table
733
    while True:
734
        create_query = 'CREATE'
735
        if temp: create_query += ' TEMP'
736
        create_query += ' TABLE '+into.to_str(db)+' AS\n'+query
737
        
738
        try:
739
            cur = run_query(db, create_query, **kw_args)
740
                # CREATE TABLE AS sets rowcount to # rows in query
741
            break
742
        except DuplicateException, e:
743
            into.name = next_version(into.name)
744
            # try again with next version of name
745
    
746
    if add_pkey_: add_pkey_or_index(db, into, warn=add_pkey_warn)
747
    
748
    # According to the PostgreSQL doc, "The autovacuum daemon cannot access and
749
    # therefore cannot vacuum or analyze temporary tables. [...] if a temporary
750
    # table is going to be used in complex queries, it is wise to run ANALYZE on
751
    # the temporary table after it is populated."
752
    # (http://www.postgresql.org/docs/9.1/static/sql-createtable.html)
753
    # If into is not a temp table, ANALYZE is useful but not required.
754
    analyze(db, into)
755
    
756
    return cur
757

    
758
order_by_pkey = object() # tells mk_select() to order by the pkey
759

    
760
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
761

    
762
def has_subset_func(db, table):
763
    return sql_gen.is_underlying_table(table) and function_exists(db, table)
764

    
765
def mk_select(db, tables=None, fields=None, conds=None, distinct_on=[],
766
    limit=None, start=None, order_by=order_by_pkey, default_table=None,
767
    explain=True):
768
    '''
769
    @param tables The single table to select from, or a list of tables to join
770
        together, with tables after the first being sql_gen.Join objects
771
    @param fields Use None to select all fields in the table
772
    @param conds WHERE conditions: [(compare_left_side, compare_right_side),...]
773
        * container can be any iterable type
774
        * compare_left_side: sql_gen.Code|str (for col name)
775
        * compare_right_side: sql_gen.ValueCond|literal value
776
    @param distinct_on The columns to SELECT DISTINCT ON, or distinct_on_all to
777
        use all columns
778
    @return query
779
    '''
780
    # Parse tables param
781
    tables = lists.mk_seq(tables)
782
    tables = list(tables) # don't modify input! (list() copies input)
783
    table0 = sql_gen.as_Table(tables.pop(0)) # first table is separate
784
    
785
    # Parse other params
786
    if conds == None: conds = []
787
    elif dicts.is_dict(conds): conds = conds.items()
788
    conds = list(conds) # don't modify input! (list() copies input)
789
    assert limit == None or isinstance(limit, (int, long))
790
    assert start == None or isinstance(start, (int, long))
791
    if limit == 0: order_by = None
792
    if order_by in (None, order_by_pkey) and has_subset_func(db, table0):
793
        # can use subset function for fast querying at large OFFSET values
794
        run_query(db, 'SET LOCAL enable_sort TO off')
795
        table0 = sql_gen.FunctionCall(table0, limit_=limit, offset_=start)
796
        if limit != 0: limit = None # done by function
797
        start = None # done by function
798
        order_by = None # done by function
799
    elif order_by is order_by_pkey:
800
        if lists.is_seq(distinct_on) and distinct_on: order_by = distinct_on[0]
801
        elif table0 != None: order_by = table_order_by(db, table0, recover=True)
802
        else: order_by = None
803
    
804
    query = 'SELECT'
805
    
806
    def parse_col(col): return sql_gen.as_Col(col, default_table).to_str(db)
807
    
808
    # DISTINCT ON columns
809
    if distinct_on != []:
810
        query += '\nDISTINCT'
811
        if distinct_on is not distinct_on_all:
812
            query += ' ON ('+(', '.join(map(parse_col, distinct_on)))+')'
813
    
814
    # Columns
815
    if query.find('\n') >= 0: whitespace = '\n'
816
    else: whitespace = ' '
817
    if fields == None: query += whitespace+'*'
818
    else:
819
        assert fields != []
820
        if len(fields) > 1: whitespace = '\n'
821
        query += whitespace+('\n, '.join(map(parse_col, fields)))
822
    
823
    # Main table
824
    if query.find('\n') >= 0 or len(tables) > 0: whitespace = '\n'
825
    else: whitespace = ' '
826
    if table0 != None: query += whitespace+'FROM '+table0.to_str(db)
827
    
828
    # Add joins
829
    left_table = table0
830
    for join_ in tables:
831
        table = join_.table
832
        
833
        # Parse special values
834
        if join_.type_ is sql_gen.filter_out: # filter no match
835
            conds.append((sql_gen.Col(table_not_null_col(db, table), table),
836
                sql_gen.CompareCond(None, '~=')))
837
        
838
        query += '\n'+join_.to_str(db, left_table)
839
        
840
        left_table = table
841
    
842
    missing = True
843
    if conds != []:
844
        if len(conds) == 1: whitespace = ' '
845
        else: whitespace = '\n'
846
        query += '\n'+sql_gen.combine_conds([sql_gen.ColValueCond(l, r)
847
            .to_str(db) for l, r in conds], 'WHERE')
848
    if order_by != None:
849
        query += '\nORDER BY '+sql_gen.as_Col(order_by).to_str(db)
850
    if limit != None: query += '\nLIMIT '+str(limit)
851
    if start != None:
852
        if start != 0: query += '\nOFFSET '+str(start)
853
    
854
    if explain: query = with_explain_comment(db, query)
855
    
856
    return query
857

    
858
def select(db, *args, **kw_args):
859
    '''For params, see mk_select() and run_query()'''
860
    recover = kw_args.pop('recover', None)
861
    cacheable = kw_args.pop('cacheable', True)
862
    log_level = kw_args.pop('log_level', 2)
863
    
864
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
865
        log_level=log_level)
866

    
867
def mk_insert_select(db, table, cols=None, select_query=None, returning=None,
868
    embeddable=False, ignore=False, src=None):
869
    '''
870
    @param returning str|None An inserted column (such as pkey) to return
871
    @param embeddable Whether the query should be embeddable as a nested SELECT.
872
        Warning: If you set this and cacheable=True when the query is run, the
873
        query will be fully cached, not just if it raises an exception.
874
    @param ignore Whether to ignore duplicate keys.
875
    @param src Will be included in the name of any created function, to help
876
        identify the data source in pg_stat_activity.
877
    '''
878
    table = sql_gen.remove_table_rename(sql_gen.as_Table(table))
879
    if cols == []: cols = None # no cols (all defaults) = unknown col names
880
    if cols != None: cols = [sql_gen.to_name_only_col(c, table) for c in cols]
881
    if select_query == None: select_query = 'DEFAULT VALUES'
882
    if returning != None: returning = sql_gen.as_Col(returning, table)
883
    
884
    first_line = 'INSERT INTO '+table.to_str(db)
885
    
886
    def mk_insert(select_query):
887
        query = first_line
888
        if cols != None:
889
            query += '\n('+(', '.join((c.to_str(db) for c in cols)))+')'
890
        query += '\n'+select_query
891
        
892
        if returning != None:
893
            returning_name_col = sql_gen.to_name_only_col(returning)
894
            query += '\nRETURNING '+returning_name_col.to_str(db)
895
        
896
        return query
897
    
898
    return_type = sql_gen.CustomCode('unknown')
899
    if returning != None: return_type = sql_gen.ColType(returning)
900
    
901
    if ignore:
902
        # Always return something to set the correct rowcount
903
        if returning == None: returning = sql_gen.NamedCol('NULL', None)
904
        
905
        embeddable = True # must use function
906
        
907
        if cols == None: row = [sql_gen.Col(sql_gen.all_cols, 'row')]
908
        else: row = [sql_gen.Col(c.name, 'row') for c in cols]
909
        
910
        query = sql_gen.RowExcIgnore(sql_gen.RowType(table), select_query,
911
            sql_gen.ReturnQuery(mk_insert(sql_gen.Values(row).to_str(db))),
912
            cols)
913
    else: query = mk_insert(select_query)
914
    
915
    if embeddable:
916
        # Create function
917
        function_name = sql_gen.clean_name(first_line)
918
        if src != None: function_name = src+': '+function_name
919
        while True:
920
            try:
921
                func = db.TempFunction(function_name)
922
                def_ = sql_gen.FunctionDef(func, sql_gen.SetOf(return_type),
923
                    query)
924
                
925
                run_query(db, def_.to_str(db), recover=True, cacheable=True,
926
                    log_ignore_excs=(DuplicateException,))
927
                break # this version was successful
928
            except DuplicateException, e:
929
                function_name = next_version(function_name)
930
                # try again with next version of name
931
        
932
        # Return query that uses function
933
        cols = None
934
        if returning != None: cols = [returning]
935
        func_table = sql_gen.NamedTable('f', sql_gen.FunctionCall(func), cols)
936
            # AS clause requires function alias
937
        return mk_select(db, func_table, order_by=None)
938
    
939
    return query
940

    
941
def insert_select(db, table, *args, **kw_args):
942
    '''For params, see mk_insert_select() and run_query_into()
943
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
944
        values in
945
    '''
946
    returning = kw_args.get('returning', None)
947
    ignore = kw_args.get('ignore', False)
948
    
949
    into = kw_args.pop('into', None)
950
    if into != None: kw_args['embeddable'] = True
951
    recover = kw_args.pop('recover', None)
952
    if ignore: recover = True
953
    cacheable = kw_args.pop('cacheable', True)
954
    log_level = kw_args.pop('log_level', 2)
955
    
956
    rowcount_only = ignore and returning == None # keep NULL rows on server
957
    if rowcount_only: into = sql_gen.Table('rowcount')
958
    
959
    cur = run_query_into(db, mk_insert_select(db, table, *args, **kw_args),
960
        into, recover=recover, cacheable=cacheable, log_level=log_level)
961
    if rowcount_only: empty_temp(db, into)
962
    autoanalyze(db, table)
963
    return cur
964

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

    
967
def insert(db, table, row, *args, **kw_args):
968
    '''For params, see insert_select()'''
969
    ignore = kw_args.pop('ignore', False)
970
    if ignore: kw_args.setdefault('recover', True)
971
    
972
    if lists.is_seq(row): cols = None
973
    else:
974
        cols = row.keys()
975
        row = row.values()
976
    row = list(row) # ensure that "== []" works
977
    
978
    if row == []: query = None
979
    else: query = sql_gen.Values(row).to_str(db)
980
    
981
    try: return insert_select(db, table, cols, query, *args, **kw_args)
982
    except (DuplicateKeyException, NullValueException):
983
        if not ignore: raise
984
        return None
985

    
986
def mk_update(db, table, changes=None, cond=None, in_place=False,
987
    cacheable_=True):
988
    '''
989
    @param changes [(col, new_value),...]
990
        * container can be any iterable type
991
        * col: sql_gen.Code|str (for col name)
992
        * new_value: sql_gen.Code|literal value
993
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
994
    @param in_place If set, locks the table and updates rows in place.
995
        This avoids creating dead rows in PostgreSQL.
996
        * cond must be None
997
    @param cacheable_ Whether column structure information used to generate the
998
        query can be cached
999
    @return str query
1000
    '''
1001
    table = sql_gen.as_Table(table)
1002
    changes = [(sql_gen.to_name_only_col(c, table), sql_gen.as_Value(v))
1003
        for c, v in changes]
1004
    
1005
    if in_place:
1006
        assert cond == None
1007
        
1008
        def col_type(col):
1009
            return sql_gen.canon_type(db.col_info(
1010
                sql_gen.with_default_table(c, table), cacheable_).type)
1011
        changes = [(c, v, col_type(c)) for c, v in changes]
1012
        query = 'ALTER TABLE '+table.to_str(db)+'\n'
1013
        query += ',\n'.join(('ALTER COLUMN '+c.to_str(db)+' TYPE '+t+'\nUSING '
1014
            +v.to_str(db) for c, v, t in changes))
1015
    else:
1016
        query = 'UPDATE '+table.to_str(db)+'\nSET\n'
1017
        query += ',\n'.join((c.to_str(db)+' = '+v.to_str(db)
1018
            for c, v in changes))
1019
        if cond != None: query += '\nWHERE\n'+cond.to_str(db)
1020
    
1021
    query = with_explain_comment(db, query)
1022
    
1023
    return query
1024

    
1025
def update(db, table, *args, **kw_args):
1026
    '''For params, see mk_update() and run_query()'''
1027
    recover = kw_args.pop('recover', None)
1028
    cacheable = kw_args.pop('cacheable', False)
1029
    log_level = kw_args.pop('log_level', 2)
1030
    
1031
    cur = run_query(db, mk_update(db, table, *args, **kw_args), recover,
1032
        cacheable, log_level=log_level)
1033
    autoanalyze(db, table)
1034
    return cur
1035

    
1036
def mk_delete(db, table, cond=None):
1037
    '''
1038
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
1039
    @return str query
1040
    '''
1041
    query = 'DELETE FROM '+table.to_str(db)
1042
    if cond != None: query += '\nWHERE '+cond.to_str(db)
1043
    
1044
    query = with_explain_comment(db, query)
1045
    
1046
    return query
1047

    
1048
def delete(db, table, *args, **kw_args):
1049
    '''For params, see mk_delete() and run_query()'''
1050
    recover = kw_args.pop('recover', None)
1051
    cacheable = kw_args.pop('cacheable', True)
1052
    log_level = kw_args.pop('log_level', 2)
1053
    
1054
    cur = run_query(db, mk_delete(db, table, *args, **kw_args), recover,
1055
        cacheable, log_level=log_level)
1056
    autoanalyze(db, table)
1057
    return cur
1058

    
1059
def last_insert_id(db):
1060
    module = util.root_module(db.db)
1061
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
1062
    elif module == 'MySQLdb': return db.insert_id()
1063
    else: return None
1064

    
1065
def define_func(db, def_):
1066
    func = def_.function
1067
    while True:
1068
        try:
1069
            run_query(db, def_.to_str(db), recover=True, cacheable=True,
1070
                log_ignore_excs=(DuplicateException,))
1071
            break # successful
1072
        except DuplicateException:
1073
            func.name = next_version(func.name)
1074
            # try again with next version of name
1075

    
1076
def mk_flatten_mapping(db, into, cols, preserve=[], as_items=False):
1077
    '''Creates a mapping from original column names (which may have collisions)
1078
    to names that will be distinct among the columns' tables.
1079
    This is meant to be used for several tables that are being joined together.
1080
    @param cols The columns to combine. Duplicates will be removed.
1081
    @param into The table for the new columns.
1082
    @param preserve [sql_gen.Col...] Columns not to rename. Note that these
1083
        columns will be included in the mapping even if they are not in cols.
1084
        The tables of the provided Col objects will be changed to into, so make
1085
        copies of them if you want to keep the original tables.
1086
    @param as_items Whether to return a list of dict items instead of a dict
1087
    @return dict(orig_col=new_col, ...)
1088
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
1089
        * new_col: sql_gen.Col(orig_col_name, into)
1090
        * All mappings use the into table so its name can easily be
1091
          changed for all columns at once
1092
    '''
1093
    cols = lists.uniqify(cols)
1094
    
1095
    items = []
1096
    for col in preserve:
1097
        orig_col = copy.copy(col)
1098
        col.table = into
1099
        items.append((orig_col, col))
1100
    preserve = set(preserve)
1101
    for col in cols:
1102
        if col not in preserve:
1103
            items.append((col, sql_gen.Col(strings.ustr(col), into, col.srcs)))
1104
    
1105
    if not as_items: items = dict(items)
1106
    return items
1107

    
1108
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
1109
    '''For params, see mk_flatten_mapping()
1110
    @return See return value of mk_flatten_mapping()
1111
    '''
1112
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
1113
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
1114
    # don't warn if can't create pkey, because this just indicates that a
1115
    # set-returning function was used
1116
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
1117
        into=into, add_pkey_=True, add_pkey_warn=False)
1118
        # don't cache because the temp table will usually be truncated after use
1119
    return dict(items)
1120

    
1121
##### Database structure introspection
1122

    
1123
#### Tables
1124

    
1125
def tables(db, schema_like='public', table_like='%', exact=False,
1126
    cacheable=True):
1127
    if exact: compare = '='
1128
    else: compare = 'LIKE'
1129
    
1130
    module = util.root_module(db.db)
1131
    if module == 'psycopg2':
1132
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1133
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1134
        return values(select(db, 'pg_tables', ['tablename'], conds,
1135
            order_by='tablename', cacheable=cacheable, log_level=4))
1136
    elif module == 'MySQLdb':
1137
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1138
            , cacheable=True, log_level=4))
1139
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1140

    
1141
def table_exists(db, table, cacheable=True):
1142
    table = sql_gen.as_Table(table)
1143
    return list(tables(db, table.schema, table.name, True, cacheable)) != []
1144

    
1145
def table_row_count(db, table, recover=None):
1146
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
1147
        order_by=None), recover=recover, log_level=3))
1148

    
1149
def table_col_names(db, table, recover=None):
1150
    return list(col_names(select(db, table, limit=0, recover=recover,
1151
        log_level=4)))
1152

    
1153
def table_cols(db, table, *args, **kw_args):
1154
    return [sql_gen.as_Col(strings.ustr(c), table)
1155
        for c in table_col_names(db, table, *args, **kw_args)]
1156

    
1157
def table_pkey_index(db, table, recover=None):
1158
    table_str = sql_gen.Literal(table.to_str(db))
1159
    try:
1160
        return sql_gen.Table(value(run_query(db, '''\
1161
SELECT relname
1162
FROM pg_index
1163
JOIN pg_class index ON index.oid = indexrelid
1164
WHERE
1165
indrelid = '''+table_str.to_str(db)+'''::regclass
1166
AND indisprimary
1167
'''
1168
            , recover, cacheable=True, log_level=4)), table.schema)
1169
    except StopIteration: raise DoesNotExistException('primary key', '')
1170

    
1171
def table_pkey_col(db, table, recover=None):
1172
    table = sql_gen.as_Table(table)
1173
    
1174
    module = util.root_module(db.db)
1175
    if module == 'psycopg2':
1176
        return sql_gen.Col(index_cols(db, table_pkey_index(db, table,
1177
            recover))[0], table)
1178
    else:
1179
        join_cols = ['table_schema', 'table_name', 'constraint_schema',
1180
            'constraint_name']
1181
        tables = [sql_gen.Table('key_column_usage', 'information_schema'),
1182
            sql_gen.Join(
1183
                sql_gen.Table('table_constraints', 'information_schema'),
1184
                dict(((c, sql_gen.join_same_not_null) for c in join_cols)))]
1185
        cols = [sql_gen.Col('column_name')]
1186
        
1187
        conds = [('constraint_type', 'PRIMARY KEY'), ('table_name', table.name)]
1188
        schema = table.schema
1189
        if schema != None: conds.append(('table_schema', schema))
1190
        order_by = 'position_in_unique_constraint'
1191
        
1192
        try: return sql_gen.Col(value(select(db, tables, cols, conds,
1193
            order_by=order_by, limit=1, log_level=4)), table)
1194
        except StopIteration: raise DoesNotExistException('primary key', '')
1195

    
1196
def table_has_pkey(db, table, recover=None):
1197
    try: table_pkey_col(db, table, recover)
1198
    except DoesNotExistException: return False
1199
    else: return True
1200

    
1201
def pkey_name(db, table, recover=None):
1202
    '''If no pkey, returns the first column in the table.'''
1203
    return pkey_col(db, table, recover).name
1204

    
1205
def pkey_col(db, table, recover=None):
1206
    '''If no pkey, returns the first column in the table.'''
1207
    try: return table_pkey_col(db, table, recover)
1208
    except DoesNotExistException: return table_cols(db, table, recover)[0]
1209

    
1210
not_null_col = 'not_null_col'
1211

    
1212
def table_not_null_col(db, table, recover=None):
1213
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
1214
    if not_null_col in table_col_names(db, table, recover): return not_null_col
1215
    else: return pkey_name(db, table, recover)
1216

    
1217
def constraint_cond(db, constraint):
1218
    module = util.root_module(db.db)
1219
    if module == 'psycopg2':
1220
        table_str = sql_gen.Literal(constraint.table.to_str(db))
1221
        name_str = sql_gen.Literal(constraint.name)
1222
        return value(run_query(db, '''\
1223
SELECT consrc
1224
FROM pg_constraint
1225
WHERE
1226
conrelid = '''+table_str.to_str(db)+'''::regclass
1227
AND conname = '''+name_str.to_str(db)+'''
1228
'''
1229
            , cacheable=True, log_level=4))
1230
    else: raise NotImplementedError("Can't get constraint condition for "
1231
        +module+' database')
1232

    
1233
def index_exprs(db, index):
1234
    index = sql_gen.as_Table(index)
1235
    module = util.root_module(db.db)
1236
    if module == 'psycopg2':
1237
        qual_index = sql_gen.Literal(index.to_str(db))
1238
        return list(values(run_query(db, '''\
1239
SELECT pg_get_indexdef(indexrelid, generate_series(1, indnatts), true)
1240
FROM pg_index
1241
WHERE indexrelid = '''+qual_index.to_str(db)+'''::regclass
1242
'''
1243
            , cacheable=True, log_level=4)))
1244
    else: raise NotImplementedError()
1245

    
1246
def index_cols(db, index):
1247
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
1248
    automatically created. When you don't know whether something is a UNIQUE
1249
    constraint or a UNIQUE index, use this function.'''
1250
    return map(sql_gen.parse_expr_col, index_exprs(db, index))
1251

    
1252
def index_cond(db, index):
1253
    index = sql_gen.as_Table(index)
1254
    module = util.root_module(db.db)
1255
    if module == 'psycopg2':
1256
        qual_index = sql_gen.Literal(index.to_str(db))
1257
        return value(run_query(db, '''\
1258
SELECT pg_get_expr(indpred, indrelid, true)
1259
FROM pg_index
1260
WHERE indexrelid = '''+qual_index.to_str(db)+'''::regclass
1261
'''
1262
            , cacheable=True, log_level=4))
1263
    else: raise NotImplementedError()
1264

    
1265
def index_order_by(db, index):
1266
    return sql_gen.CustomCode(', '.join(index_exprs(db, index)))
1267

    
1268
def table_cluster_on(db, table, recover=None):
1269
    '''
1270
    @return The table's cluster index, or its pkey if none is set
1271
    '''
1272
    table_str = sql_gen.Literal(table.to_str(db))
1273
    try:
1274
        return sql_gen.Table(value(run_query(db, '''\
1275
SELECT relname
1276
FROM pg_index
1277
JOIN pg_class index ON index.oid = indexrelid
1278
WHERE
1279
indrelid = '''+table_str.to_str(db)+'''::regclass
1280
AND indisclustered
1281
'''
1282
            , recover, cacheable=True, log_level=4)), table.schema)
1283
    except StopIteration: return table_pkey_index(db, table, recover)
1284

    
1285
def table_order_by(db, table, recover=None):
1286
    '''
1287
    @return None if table is view, because table_cluster_on() would return None
1288
    '''
1289
    if table.order_by == None:
1290
        try: table.order_by = index_order_by(db, table_cluster_on(db, table,
1291
            recover))
1292
        except DoesNotExistException: pass
1293
    return table.order_by
1294

    
1295
#### Views
1296

    
1297
def view_exists(db, view):
1298
    view_str = sql_gen.Literal(view.to_str(db))
1299
    try:
1300
        return value(run_query(db, '''\
1301
SELECT relkind = 'v'
1302
FROM pg_class
1303
WHERE oid = '''+view_str.to_str(db)+'''::regclass
1304
'''
1305
            , cacheable=True, log_level=4))
1306
    except DoesNotExistException: return False
1307

    
1308
#### Columns
1309

    
1310
def col_default_value(db, col):
1311
    assert isinstance(col, sql_gen.Col)
1312
    return value(run_query(db,
1313
        'SELECT util.col_default_value('+sql_gen.col2col_ref(db, col)+')'))
1314

    
1315
def col_is_constant(db, col):
1316
    assert isinstance(col, sql_gen.Col)
1317
    return value(run_query(db,
1318
        'SELECT util.is_constant('+sql_gen.col2col_ref(db, col)+')'))
1319

    
1320
#### Functions
1321

    
1322
def function_exists(db, function):
1323
    qual_function = sql_gen.Literal(function.to_str(db))
1324
    try:
1325
        select(db, fields=[sql_gen.Cast('regproc', qual_function)],
1326
            recover=True, cacheable=True, log_level=4)
1327
    except DoesNotExistException: return False
1328
    except DuplicateException: return True # overloaded function
1329
    else: return True
1330

    
1331
def function_param0_type(db, function):
1332
    qual_function = sql_gen.Literal(function.to_str(db))
1333
    return value(run_query(db, '''\
1334
SELECT proargtypes[0]::regtype
1335
FROM pg_proc
1336
WHERE oid = '''+qual_function.to_str(db)+'''::regproc
1337
'''
1338
        , cacheable=True, log_level=4))
1339

    
1340
##### Structural changes
1341

    
1342
#### Columns
1343

    
1344
def add_col(db, table, col, comment=None, if_not_exists=False, **kw_args):
1345
    '''
1346
    @param col TypedCol Name may be versioned, so be sure to propagate any
1347
        renaming back to any source column for the TypedCol.
1348
    @param comment None|str SQL comment used to distinguish columns of the same
1349
        name from each other when they contain different data, to allow the
1350
        ADD COLUMN query to be cached. If not set, query will not be cached.
1351
    '''
1352
    assert isinstance(col, sql_gen.TypedCol)
1353
    
1354
    while True:
1355
        str_ = 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '+col.to_str(db)
1356
        if comment != None: str_ += ' '+sql_gen.esc_comment(comment)
1357
        
1358
        try:
1359
            run_query(db, str_, recover=True, cacheable=True, **kw_args)
1360
            break
1361
        except DuplicateException:
1362
            if if_not_exists: raise
1363
            col.name = next_version(col.name)
1364
            # try again with next version of name
1365

    
1366
def add_not_null(db, col):
1367
    table = col.table
1368
    col = sql_gen.to_name_only_col(col)
1369
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1370
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1371

    
1372
def drop_not_null(db, col):
1373
    table = col.table
1374
    col = sql_gen.to_name_only_col(col)
1375
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1376
        +col.to_str(db)+' DROP NOT NULL', cacheable=True, log_level=3)
1377

    
1378
row_num_col = '_row_num'
1379

    
1380
row_num_col_def = sql_gen.TypedCol('', 'serial', nullable=False,
1381
    constraints='PRIMARY KEY')
1382

    
1383
def add_row_num(db, table, name=row_num_col):
1384
    '''Adds a row number column to a table. Its definition is in
1385
    row_num_col_def. It will be the primary key.'''
1386
    col_def = copy.copy(row_num_col_def)
1387
    col_def.name = name
1388
    add_col(db, table, col_def, comment='', if_not_exists=True, log_level=3)
1389

    
1390
#### Indexes
1391

    
1392
def add_pkey(db, table, cols=None, recover=None):
1393
    '''Adds a primary key.
1394
    @param cols [sql_gen.Col,...] The columns in the primary key.
1395
        Defaults to the first column in the table.
1396
    @pre The table must not already have a primary key.
1397
    '''
1398
    table = sql_gen.as_Table(table)
1399
    if cols == None: cols = [pkey_name(db, table, recover)]
1400
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1401
    
1402
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1403
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1404
        log_ignore_excs=(DuplicateException,))
1405

    
1406
def add_index(db, exprs, table=None, unique=False, ensure_not_null_=True):
1407
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
1408
    Currently, only function calls and literal values are supported expressions.
1409
    @param ensure_not_null_ If set, translates NULL values to sentinel values.
1410
        This allows indexes to be used for comparisons where NULLs are equal.
1411
    '''
1412
    exprs = lists.mk_seq(exprs)
1413
    
1414
    # Parse exprs
1415
    old_exprs = exprs[:]
1416
    exprs = []
1417
    cols = []
1418
    for i, expr in enumerate(old_exprs):
1419
        expr = sql_gen.as_Col(expr, table)
1420
        
1421
        # Handle nullable columns
1422
        if ensure_not_null_:
1423
            try: expr = sql_gen.ensure_not_null(db, expr)
1424
            except KeyError: pass # unknown type, so just create plain index
1425
        
1426
        # Extract col
1427
        expr = copy.deepcopy(expr) # don't modify input!
1428
        col = expr
1429
        if isinstance(expr, sql_gen.FunctionCall): col = expr.args[0]
1430
        expr = sql_gen.cast_literal(expr)
1431
        if not isinstance(expr, (sql_gen.Expr, sql_gen.Col)):
1432
            expr = sql_gen.Expr(expr)
1433
            
1434
        
1435
        # Extract table
1436
        if table == None:
1437
            assert sql_gen.is_table_col(col)
1438
            table = col.table
1439
        
1440
        if isinstance(col, sql_gen.Col): col.table = None
1441
        
1442
        exprs.append(expr)
1443
        cols.append(col)
1444
    
1445
    table = sql_gen.as_Table(table)
1446
    
1447
    # Add index
1448
    str_ = 'CREATE'
1449
    if unique: str_ += ' UNIQUE'
1450
    str_ += ' INDEX ON '+table.to_str(db)+' ('+(
1451
        ', '.join((v.to_str(db) for v in exprs)))+')'
1452
    run_query(db, str_, recover=True, cacheable=True, log_level=3)
1453

    
1454
def add_pkey_index(db, table): add_index(db, pkey_col(db, table), table)
1455

    
1456
def add_pkey_or_index(db, table, cols=None, recover=None, warn=False):
1457
    try: add_pkey(db, table, cols, recover)
1458
    except DuplicateKeyException, e:
1459
        if warn: warnings.warn(UserWarning(exc.str_(e)))
1460
        add_pkey_index(db, table)
1461

    
1462
already_indexed = object() # tells add_indexes() the pkey has already been added
1463

    
1464
def add_indexes(db, table, has_pkey=True):
1465
    '''Adds an index on all columns in a table.
1466
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1467
        index should be added on the first column.
1468
        * If already_indexed, the pkey is assumed to have already been added
1469
    '''
1470
    cols = table_col_names(db, table)
1471
    if has_pkey:
1472
        if has_pkey is not already_indexed: add_pkey(db, table)
1473
        cols = cols[1:]
1474
    for col in cols: add_index(db, col, table)
1475

    
1476
#### Tables
1477

    
1478
### Maintenance
1479

    
1480
def analyze(db, table):
1481
    table = sql_gen.as_Table(table)
1482
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1483

    
1484
def autoanalyze(db, table):
1485
    if db.autoanalyze: analyze(db, table)
1486

    
1487
def vacuum(db, table):
1488
    table = sql_gen.as_Table(table)
1489
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1490
        log_level=3))
1491

    
1492
### Lifecycle
1493

    
1494
def drop(db, type_, name):
1495
    name = sql_gen.as_Name(name)
1496
    run_query(db, 'DROP '+type_+' IF EXISTS '+name.to_str(db)+' CASCADE')
1497

    
1498
def drop_table(db, table): drop(db, 'TABLE', table)
1499

    
1500
def create_table(db, table, cols=[], has_pkey=True, col_indexes=True,
1501
    like=None, **query_opts):
1502
    '''Creates a table.
1503
    @param cols [sql_gen.TypedCol,...] The column names and types
1504
    @param has_pkey If set, the first column becomes the primary key.
1505
    @param col_indexes bool|[ref]
1506
        * If True, indexes will be added on all non-pkey columns.
1507
        * If a list reference, [0] will be set to a function to do this.
1508
          This can be used to delay index creation until the table is populated.
1509
    '''
1510
    query_opts.setdefault('cacheable', True)
1511
    
1512
    table = sql_gen.as_Table(table)
1513
    
1514
    if like != None:
1515
        cols = [sql_gen.CustomCode('LIKE '+like.to_str(db)+' INCLUDING ALL')
1516
            ]+cols
1517
        table.order_by = like.order_by
1518
    if has_pkey:
1519
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1520
        pkey.constraints = 'PRIMARY KEY'
1521
    
1522
    temp = table.is_temp and not db.debug_temp
1523
        # temp tables permanent in debug_temp mode
1524
    
1525
    # Create table
1526
    def create():
1527
        str_ = 'CREATE'
1528
        if temp: str_ += ' TEMP'
1529
        str_ += ' TABLE '+table.to_str(db)+' (\n'
1530
        str_ += '\n, '.join(c.to_str(db) for c in cols)
1531
        str_ += '\n);'
1532
        
1533
        opts = dict(recover=True, log_level=2,
1534
            log_ignore_excs=(DuplicateException,), **query_opts)
1535
        try: run_query(db, str_, **opts)
1536
        except InvalidTypeException: # try again as view
1537
            run_query_into(db, mk_select(db, like, limit=0), into=table, **opts)
1538
    if table.is_temp:
1539
        while True:
1540
            try:
1541
                create()
1542
                break
1543
            except DuplicateException:
1544
                table.name = next_version(table.name)
1545
                # try again with next version of name
1546
    else: create()
1547
    
1548
    # Add indexes
1549
    if has_pkey: has_pkey = already_indexed
1550
    def add_indexes_(): add_indexes(db, table, has_pkey)
1551
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1552
    elif col_indexes: add_indexes_() # add now
1553

    
1554
def copy_table_struct(db, src, dest, **opts):
1555
    '''Creates a structure-only copy of a table. (Does not copy data.)'''
1556
    create_table(db, dest, has_pkey=False, col_indexes=False, like=src, **opts)
1557

    
1558
def copy_table(db, src, dest):
1559
    '''Creates a copy of a table, including data'''
1560
    copy_table_struct(db, src, dest)
1561
    insert_select(db, dest, None, mk_select(db, src))
1562

    
1563
### Data
1564

    
1565
def truncate(db, table, schema='public', **kw_args):
1566
    '''For params, see run_query()'''
1567
    table = sql_gen.as_Table(table, schema)
1568
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1569

    
1570
def empty_temp(db, tables):
1571
    tables = lists.mk_seq(tables)
1572
    for table in tables: truncate(db, table, log_level=3)
1573

    
1574
def empty_db(db, schema='public', **kw_args):
1575
    '''For kw_args, see tables()'''
1576
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1577

    
1578
def distinct_table(db, table, distinct_on, joins=None, conds=None):
1579
    '''Creates a copy of a temp table which is distinct on the given columns.
1580
    Adds an index on table's distinct_on columns, to facilitate merge joins.
1581
    @param distinct_on If empty, creates a table with one row. This is useful if
1582
        your distinct_on columns are all literal values.
1583
    @param joins The joins to use when creating the new table
1584
    @param conds Any additional filters to use when creating the new table
1585
    @return The new table.
1586
    '''
1587
    if joins == None: joins = [table]
1588
    
1589
    new_table = sql_gen.suffixed_table(table, '_distinct')
1590
    distinct_on = filter(sql_gen.is_table_col, distinct_on)
1591
    
1592
    copy_table_struct(db, table, new_table, cacheable=False)
1593
    
1594
    limit = None
1595
    if distinct_on == []: limit = 1 # one sample row
1596
    else: add_index(db, distinct_on, table) # for join optimization
1597
    
1598
    insert_select(db, new_table, None, mk_select(db, joins,
1599
        [sql_gen.Col(sql_gen.all_cols, table)], conds, distinct_on,
1600
        order_by=None, limit=limit))
1601
    analyze(db, new_table)
1602
    
1603
    return new_table
(35-35/49)