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
        return DuplicateKeyException(constraint, cond, cols, e)
544
    
545
    match = re.match(r'^duplicate key value violates unique constraint "(.+?)"',
546
        msg)
547
    if match:
548
        constraint, = match.groups()
549
        raise make_DuplicateKeyException(constraint, e)
550
    
551
    match = re.match(r'^could not create unique index "(.+?)"\n'
552
        r'DETAIL:  Key .+? is duplicated', msg)
553
    if match:
554
        constraint, = match.groups()
555
        raise DuplicateKeyException(constraint, None, [], e)
556
    
557
    match = re.match(r'^null value in column "(.+?)" violates not-null'
558
        r' constraint', msg)
559
    if match:
560
        col, = match.groups()
561
        raise NullValueException('NOT NULL', None, [col], e)
562
    
563
    match = re.match(r'^new row for relation "(.+?)" violates check '
564
        r'constraint "(.+?)"', msg)
565
    if match:
566
        table, constraint = match.groups()
567
        constraint = sql_gen.Col(constraint, table)
568
        cond = None
569
        if recover: # need auto-rollback to run constraint_cond()
570
            try: cond = constraint_cond(db, constraint)
571
            except NotImplementedError: pass
572
        raise CheckException(constraint.to_str(db), cond, [], e)
573
    
574
    match = re.match(r'^(?:invalid input (?:syntax|value)\b[^:]*'
575
        r'|.+? out of range)(?:: "(.+?)")?', msg)
576
    if match:
577
        value, = match.groups()
578
        value = util.do_ignore_none(strings.to_unicode, value)
579
        raise InvalidValueException(value, e)
580
    
581
    match = re.match(r'^column "(.+?)" is of type (.+?) but expression '
582
        r'is of type', msg)
583
    if match:
584
        col, type_ = match.groups()
585
        raise MissingCastException(type_, col, e)
586
    
587
    match = re.match(r'^could not determine polymorphic type because '
588
        r'input has type "unknown"', msg)
589
    if match: raise MissingCastException('text', None, e)
590
    
591
    match = re.match(r'^.+? types (.+?) and (.+?) cannot be matched', msg)
592
    if match:
593
        type0, type1 = match.groups()
594
        raise MissingCastException(type0, None, e)
595
    
596
    match = re.match(r'^.*?\brelation "(.+?)" is not a (table)', msg)
597
    if match:
598
        name, type_ = match.groups()
599
        raise InvalidTypeException(type_, name, e)
600
    
601
    typed_name_re = r'^(\S+) ("?)(.+?)\2(?: of relation ".+?")?'
602
        # regexp must be followed with text for .*? to match properly
603
    
604
    match = re.match(typed_name_re+r'(?:\(.*?)? already exists', msg)
605
    if match:
606
        type_, quote, name = match.groups()
607
        raise DuplicateException(type_, name, e)
608
    
609
    match = re.match(r'more than one (\S+) named ""(.+?)""', msg)
610
    if match:
611
        type_, name = match.groups()
612
        raise DuplicateException(type_, name, e)
613
    
614
    match = re.match(typed_name_re+r' does not exist', msg)
615
    if match:
616
        type_, quote, name = match.groups()
617
        if type_ == 'function':
618
            match = re.match(r'^(.+?)\(.*\)$', name)
619
            if match: # includes params, so is call rather than cast to regproc
620
                function_name, = match.groups()
621
                func = sql_gen.Function(function_name)
622
                if function_exists(db, func) and msg.find('CAST') < 0:
623
                    # not found only because of a missing cast
624
                    type_ = function_param0_type(db, func)
625
                    col = None
626
                    if type_ == 'anyelement': type_ = 'text'
627
                    elif type_ == 'hstore': # cast just the value param
628
                        type_ = 'text'
629
                        col = 'value'
630
                    raise MissingCastException(type_, col, e)
631
        raise DoesNotExistException(type_, name, e)
632
    
633
    raise # no specific exception raised
634

    
635
def with_savepoint(db, func): return db.with_savepoint(func)
636

    
637
def run_query(db, query, recover=None, cacheable=False, log_level=2,
638
    log_ignore_excs=None, **kw_args):
639
    '''For params, see DbConn.run_query()'''
640
    if recover == None: recover = False
641
    if log_ignore_excs == None: log_ignore_excs = ()
642
    log_ignore_excs = tuple(log_ignore_excs)
