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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

    
1107
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
1108
    '''For params, see mk_flatten_mapping()
1109
    @return See return value of mk_flatten_mapping()
1110
    '''
1111
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
1112
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
1113
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
1114
        into=into, add_pkey_=True)
1115
        # don't cache because the temp table will usually be truncated after use
1116
    return dict(items)
1117

    
1118
##### Database structure introspection
1119

    
1120
#### Tables
1121

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

    
1138
def table_exists(db, table, cacheable=True):
1139
    table = sql_gen.as_Table(table)
1140
    return list(tables(db, table.schema, table.name, True, cacheable)) != []
1141

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

    
1146
def table_col_names(db, table, recover=None):
1147
    return list(col_names(select(db, table, limit=0, recover=recover,
1148
        log_level=4)))
1149

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

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

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

    
1193
def table_has_pkey(db, table, recover=None):
1194
    try: table_pkey_col(db, table, recover)
1195
    except DoesNotExistException: return False
1196
    else: return True
1197

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

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

    
1207
not_null_col = 'not_null_col'
1208

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

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

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

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

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

    
1262
def index_order_by(db, index):
1263
    return sql_gen.CustomCode(', '.join(index_exprs(db, index)))
1264

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

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

    
1292
#### Views
1293

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

    
1305
#### Columns
1306

    
1307
def col_default_value(db, col):
1308
    assert isinstance(col, sql_gen.Col)
1309
    return value(run_query(db,
1310
        'SELECT util.col_default_value('+sql_gen.col2col_ref(db, col)+')'))
1311

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

    
1317
#### Functions
1318

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

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

    
1337
##### Structural changes
1338

    
1339
#### Columns
1340

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

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

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

    
1375
row_num_col = '_row_num'
1376

    
1377
row_num_col_def = sql_gen.TypedCol('', 'serial', nullable=False,
1378
    constraints='PRIMARY KEY')
1379

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

    
1387
#### Indexes
1388

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

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

    
1451
def add_pkey_index(db, table): add_index(db, pkey_col(db, table), table)
1452

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

    
1459
already_indexed = object() # tells add_indexes() the pkey has already been added
1460

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

    
1473
#### Tables
1474

    
1475
### Maintenance
1476

    
1477
def analyze(db, table):
1478
    table = sql_gen.as_Table(table)
1479
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1480

    
1481
def autoanalyze(db, table):
1482
    if db.autoanalyze: analyze(db, table)
1483

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

    
1489
### Lifecycle
1490

    
1491
def drop(db, type_, name):
1492
    name = sql_gen.as_Name(name)
1493
    run_query(db, 'DROP '+type_+' IF EXISTS '+name.to_str(db)+' CASCADE')
1494

    
1495
def drop_table(db, table): drop(db, 'TABLE', table)
1496

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

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

    
1555
def copy_table(db, src, dest):
1556
    '''Creates a copy of a table, including data'''
1557
    copy_table_struct(db, src, dest)
1558
    insert_select(db, dest, None, mk_select(db, src))
1559

    
1560
### Data
1561

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

    
1567
def empty_temp(db, tables):
1568
    tables = lists.mk_seq(tables)
1569
    for table in tables: truncate(db, table, log_level=3)
1570

    
1571
def empty_db(db, schema='public', **kw_args):
1572
    '''For kw_args, see tables()'''
1573
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1574

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