643
    debug_msg_ref = [None]
644
    
645
    query = with_explain_comment(db, query)
646
    
647
    try:
648
        try:
649
            def run(): return db.run_query(query, cacheable, log_level,
650
                debug_msg_ref, **kw_args)
651
            if recover and not db.is_cached(query):
652
                return with_savepoint(db, run)
653
            else: return run() # don't need savepoint if cached
654
        except Exception, e:
655
            # Give failed EXPLAIN approximately the log_level of its query
656
            if query.startswith('EXPLAIN'): log_level -= 1
657
            
658
            parse_exception(db, e, recover)
659
    except log_ignore_excs:
660
        log_level += 2
661
        raise
662
    finally:
663
        if debug_msg_ref[0] != None: db.log_debug(debug_msg_ref[0], log_level)
664

    
665
##### Basic queries
666

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

    
672
def explain(db, query, **kw_args):
673
    '''
674
    For params, see run_query().
675
    '''
676
    kw_args.setdefault('log_level', 4)
677
    
678
    return strings.ustr(strings.join_lines(values(run_query(db,
679
        'EXPLAIN '+query, recover=True, cacheable=True, **kw_args))))
680
        # not a higher log_level because it's useful to see what query is being
681
        # run before it's executed, which EXPLAIN effectively provides
682

    
683
def has_comment(query): return query.endswith('*/')
684

    
685
def with_explain_comment(db, query, **kw_args):
686
    if db.autoexplain and not has_comment(query) and is_explainable(query):
687
        query += '\n'+sql_gen.esc_comment(' EXPLAIN:\n'
688
            +explain(db, query, **kw_args))
689
    return query
690

    
691
def next_version(name):
692
    version = 1 # first existing name was version 0
693
    match = re.match(r'^(.*)#(\d+)$', name)
694
    if match:
695
        name, version = match.groups()
696
        version = int(version)+1
697
    return sql_gen.concat(name, '#'+str(version))
698

    
699
def lock_table(db, table, mode):
700
    table = sql_gen.as_Table(table)
701
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
702

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

    
746
order_by_pkey = object() # tells mk_select() to order by the pkey
747

    
748
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
749

    
750
def has_subset_func(db, table):
751
    return sql_gen.is_underlying_table(table) and function_exists(db, table)
752

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

    
846
def select(db, *args, **kw_args):
847
    '''For params, see mk_select() and run_query()'''
848
    recover = kw_args.pop('recover', None)
849
    cacheable = kw_args.pop('cacheable', True)
850
    log_level = kw_args.pop('log_level', 2)
851
    
852
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
853
        log_level=log_level)
854

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

    
929
def insert_select(db, table, *args, **kw_args):
930
    '''For params, see mk_insert_select() and run_query_into()
931
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
932
        values in
933
    '''
934
    returning = kw_args.get('returning', None)
935
    ignore = kw_args.get('ignore', False)
936
    
937
    into = kw_args.pop('into', None)
938
    if into != None: kw_args['embeddable'] = True
939
    recover = kw_args.pop('recover', None)
940
    if ignore: recover = True
941
    cacheable = kw_args.pop('cacheable', True)
942
    log_level = kw_args.pop('log_level', 2)
943
    
944
    rowcount_only = ignore and returning == None # keep NULL rows on server
945
    if rowcount_only: into = sql_gen.Table('rowcount')
946
    
947
    cur = run_query_into(db, mk_insert_select(db, table, *args, **kw_args),
948
        into, recover=recover, cacheable=cacheable, log_level=log_level)
949
    if rowcount_only: empty_temp(db, into)
950
    autoanalyze(db, table)
951
    return cur
952

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

    
955
def insert(db, table, row, *args, **kw_args):
956
    '''For params, see insert_select()'''
957
    ignore = kw_args.pop('ignore', False)
958
    if ignore: kw_args.setdefault('recover', True)
959
    
960
    if lists.is_seq(row): cols = None
961
    else:
962
        cols = row.keys()
963
        row = row.values()
964
    row = list(row) # ensure that "== []" works
965
    
966
    if row == []: query = None
967
    else: query = sql_gen.Values(row).to_str(db)
968
    
969
    try: return insert_select(db, table, cols, query, *args, **kw_args)
970
    except (DuplicateKeyException, NullValueException):
971
        if not ignore: raise
972
        return None
973

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

    
1013
def update(db, table, *args, **kw_args):
1014
    '''For params, see mk_update() and run_query()'''
1015
    recover = kw_args.pop('recover', None)
1016
    cacheable = kw_args.pop('cacheable', False)
1017
    log_level = kw_args.pop('log_level', 2)
1018
    
1019
    cur = run_query(db, mk_update(db, table, *args, **kw_args), recover,
1020
        cacheable, log_level=log_level)
1021
    autoanalyze(db, table)
1022
    return cur
1023

    
1024
def mk_delete(db, table, cond=None):
1025
    '''
1026
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
1027
    @return str query
1028
    '''
1029
    query = 'DELETE FROM '+table.to_str(db)
1030
    if cond != None: query += '\nWHERE '+cond.to_str(db)
1031
    
1032
    query = with_explain_comment(db, query)
1033
    
1034
    return query
1035

    
1036
def delete(db, table, *args, **kw_args):
1037
    '''For params, see mk_delete() and run_query()'''
1038
    recover = kw_args.pop('recover', None)
1039
    cacheable = kw_args.pop('cacheable', True)
1040
    log_level = kw_args.pop('log_level', 2)
1041
    
1042
    cur = run_query(db, mk_delete(db, table, *args, **kw_args), recover,
1043
        cacheable, log_level=log_level)
1044
    autoanalyze(db, table)
1045
    return cur
1046

    
1047
def last_insert_id(db):
1048
    module = util.root_module(db.db)
1049
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
1050
    elif module == 'MySQLdb': return db.insert_id()
1051
    else: return None
1052

    
1053
def define_func(db, def_):
1054
    func = def_.function
1055
    while True:
1056
        try:
1057
            run_query(db, def_.to_str(db), recover=True, cacheable=True,
1058
                log_ignore_excs=(DuplicateException,))
1059
            break # successful
1060
        except DuplicateException:
1061
            func.name = next_version(func.name)
1062
            # try again with next version of name
1063

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

    
1096
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
1097
    '''For params, see mk_flatten_mapping()
1098
    @return See return value of mk_flatten_mapping()
1099
    '''
1100
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
1101
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
1102
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
1103
        into=into, add_pkey_=True)
1104
        # don't cache because the temp table will usually be truncated after use
1105
    return dict(items)
1106

    
1107
##### Database structure introspection
1108

    
1109
#### Tables
1110

    
1111
def tables(db, schema_like='public', table_like='%', exact=False,
1112
    cacheable=True):
1113
    if exact: compare = '='
1114
    else: compare = 'LIKE'
1115
    
1116
    module = util.root_module(db.db)
1117
    if module == 'psycopg2':
1118
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1119
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1120
        return values(select(db, 'pg_tables', ['tablename'], conds,
1121
            order_by='tablename', cacheable=cacheable, log_level=4))
1122
    elif module == 'MySQLdb':
1123
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1124
            , cacheable=True, log_level=4))
1125
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1126

    
1127
def table_exists(db, table, cacheable=True):
1128
    table = sql_gen.as_Table(table)
1129
    return list(tables(db, table.schema, table.name, True, cacheable)) != []
1130

    
1131
def table_row_count(db, table, recover=None):
1132
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
1133
        order_by=None), recover=recover, log_level=3))
1134

    
1135
def table_col_names(db, table, recover=None):
1136
    return list(col_names(select(db, table, limit=0, recover=recover,
1137
        log_level=4)))
1138

    
1139
def table_cols(db, table, *args, **kw_args):
1140
    return [sql_gen.as_Col(strings.ustr(c), table)
1141
        for c in table_col_names(db, table, *args, **kw_args)]
1142

    
1143
def table_pkey_index(db, table, recover=None):
1144
    table_str = sql_gen.Literal(table.to_str(db))
1145
    try:
1146
        return sql_gen.Table(value(run_query(db, '''\
1147
SELECT relname
1148
FROM pg_index
1149
JOIN pg_class index ON index.oid = indexrelid
1150
WHERE
1151
indrelid = '''+table_str.to_str(db)+'''::regclass
1152
AND indisprimary
1153
'''
1154
            , recover, cacheable=True, log_level=4)), table.schema)
1155
    except StopIteration: raise DoesNotExistException('primary key', '')
1156

    
1157
def table_pkey_col(db, table, recover=None):
1158
    table = sql_gen.as_Table(table)
1159
    
1160
    module = util.root_module(db.db)
1161
    if module == 'psycopg2':
1162
        return sql_gen.Col(index_cols(db, table_pkey_index(db, table,
1163
            recover))[0], table)
1164
    else:
1165
        join_cols = ['table_schema', 'table_name', 'constraint_schema',
1166
            'constraint_name']
1167
        tables = [sql_gen.Table('key_column_usage', 'information_schema'),
1168
            sql_gen.Join(
1169
                sql_gen.Table('table_constraints', 'information_schema'),
1170
                dict(((c, sql_gen.join_same_not_null) for c in join_cols)))]
1171
        cols = [sql_gen.Col('column_name')]
1172
        
1173
        conds = [('constraint_type', 'PRIMARY KEY'), ('table_name', table.name)]
1174
        schema = table.schema
1175
        if schema != None: conds.append(('table_schema', schema))
1176
        order_by = 'position_in_unique_constraint'
1177
        
1178
        try: return sql_gen.Col(value(select(db, tables, cols, conds,
1179
            order_by=order_by, limit=1, log_level=4)), table)
1180
        except StopIteration: raise DoesNotExistException('primary key', '')
1181

    
1182
def table_has_pkey(db, table, recover=None):
1183
    try: table_pkey_col(db, table, recover)
1184
    except DoesNotExistException: return False
1185
    else: return True
1186

    
1187
def pkey_name(db, table, recover=None):
1188
    '''If no pkey, returns the first column in the table.'''
1189
    return pkey_col(db, table, recover).name
1190

    
1191
def pkey_col(db, table, recover=None):
1192
    '''If no pkey, returns the first column in the table.'''
1193
    try: return table_pkey_col(db, table, recover)
1194
    except DoesNotExistException: return table_cols(db, table, recover)[0]
1195

    
1196
not_null_col = 'not_null_col'
1197

    
1198
def table_not_null_col(db, table, recover=None):
1199
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
1200
    if not_null_col in table_col_names(db, table, recover): return not_null_col
1201
    else: return pkey_name(db, table, recover)
1202

    
1203
def constraint_cond(db, constraint):
1204
    module = util.root_module(db.db)
1205
    if module == 'psycopg2':
1206
        table_str = sql_gen.Literal(constraint.table.to_str(db))
1207
        name_str = sql_gen.Literal(constraint.name)
1208
        return value(run_query(db, '''\
1209
SELECT consrc
1210
FROM pg_constraint
1211
WHERE
1212
conrelid = '''+table_str.to_str(db)+'''::regclass
1213
AND conname = '''+name_str.to_str(db)+'''
1214
'''
1215
            , cacheable=True, log_level=4))
1216
    else: raise NotImplementedError("Can't get constraint condition for "
1217
        +module+' database')
1218

    
1219
def index_exprs(db, index):
1220
    index = sql_gen.as_Table(index)
1221
    module = util.root_module(db.db)
1222
    if module == 'psycopg2':
1223
        qual_index = sql_gen.Literal(index.to_str(db))
1224
        return list(values(run_query(db, '''\
1225
SELECT pg_get_indexdef(indexrelid, generate_series(1, indnatts), true)
1226
FROM pg_index
1227
WHERE indexrelid = '''+qual_index.to_str(db)+'''::regclass
1228
'''
1229
            , cacheable=True, log_level=4)))
1230
    else: raise NotImplementedError()
1231

    
1232
def index_cols(db, index):
1233
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
1234
    automatically created. When you don't know whether something is a UNIQUE
1235
    constraint or a UNIQUE index, use this function.'''
1236
    return map(sql_gen.parse_expr_col, index_exprs(db, index))
1237

    
1238
def index_cond(db, index):
1239
    index = sql_gen.as_Table(index)
1240
    module = util.root_module(db.db)
1241
    if module == 'psycopg2':
1242
        qual_index = sql_gen.Literal(index.to_str(db))
1243
        return value(run_query(db, '''\
1244
SELECT pg_get_expr(indpred, indrelid, true)
1245
FROM pg_index
1246
WHERE indexrelid = '''+qual_index.to_str(db)+'''::regclass
1247
'''
1248
            , cacheable=True, log_level=4))
1249
    else: raise NotImplementedError()
1250

    
1251
def index_order_by(db, index):
1252
    return sql_gen.CustomCode(', '.join(index_exprs(db, index)))
1253

    
1254
def table_cluster_on(db, table, recover=None):
1255
    '''
1256
    @return The table's cluster index, or its pkey if none is set
1257
    '''
1258
    table_str = sql_gen.Literal(table.to_str(db))
1259
    try:
1260
        return sql_gen.Table(value(run_query(db, '''\
1261
SELECT relname
1262
FROM pg_index
1263
JOIN pg_class index ON index.oid = indexrelid
1264
WHERE
1265
indrelid = '''+table_str.to_str(db)+'''::regclass
1266
AND indisclustered
1267
'''
1268
            , recover, cacheable=True, log_level=4)), table.schema)
1269
    except StopIteration: return table_pkey_index(db, table, recover)
1270

    
1271
def table_order_by(db, table, recover=None):
1272
    '''
1273
    @return None if table is view, because table_cluster_on() would return None
1274
    '''
1275
    if table.order_by == None:
1276
        try: table.order_by = index_order_by(db, table_cluster_on(db, table,
1277
            recover))
1278
        except DoesNotExistException: pass
1279
    return table.order_by
1280

    
1281
#### Views
1282

    
1283
def view_exists(db, view):
1284
    view_str = sql_gen.Literal(view.to_str(db))
1285
    try:
1286
        return value(run_query(db, '''\
1287
SELECT relkind = 'v'
1288
FROM pg_class
1289
WHERE oid = '''+view_str.to_str(db)+'''::regclass
1290
'''
1291
            , cacheable=True, log_level=4))
1292
    except DoesNotExistException: return False
1293

    
1294
#### Functions
1295

    
1296
def function_exists(db, function):
1297
    qual_function = sql_gen.Literal(function.to_str(db))
1298
    try:
1299
        select(db, fields=[sql_gen.Cast('regproc', qual_function)],
1300
            recover=True, cacheable=True, log_level=4)
1301
    except DoesNotExistException: return False
1302
    except DuplicateException: return True # overloaded function
1303
    else: return True
1304

    
1305
def function_param0_type(db, function):
1306
    qual_function = sql_gen.Literal(function.to_str(db))
1307
    return value(run_query(db, '''\
1308
SELECT proargtypes[0]::regtype
1309
FROM pg_proc
1310
WHERE oid = '''+qual_function.to_str(db)+'''::regproc
1311
'''
1312
        , cacheable=True, log_level=4))
1313

    
1314
##### Structural changes
1315

    
1316
#### Columns
1317

    
1318
def add_col(db, table, col, comment=None, if_not_exists=False, **kw_args):
1319
    '''
1320
    @param col TypedCol Name may be versioned, so be sure to propagate any
1321
        renaming back to any source column for the TypedCol.
1322
    @param comment None|str SQL comment used to distinguish columns of the same
1323
        name from each other when they contain different data, to allow the
1324
        ADD COLUMN query to be cached. If not set, query will not be cached.
1325
    '''
1326
    assert isinstance(col, sql_gen.TypedCol)
1327
    
1328
    while True:
1329
        str_ = 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '+col.to_str(db)
1330
        if comment != None: str_ += ' '+sql_gen.esc_comment(comment)
1331
        
1332
        try:
1333
            run_query(db, str_, recover=True, cacheable=True, **kw_args)
1334
            break
1335
        except DuplicateException:
1336
            if if_not_exists: raise
1337
            col.name = next_version(col.name)
1338
            # try again with next version of name
1339

    
1340
def add_not_null(db, col):
1341
    table = col.table
1342
    col = sql_gen.to_name_only_col(col)
1343
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1344
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1345

    
1346
def drop_not_null(db, col):
1347
    table = col.table
1348
    col = sql_gen.to_name_only_col(col)
1349
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1350
        +col.to_str(db)+' DROP NOT NULL', cacheable=True, log_level=3)
1351

    
1352
row_num_col = '_row_num'
1353

    
1354
row_num_col_def = sql_gen.TypedCol('', 'serial', nullable=False,
1355
    constraints='PRIMARY KEY')
1356

    
1357
def add_row_num(db, table, name=row_num_col):
1358
    '''Adds a row number column to a table. Its definition is in
1359
    row_num_col_def. It will be the primary key.'''
1360
    col_def = copy.copy(row_num_col_def)
1361
    col_def.name = name
1362
    add_col(db, table, col_def, comment='', if_not_exists=True, log_level=3)
1363

    
1364
#### Indexes
1365

    
1366
def add_pkey(db, table, cols=None, recover=None):
1367
    '''Adds a primary key.
1368
    @param cols [sql_gen.Col,...] The columns in the primary key.
1369
        Defaults to the first column in the table.
1370
    @pre The table must not already have a primary key.
1371
    '''
1372
    table = sql_gen.as_Table(table)
1373
    if cols == None: cols = [pkey_name(db, table, recover)]
1374
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1375
    
1376
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1377
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1378
        log_ignore_excs=(DuplicateException,))
1379

    
1380
def add_index(db, exprs, table=None, unique=False, ensure_not_null_=True):
1381
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
1382
    Currently, only function calls and literal values are supported expressions.
1383
    @param ensure_not_null_ If set, translates NULL values to sentinel values.
1384
        This allows indexes to be used for comparisons where NULLs are equal.
1385
    '''
1386
    exprs = lists.mk_seq(exprs)
1387
    
1388
    # Parse exprs
1389
    old_exprs = exprs[:]
1390
    exprs = []
1391
    cols = []
1392
    for i, expr in enumerate(old_exprs):
1393
        expr = sql_gen.as_Col(expr, table)
1394
        
1395
        # Handle nullable columns
1396
        if ensure_not_null_:
1397
            try: expr = sql_gen.ensure_not_null(db, expr)
1398
            except KeyError: pass # unknown type, so just create plain index
1399
        
1400
        # Extract col
1401
        expr = copy.deepcopy(expr) # don't modify input!
1402
        col = expr
1403
        if isinstance(expr, sql_gen.FunctionCall): col = expr.args[0]
1404
        expr = sql_gen.cast_literal(expr)
1405
        if not isinstance(expr, (sql_gen.Expr, sql_gen.Col)):
1406
            expr = sql_gen.Expr(expr)
1407
            
1408
        
1409
        # Extract table
1410
        if table == None:
1411
            assert sql_gen.is_table_col(col)
1412
            table = col.table
1413
        
1414
        if isinstance(col, sql_gen.Col): col.table = None
1415
        
1416
        exprs.append(expr)
1417
        cols.append(col)
1418
    
1419
    table = sql_gen.as_Table(table)
1420
    
1421
    # Add index
1422
    str_ = 'CREATE'
1423
    if unique: str_ += ' UNIQUE'
1424
    str_ += ' INDEX ON '+table.to_str(db)+' ('+(
1425
        ', '.join((v.to_str(db) for v in exprs)))+')'
1426
    run_query(db, str_, recover=True, cacheable=True, log_level=3)
1427

    
1428
def add_pkey_index(db, table): add_index(db, pkey_col(db, table), table)
1429

    
1430
def add_pkey_or_index(db, table, cols=None, recover=None, warn=False):
1431
    try: add_pkey(db, table, cols, recover)
1432
    except DuplicateKeyException, e:
1433
        if warn: warnings.warn(UserWarning(exc.str_(e)))
1434
        add_pkey_index(db, table)
1435

    
1436
already_indexed = object() # tells add_indexes() the pkey has already been added
1437

    
1438
def add_indexes(db, table, has_pkey=True):
1439
    '''Adds an index on all columns in a table.
1440
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1441
        index should be added on the first column.
1442
        * If already_indexed, the pkey is assumed to have already been added
1443
    '''
1444
    cols = table_col_names(db, table)
1445
    if has_pkey:
1446
        if has_pkey is not already_indexed: add_pkey(db, table)
1447
        cols = cols[1:]
1448
    for col in cols: add_index(db, col, table)
1449

    
1450
#### Tables
1451

    
1452
### Maintenance
1453

    
1454
def analyze(db, table):
1455
    table = sql_gen.as_Table(table)
1456
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1457

    
1458
def autoanalyze(db, table):
1459
    if db.autoanalyze: analyze(db, table)
1460

    
1461
def vacuum(db, table):
1462
    table = sql_gen.as_Table(table)
1463
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1464
        log_level=3))
1465

    
1466
### Lifecycle
1467

    
1468
def drop(db, type_, name):
1469
    name = sql_gen.as_Name(name)
1470
    run_query(db, 'DROP '+type_+' IF EXISTS '+name.to_str(db)+' CASCADE')
1471

    
1472
def drop_table(db, table): drop(db, 'TABLE', table)
1473

    
1474
def create_table(db, table, cols=[], has_pkey=True, col_indexes=True,
1475
    like=None):
1476
    '''Creates a table.
1477
    @param cols [sql_gen.TypedCol,...] The column names and types
1478
    @param has_pkey If set, the first column becomes the primary key.
1479
    @param col_indexes bool|[ref]
1480
        * If True, indexes will be added on all non-pkey columns.
1481
        * If a list reference, [0] will be set to a function to do this.
1482
          This can be used to delay index creation until the table is populated.
1483
    '''
1484
    table = sql_gen.as_Table(table)
1485
    
1486
    if like != None:
1487
        cols = [sql_gen.CustomCode('LIKE '+like.to_str(db)+' INCLUDING ALL')
1488
            ]+cols
1489
        table.order_by = like.order_by
1490
    if has_pkey:
1491
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1492
        pkey.constraints = 'PRIMARY KEY'
1493
    
1494
    temp = table.is_temp and not db.debug_temp
1495
        # temp tables permanent in debug_temp mode
1496
    
1497
    # Create table
1498
    def create():
1499
        str_ = 'CREATE'
1500
        if temp: str_ += ' TEMP'
1501
        str_ += ' TABLE '+table.to_str(db)+' (\n'
1502
        str_ += '\n, '.join(c.to_str(db) for c in cols)
1503
        str_ += '\n);'
1504
        
1505
        opts = dict(recover=True, cacheable=True, log_level=2,
1506
            log_ignore_excs=(DuplicateException,))
1507
        try: run_query(db, str_, **opts)
1508
        except InvalidTypeException: # try again as view
1509
            run_query_into(db, mk_select(db, like, limit=0), into=table, **opts)
1510
    if table.is_temp:
1511
        while True:
1512
            try:
1513
                create()
1514
                break
1515
            except DuplicateException:
1516
                table.name = next_version(table.name)
1517
                # try again with next version of name
1518
    else: create()
1519
    
1520
    # Add indexes
1521
    if has_pkey: has_pkey = already_indexed
1522
    def add_indexes_(): add_indexes(db, table, has_pkey)
1523
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1524
    elif col_indexes: add_indexes_() # add now
1525

    
1526
def copy_table_struct(db, src, dest):
1527
    '''Creates a structure-only copy of a table. (Does not copy data.)'''
1528
    create_table(db, dest, has_pkey=False, col_indexes=False, like=src)
1529

    
1530
def copy_table(db, src, dest):
1531
    '''Creates a copy of a table, including data'''
1532
    copy_table_struct(db, src, dest)
1533
    insert_select(db, dest, None, mk_select(db, src))
1534

    
1535
### Data
1536

    
1537
def truncate(db, table, schema='public', **kw_args):
1538
    '''For params, see run_query()'''
1539
    table = sql_gen.as_Table(table, schema)
1540
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1541

    
1542
def empty_temp(db, tables):
1543
    tables = lists.mk_seq(tables)
1544
    for table in tables: truncate(db, table, log_level=3)
1545

    
1546
def empty_db(db, schema='public', **kw_args):
1547
    '''For kw_args, see tables()'''
1548
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1549

    
1550
def distinct_table(db, table, distinct_on, joins=None):
1551
    '''Creates a copy of a temp table which is distinct on the given columns.
1552
    Adds an index on table's distinct_on columns, to facilitate merge joins.
1553
    @param distinct_on If empty, creates a table with one row. This is useful if
1554
        your distinct_on columns are all literal values.
1555
    @param joins The joins to use when creating the new table
1556
    @return The new table.
1557
    '''
1558
    if joins == None: joins = [table]
1559
    
1560
    new_table = sql_gen.suffixed_table(table, '_distinct')
1561
    distinct_on = filter(sql_gen.is_table_col, distinct_on)
1562
    
1563
    copy_table_struct(db, table, new_table)
1564
    
1565
    limit = None
1566
    if distinct_on == []: limit = 1 # one sample row
1567
    else: add_index(db, distinct_on, table) # for join optimization
1568
    
1569
    insert_select(db, new_table, None, mk_select(db, joins,
1570
        [sql_gen.Col(sql_gen.all_cols, table)], distinct_on=distinct_on,
1571
        order_by=None, limit=limit))
1572
    analyze(db, new_table)
1573
    
1574
    return new_table
(36-36/50)