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 DuplicateException(ExceptionWithNameType): pass
86

    
87
class DoesNotExistException(ExceptionWithNameType): pass
88

    
89
class EmptyRowException(DbException): pass
90

    
91
##### Warnings
92

    
93
class DbWarning(UserWarning): pass
94

    
95
##### Result retrieval
96

    
97
def col_names(cur): return (col[0] for col in cur.description)
98

    
99
def rows(cur): return iter(lambda: cur.fetchone(), None)
100

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

    
105
def next_row(cur): return rows(cur).next()
106

    
107
def row(cur):
108
    row_ = next_row(cur)
109
    consume_rows(cur)
110
    return row_
111

    
112
def next_value(cur): return next_row(cur)[0]
113

    
114
def value(cur): return row(cur)[0]
115

    
116
def values(cur): return iters.func_iter(lambda: next_value(cur))
117

    
118
def value_or_none(cur):
119
    try: return value(cur)
120
    except StopIteration: return None
121

    
122
##### Escaping
123

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

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

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

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

    
142
##### Database connections
143

    
144
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
145

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

    
151
DatabaseErrors_set = set([DbException])
152
DatabaseErrors = tuple(DatabaseErrors_set)
153

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

    
159
def db_config_str(db_config):
160
    return db_config['engine']+' database '+db_config['database']
161

    
162
log_debug_none = lambda msg, level=2: None
163

    
164
class DbConn:
165
    def __init__(self, db_config, autocommit=True, caching=True,
166
        log_debug=log_debug_none, debug_temp=False, src=None):
167
        '''
168
        @param debug_temp Whether temporary objects should instead be permanent.
169
            This assists in debugging the internal objects used by the program.
170
        @param src In autocommit mode, will be included in a comment in every
171
            query, to help identify the data source in pg_stat_activity.
172
        '''
173
        self.db_config = db_config
174
        self.autocommit = autocommit
175
        self.caching = caching
176
        self.log_debug = log_debug
177
        self.debug = log_debug != log_debug_none
178
        self.debug_temp = debug_temp
179
        self.src = src
180
        self.autoanalyze = False
181
        self.autoexplain = False
182
        self.profile_row_ct = None
183
        
184
        self._savepoint = 0
185
        self._reset()
186
    
187
    def __getattr__(self, name):
188
        if name == '__dict__': raise Exception('getting __dict__')
189
        if name == 'db': return self._db()
190
        else: raise AttributeError()
191
    
192
    def __getstate__(self):
193
        state = copy.copy(self.__dict__) # shallow copy
194
        state['log_debug'] = None # don't pickle the debug callback
195
        state['_DbConn__db'] = None # don't pickle the connection
196
        return state
197
    
198
    def clear_cache(self): self.query_results = {}
199
    
200
    def _reset(self):
201
        self.clear_cache()
202
        assert self._savepoint == 0
203
        self._notices_seen = set()
204
        self.__db = None
205
    
206
    def connected(self): return self.__db != None
207
    
208
    def close(self):
209
        if not self.connected(): return
210
        
211
        # Record that the automatic transaction is now closed
212
        self._savepoint -= 1
213
        
214
        self.db.close()
215
        self._reset()
216
    
217
    def reconnect(self):
218
        # Do not do this in test mode as it would roll back everything
219
        if self.autocommit: self.close()
220
        # Connection will be reopened automatically on first query
221
    
222
    def _db(self):
223
        if self.__db == None:
224
            # Process db_config
225
            db_config = self.db_config.copy() # don't modify input!
226
            schemas = db_config.pop('schemas', None)
227
            module_name, mappings = db_engines[db_config.pop('engine')]
228
            module = __import__(module_name)
229
            _add_module(module)
230
            for orig, new in mappings.iteritems():
231
                try: util.rename_key(db_config, orig, new)
232
                except KeyError: pass
233
            
234
            # Connect
235
            self.__db = module.connect(**db_config)
236
            
237
            # Record that a transaction is already open
238
            self._savepoint += 1
239
            
240
            # Configure connection
241
            if hasattr(self.db, 'set_isolation_level'):
242
                import psycopg2.extensions
243
                self.db.set_isolation_level(
244
                    psycopg2.extensions.ISOLATION_LEVEL_READ_COMMITTED)
245
            if schemas != None:
246
                search_path = [self.esc_name(s) for s in schemas.split(',')]
247
                search_path.append(value(run_query(self, 'SHOW search_path',
248
                    log_level=4)))
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_attrdef.adsrc 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
                    , cacheable=True, log_level=4))
491
            except StopIteration: raise sql_gen.NoUnderlyingTableException(col)
492
            if is_array: type_ = sql_gen.ArrayType(type_)
493
        else:
494
            table = sql_gen.Table('columns', 'information_schema')
495
            cols = [sql_gen.Col('data_type'), sql_gen.Col('udt_name'),
496
                'column_default', sql_gen.Cast('boolean',
497
                sql_gen.Col('is_nullable'))]
498
            
499
            conds = [('table_name', col.table.name),
500
                ('column_name', strings.ustr(col.name))]
501
            schema = col.table.schema
502
            if schema != None: conds.append(('table_schema', schema))
503
            
504
            cur = select(self, table, cols, conds, order_by='table_schema',
505
                limit=1, cacheable=cacheable, log_level=4)
506
            try: type_, extra_type, default, nullable = row(cur)
507
            except StopIteration: raise sql_gen.NoUnderlyingTableException(col)
508
            if type_ == 'USER-DEFINED': type_ = extra_type
509
            elif type_ == 'ARRAY':
510
                type_ = sql_gen.ArrayType(strings.remove_prefix('_', extra_type,
511
                    require=True))
512
        
513
        if default != None: default = sql_gen.as_Code(default, self)
514
        return sql_gen.TypedCol(col.name, type_, default, nullable)
515
    
516
    def TempFunction(self, name):
517
        if self.debug_temp: schema = None
518
        else: schema = 'pg_temp'
519
        return sql_gen.Function(name, schema)
520

    
521
connect = DbConn
522

    
523
##### Recoverable querying
524

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

    
628
def with_savepoint(db, func): return db.with_savepoint(func)
629

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

    
658
##### Basic queries
659

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

    
665
def explain(db, query, **kw_args):
666
    '''
667
    For params, see run_query().
668
    '''
669
    kw_args.setdefault('log_level', 4)
670
    
671
    return strings.ustr(strings.join_lines(values(run_query(db,
672
        'EXPLAIN '+query, recover=True, cacheable=True, **kw_args))))
673
        # not a higher log_level because it's useful to see what query is being
674
        # run before it's executed, which EXPLAIN effectively provides
675

    
676
def has_comment(query): return query.endswith('*/')
677

    
678
def with_explain_comment(db, query, **kw_args):
679
    if db.autoexplain and not has_comment(query) and is_explainable(query):
680
        query += '\n'+sql_gen.esc_comment(' EXPLAIN:\n'
681
            +explain(db, query, **kw_args))
682
    return query
683

    
684
def next_version(name):
685
    version = 1 # first existing name was version 0
686
    match = re.match(r'^(.*)#(\d+)$', name)
687
    if match:
688
        name, version = match.groups()
689
        version = int(version)+1
690
    return sql_gen.concat(name, '#'+str(version))
691

    
692
def lock_table(db, table, mode):
693
    table = sql_gen.as_Table(table)
694
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
695

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

    
739
order_by_pkey = object() # tells mk_select() to order by the pkey
740

    
741
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
742

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

    
829
def select(db, *args, **kw_args):
830
    '''For params, see mk_select() and run_query()'''
831
    recover = kw_args.pop('recover', None)
832
    cacheable = kw_args.pop('cacheable', True)
833
    log_level = kw_args.pop('log_level', 2)
834
    
835
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
836
        log_level=log_level)
837

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

    
912
def insert_select(db, table, *args, **kw_args):
913
    '''For params, see mk_insert_select() and run_query_into()
914
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
915
        values in
916
    '''
917
    returning = kw_args.get('returning', None)
918
    ignore = kw_args.get('ignore', False)
919
    
920
    into = kw_args.pop('into', None)
921
    if into != None: kw_args['embeddable'] = True
922
    recover = kw_args.pop('recover', None)
923
    if ignore: recover = True
924
    cacheable = kw_args.pop('cacheable', True)
925
    log_level = kw_args.pop('log_level', 2)
926
    
927
    rowcount_only = ignore and returning == None # keep NULL rows on server
928
    if rowcount_only: into = sql_gen.Table('rowcount')
929
    
930
    cur = run_query_into(db, mk_insert_select(db, table, *args, **kw_args),
931
        into, recover=recover, cacheable=cacheable, log_level=log_level)
932
    if rowcount_only: empty_temp(db, into)
933
    autoanalyze(db, table)
934
    return cur
935

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

    
938
def insert(db, table, row, *args, **kw_args):
939
    '''For params, see insert_select()'''
940
    ignore = kw_args.pop('ignore', False)
941
    if ignore: kw_args.setdefault('recover', True)
942
    
943
    if lists.is_seq(row): cols = None
944
    else:
945
        cols = row.keys()
946
        row = row.values()
947
    row = list(row) # ensure that "== []" works
948
    
949
    if row == []: query = None
950
    else: query = sql_gen.Values(row).to_str(db)
951
    
952
    try: return insert_select(db, table, cols, query, *args, **kw_args)
953
    except (DuplicateKeyException, NullValueException):
954
        if not ignore: raise
955
        return None
956

    
957
def mk_update(db, table, changes=None, cond=None, in_place=False,
958
    cacheable_=True):
959
    '''
960
    @param changes [(col, new_value),...]
961
        * container can be any iterable type
962
        * col: sql_gen.Code|str (for col name)
963
        * new_value: sql_gen.Code|literal value
964
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
965
    @param in_place If set, locks the table and updates rows in place.
966
        This avoids creating dead rows in PostgreSQL.
967
        * cond must be None
968
    @param cacheable_ Whether column structure information used to generate the
969
        query can be cached
970
    @return str query
971
    '''
972
    table = sql_gen.as_Table(table)
973
    changes = [(sql_gen.to_name_only_col(c, table), sql_gen.as_Value(v))
974
        for c, v in changes]
975
    
976
    if in_place:
977
        assert cond == None
978
        
979
        def col_type(col):
980
            return sql_gen.canon_type(db.col_info(
981
                sql_gen.with_default_table(c, table), cacheable_).type)
982
        changes = [(c, v, col_type(c)) for c, v in changes]
983
        query = 'ALTER TABLE '+table.to_str(db)+'\n'
984
        query += ',\n'.join(('ALTER COLUMN '+c.to_str(db)+' TYPE '+t+'\nUSING '
985
            +v.to_str(db) for c, v, t in changes))
986
    else:
987
        query = 'UPDATE '+table.to_str(db)+'\nSET\n'
988
        query += ',\n'.join((c.to_str(db)+' = '+v.to_str(db)
989
            for c, v in changes))
990
        if cond != None: query += '\nWHERE\n'+cond.to_str(db)
991
    
992
    query = with_explain_comment(db, query)
993
    
994
    return query
995

    
996
def update(db, table, *args, **kw_args):
997
    '''For params, see mk_update() and run_query()'''
998
    recover = kw_args.pop('recover', None)
999
    cacheable = kw_args.pop('cacheable', False)
1000
    log_level = kw_args.pop('log_level', 2)
1001
    
1002
    cur = run_query(db, mk_update(db, table, *args, **kw_args), recover,
1003
        cacheable, log_level=log_level)
1004
    autoanalyze(db, table)
1005
    return cur
1006

    
1007
def mk_delete(db, table, cond=None):
1008
    '''
1009
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
1010
    @return str query
1011
    '''
1012
    query = 'DELETE FROM '+table.to_str(db)
1013
    if cond != None: query += '\nWHERE '+cond.to_str(db)
1014
    
1015
    query = with_explain_comment(db, query)
1016
    
1017
    return query
1018

    
1019
def delete(db, table, *args, **kw_args):
1020
    '''For params, see mk_delete() and run_query()'''
1021
    recover = kw_args.pop('recover', None)
1022
    cacheable = kw_args.pop('cacheable', True)
1023
    log_level = kw_args.pop('log_level', 2)
1024
    
1025
    cur = run_query(db, mk_delete(db, table, *args, **kw_args), recover,
1026
        cacheable, log_level=log_level)
1027
    autoanalyze(db, table)
1028
    return cur
1029

    
1030
def last_insert_id(db):
1031
    module = util.root_module(db.db)
1032
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
1033
    elif module == 'MySQLdb': return db.insert_id()
1034
    else: return None
1035

    
1036
def define_func(db, def_):
1037
    func = def_.function
1038
    while True:
1039
        try:
1040
            run_query(db, def_.to_str(db), recover=True, cacheable=True,
1041
                log_ignore_excs=(DuplicateException,))
1042
            break # successful
1043
        except DuplicateException:
1044
            func.name = next_version(func.name)
1045
            # try again with next version of name
1046

    
1047
def mk_flatten_mapping(db, into, cols, preserve=[], as_items=False):
1048
    '''Creates a mapping from original column names (which may have collisions)
1049
    to names that will be distinct among the columns' tables.
1050
    This is meant to be used for several tables that are being joined together.
1051
    @param cols The columns to combine. Duplicates will be removed.
1052
    @param into The table for the new columns.
1053
    @param preserve [sql_gen.Col...] Columns not to rename. Note that these
1054
        columns will be included in the mapping even if they are not in cols.
1055
        The tables of the provided Col objects will be changed to into, so make
1056
        copies of them if you want to keep the original tables.
1057
    @param as_items Whether to return a list of dict items instead of a dict
1058
    @return dict(orig_col=new_col, ...)
1059
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
1060
        * new_col: sql_gen.Col(orig_col_name, into)
1061
        * All mappings use the into table so its name can easily be
1062
          changed for all columns at once
1063
    '''
1064
    cols = lists.uniqify(cols)
1065
    
1066
    items = []
1067
    for col in preserve:
1068
        orig_col = copy.copy(col)
1069
        col.table = into
1070
        items.append((orig_col, col))
1071
    preserve = set(preserve)
1072
    for col in cols:
1073
        if col not in preserve:
1074
            items.append((col, sql_gen.Col(strings.ustr(col), into, col.srcs)))
1075
    
1076
    if not as_items: items = dict(items)
1077
    return items
1078

    
1079
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
1080
    '''For params, see mk_flatten_mapping()
1081
    @return See return value of mk_flatten_mapping()
1082
    '''
1083
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
1084
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
1085
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
1086
        into=into, add_pkey_=True)
1087
        # don't cache because the temp table will usually be truncated after use
1088
    return dict(items)
1089

    
1090
##### Database structure introspection
1091

    
1092
#### Tables
1093

    
1094
def tables(db, schema_like='public', table_like='%', exact=False,
1095
    cacheable=True):
1096
    if exact: compare = '='
1097
    else: compare = 'LIKE'
1098
    
1099
    module = util.root_module(db.db)
1100
    if module == 'psycopg2':
1101
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1102
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1103
        return values(select(db, 'pg_tables', ['tablename'], conds,
1104
            order_by='tablename', cacheable=cacheable, log_level=4))
1105
    elif module == 'MySQLdb':
1106
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1107
            , cacheable=True, log_level=4))
1108
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1109

    
1110
def table_exists(db, table, cacheable=True):
1111
    table = sql_gen.as_Table(table)
1112
    return list(tables(db, table.schema, table.name, True, cacheable)) != []
1113

    
1114
def table_row_count(db, table, recover=None):
1115
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
1116
        order_by=None), recover=recover, log_level=3))
1117

    
1118
def table_col_names(db, table, recover=None):
1119
    return list(col_names(select(db, table, limit=0, recover=recover,
1120
        log_level=4)))
1121

    
1122
def table_cols(db, table, *args, **kw_args):
1123
    return [sql_gen.as_Col(strings.ustr(c), table)
1124
        for c in table_col_names(db, table, *args, **kw_args)]
1125

    
1126
def table_pkey_index(db, table, recover=None):
1127
    table_str = sql_gen.Literal(table.to_str(db))
1128
    try:
1129
        return sql_gen.Table(value(run_query(db, '''\
1130
SELECT relname
1131
FROM pg_index
1132
JOIN pg_class index ON index.oid = indexrelid
1133
WHERE
1134
indrelid = '''+table_str.to_str(db)+'''::regclass
1135
AND indisprimary
1136
'''
1137
            , recover, cacheable=True, log_level=4)), table.schema)
1138
    except StopIteration: raise DoesNotExistException('primary key', '')
1139

    
1140
def table_pkey_col(db, table, recover=None):
1141
    table = sql_gen.as_Table(table)
1142
    
1143
    module = util.root_module(db.db)
1144
    if module == 'psycopg2':
1145
        return sql_gen.Col(index_cols(db, table_pkey_index(db, table,
1146
            recover))[0], table)
1147
    else:
1148
        join_cols = ['table_schema', 'table_name', 'constraint_schema',
1149
            'constraint_name']
1150
        tables = [sql_gen.Table('key_column_usage', 'information_schema'),
1151
            sql_gen.Join(
1152
                sql_gen.Table('table_constraints', 'information_schema'),
1153
                dict(((c, sql_gen.join_same_not_null) for c in join_cols)))]
1154
        cols = [sql_gen.Col('column_name')]
1155
        
1156
        conds = [('constraint_type', 'PRIMARY KEY'), ('table_name', table.name)]
1157
        schema = table.schema
1158
        if schema != None: conds.append(('table_schema', schema))
1159
        order_by = 'position_in_unique_constraint'
1160
        
1161
        try: return sql_gen.Col(value(select(db, tables, cols, conds,
1162
            order_by=order_by, limit=1, log_level=4)), table)
1163
        except StopIteration: raise DoesNotExistException('primary key', '')
1164

    
1165
def table_has_pkey(db, table, recover=None):
1166
    try: table_pkey_col(db, table, recover)
1167
    except DoesNotExistException: return False
1168
    else: return True
1169

    
1170
def pkey_name(db, table, recover=None):
1171
    '''If no pkey, returns the first column in the table.'''
1172
    return pkey_col(db, table, recover).name
1173

    
1174
def pkey_col(db, table, recover=None):
1175
    '''If no pkey, returns the first column in the table.'''
1176
    try: return table_pkey_col(db, table, recover)
1177
    except DoesNotExistException: return table_cols(db, table, recover)[0]
1178

    
1179
not_null_col = 'not_null_col'
1180

    
1181
def table_not_null_col(db, table, recover=None):
1182
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
1183
    if not_null_col in table_col_names(db, table, recover): return not_null_col
1184
    else: return pkey_name(db, table, recover)
1185

    
1186
def constraint_cond(db, constraint):
1187
    module = util.root_module(db.db)
1188
    if module == 'psycopg2':
1189
        table_str = sql_gen.Literal(constraint.table.to_str(db))
1190
        name_str = sql_gen.Literal(constraint.name)
1191
        return value(run_query(db, '''\
1192
SELECT consrc
1193
FROM pg_constraint
1194
WHERE
1195
conrelid = '''+table_str.to_str(db)+'''::regclass
1196
AND conname = '''+name_str.to_str(db)+'''
1197
'''
1198
            , cacheable=True, log_level=4))
1199
    else: raise NotImplementedError("Can't get constraint condition for "
1200
        +module+' database')
1201

    
1202
def index_exprs(db, index):
1203
    index = sql_gen.as_Table(index)
1204
    module = util.root_module(db.db)
1205
    if module == 'psycopg2':
1206
        qual_index = sql_gen.Literal(index.to_str(db))
1207
        return list(values(run_query(db, '''\
1208
SELECT pg_get_indexdef(indexrelid, generate_series(1, indnatts), true)
1209
FROM pg_index
1210
WHERE indexrelid = '''+qual_index.to_str(db)+'''::regclass
1211
'''
1212
            , cacheable=True, log_level=4)))
1213
    else: raise NotImplementedError()
1214

    
1215
def index_cols(db, index):
1216
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
1217
    automatically created. When you don't know whether something is a UNIQUE
1218
    constraint or a UNIQUE index, use this function.'''
1219
    return map(sql_gen.parse_expr_col, index_exprs(db, index))
1220

    
1221
def index_cond(db, index):
1222
    index = sql_gen.as_Table(index)
1223
    module = util.root_module(db.db)
1224
    if module == 'psycopg2':
1225
        qual_index = sql_gen.Literal(index.to_str(db))
1226
        return value(run_query(db, '''\
1227
SELECT pg_get_expr(indpred, indrelid, true)
1228
FROM pg_index
1229
WHERE indexrelid = '''+qual_index.to_str(db)+'''::regclass
1230
'''
1231
            , cacheable=True, log_level=4))
1232
    else: raise NotImplementedError()
1233

    
1234
def index_order_by(db, index):
1235
    return sql_gen.CustomCode(', '.join(index_exprs(db, index)))
1236

    
1237
def table_cluster_on(db, table, recover=None):
1238
    '''
1239
    @return The table's cluster index, or its pkey if none is set
1240
    '''
1241
    table_str = sql_gen.Literal(table.to_str(db))
1242
    try:
1243
        return sql_gen.Table(value(run_query(db, '''\
1244
SELECT relname
1245
FROM pg_index
1246
JOIN pg_class index ON index.oid = indexrelid
1247
WHERE
1248
indrelid = '''+table_str.to_str(db)+'''::regclass
1249
AND indisclustered
1250
'''
1251
            , recover, cacheable=True, log_level=4)), table.schema)
1252
    except StopIteration: return table_pkey_index(db, table, recover)
1253

    
1254
def table_order_by(db, table, recover=None):
1255
    if table.order_by == None:
1256
        try: table.order_by = index_order_by(db, table_cluster_on(db, table,
1257
            recover))
1258
        except DoesNotExistException: pass
1259
    return table.order_by
1260

    
1261
#### Functions
1262

    
1263
def function_exists(db, function):
1264
    qual_function = sql_gen.Literal(function.to_str(db))
1265
    try:
1266
        select(db, fields=[sql_gen.Cast('regproc', qual_function)],
1267
            recover=True, cacheable=True, log_level=4)
1268
    except DoesNotExistException: return False
1269
    except DuplicateException: return True # overloaded function
1270
    else: return True
1271

    
1272
def function_param0_type(db, function):
1273
    qual_function = sql_gen.Literal(function.to_str(db))
1274
    return value(run_query(db, '''\
1275
SELECT proargtypes[0]::regtype
1276
FROM pg_proc
1277
WHERE oid = '''+qual_function.to_str(db)+'''::regproc
1278
'''
1279
        , cacheable=True, log_level=4))
1280

    
1281
##### Structural changes
1282

    
1283
#### Columns
1284

    
1285
def add_col(db, table, col, comment=None, if_not_exists=False, **kw_args):
1286
    '''
1287
    @param col TypedCol Name may be versioned, so be sure to propagate any
1288
        renaming back to any source column for the TypedCol.
1289
    @param comment None|str SQL comment used to distinguish columns of the same
1290
        name from each other when they contain different data, to allow the
1291
        ADD COLUMN query to be cached. If not set, query will not be cached.
1292
    '''
1293
    assert isinstance(col, sql_gen.TypedCol)
1294
    
1295
    while True:
1296
        str_ = 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '+col.to_str(db)
1297
        if comment != None: str_ += ' '+sql_gen.esc_comment(comment)
1298
        
1299
        try:
1300
            run_query(db, str_, recover=True, cacheable=True, **kw_args)
1301
            break
1302
        except DuplicateException:
1303
            if if_not_exists: raise
1304
            col.name = next_version(col.name)
1305
            # try again with next version of name
1306

    
1307
def add_not_null(db, col):
1308
    table = col.table
1309
    col = sql_gen.to_name_only_col(col)
1310
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1311
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1312

    
1313
def drop_not_null(db, col):
1314
    table = col.table
1315
    col = sql_gen.to_name_only_col(col)
1316
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1317
        +col.to_str(db)+' DROP NOT NULL', cacheable=True, log_level=3)
1318

    
1319
row_num_col = '_row_num'
1320

    
1321
row_num_col_def = sql_gen.TypedCol('', 'serial', nullable=False,
1322
    constraints='PRIMARY KEY')
1323

    
1324
def add_row_num(db, table, name=row_num_col):
1325
    '''Adds a row number column to a table. Its definition is in
1326
    row_num_col_def. It will be the primary key.'''
1327
    col_def = copy.copy(row_num_col_def)
1328
    col_def.name = name
1329
    add_col(db, table, col_def, comment='', if_not_exists=True, log_level=3)
1330

    
1331
#### Indexes
1332

    
1333
def add_pkey(db, table, cols=None, recover=None):
1334
    '''Adds a primary key.
1335
    @param cols [sql_gen.Col,...] The columns in the primary key.
1336
        Defaults to the first column in the table.
1337
    @pre The table must not already have a primary key.
1338
    '''
1339
    table = sql_gen.as_Table(table)
1340
    if cols == None: cols = [pkey_name(db, table, recover)]
1341
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1342
    
1343
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1344
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1345
        log_ignore_excs=(DuplicateException,))
1346

    
1347
def add_index(db, exprs, table=None, unique=False, ensure_not_null_=True):
1348
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
1349
    Currently, only function calls and literal values are supported expressions.
1350
    @param ensure_not_null_ If set, translates NULL values to sentinel values.
1351
        This allows indexes to be used for comparisons where NULLs are equal.
1352
    '''
1353
    exprs = lists.mk_seq(exprs)
1354
    
1355
    # Parse exprs
1356
    old_exprs = exprs[:]
1357
    exprs = []
1358
    cols = []
1359
    for i, expr in enumerate(old_exprs):
1360
        expr = sql_gen.as_Col(expr, table)
1361
        
1362
        # Handle nullable columns
1363
        if ensure_not_null_:
1364
            try: expr = sql_gen.ensure_not_null(db, expr)
1365
            except KeyError: pass # unknown type, so just create plain index
1366
        
1367
        # Extract col
1368
        expr = copy.deepcopy(expr) # don't modify input!
1369
        col = expr
1370
        if isinstance(expr, sql_gen.FunctionCall): col = expr.args[0]
1371
        expr = sql_gen.cast_literal(expr)
1372
        if not isinstance(expr, (sql_gen.Expr, sql_gen.Col)):
1373
            expr = sql_gen.Expr(expr)
1374
            
1375
        
1376
        # Extract table
1377
        if table == None:
1378
            assert sql_gen.is_table_col(col)
1379
            table = col.table
1380
        
1381
        if isinstance(col, sql_gen.Col): col.table = None
1382
        
1383
        exprs.append(expr)
1384
        cols.append(col)
1385
    
1386
    table = sql_gen.as_Table(table)
1387
    
1388
    # Add index
1389
    str_ = 'CREATE'
1390
    if unique: str_ += ' UNIQUE'
1391
    str_ += ' INDEX ON '+table.to_str(db)+' ('+(
1392
        ', '.join((v.to_str(db) for v in exprs)))+')'
1393
    run_query(db, str_, recover=True, cacheable=True, log_level=3)
1394

    
1395
def add_pkey_index(db, table): add_index(db, pkey_col(db, table), table)
1396

    
1397
def add_pkey_or_index(db, table, cols=None, recover=None, warn=False):
1398
    try: add_pkey(db, table, cols, recover)
1399
    except DuplicateKeyException, e:
1400
        if warn: warnings.warn(UserWarning(exc.str_(e)))
1401
        add_pkey_index(db, table)
1402

    
1403
already_indexed = object() # tells add_indexes() the pkey has already been added
1404

    
1405
def add_indexes(db, table, has_pkey=True):
1406
    '''Adds an index on all columns in a table.
1407
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1408
        index should be added on the first column.
1409
        * If already_indexed, the pkey is assumed to have already been added
1410
    '''
1411
    cols = table_col_names(db, table)
1412
    if has_pkey:
1413
        if has_pkey is not already_indexed: add_pkey(db, table)
1414
        cols = cols[1:]
1415
    for col in cols: add_index(db, col, table)
1416

    
1417
#### Tables
1418

    
1419
### Maintenance
1420

    
1421
def analyze(db, table):
1422
    table = sql_gen.as_Table(table)
1423
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1424

    
1425
def autoanalyze(db, table):
1426
    if db.autoanalyze: analyze(db, table)
1427

    
1428
def vacuum(db, table):
1429
    table = sql_gen.as_Table(table)
1430
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1431
        log_level=3))
1432

    
1433
### Lifecycle
1434

    
1435
def drop(db, type_, name):
1436
    name = sql_gen.as_Name(name)
1437
    run_query(db, 'DROP '+type_+' IF EXISTS '+name.to_str(db)+' CASCADE')
1438

    
1439
def drop_table(db, table): drop(db, 'TABLE', table)
1440

    
1441
def create_table(db, table, cols=[], has_pkey=True, col_indexes=True,
1442
    like=None):
1443
    '''Creates a table.
1444
    @param cols [sql_gen.TypedCol,...] The column names and types
1445
    @param has_pkey If set, the first column becomes the primary key.
1446
    @param col_indexes bool|[ref]
1447
        * If True, indexes will be added on all non-pkey columns.
1448
        * If a list reference, [0] will be set to a function to do this.
1449
          This can be used to delay index creation until the table is populated.
1450
    '''
1451
    table = sql_gen.as_Table(table)
1452
    
1453
    if like != None:
1454
        cols = [sql_gen.CustomCode('LIKE '+like.to_str(db)+' INCLUDING ALL')
1455
            ]+cols
1456
        table.order_by = like.order_by
1457
    if has_pkey:
1458
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1459
        pkey.constraints = 'PRIMARY KEY'
1460
    
1461
    temp = table.is_temp and not db.debug_temp
1462
        # temp tables permanent in debug_temp mode
1463
    
1464
    # Create table
1465
    def create():
1466
        str_ = 'CREATE'
1467
        if temp: str_ += ' TEMP'
1468
        str_ += ' TABLE '+table.to_str(db)+' (\n'
1469
        str_ += '\n, '.join(c.to_str(db) for c in cols)
1470
        str_ += '\n);'
1471
        
1472
        run_query(db, str_, recover=True, cacheable=True, log_level=2,
1473
            log_ignore_excs=(DuplicateException,))
1474
    if table.is_temp:
1475
        while True:
1476
            try:
1477
                create()
1478
                break
1479
            except DuplicateException:
1480
                table.name = next_version(table.name)
1481
                # try again with next version of name
1482
    else: create()
1483
    
1484
    # Add indexes
1485
    if has_pkey: has_pkey = already_indexed
1486
    def add_indexes_(): add_indexes(db, table, has_pkey)
1487
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1488
    elif col_indexes: add_indexes_() # add now
1489

    
1490
def copy_table_struct(db, src, dest):
1491
    '''Creates a structure-only copy of a table. (Does not copy data.)'''
1492
    create_table(db, dest, has_pkey=False, col_indexes=False, like=src)
1493

    
1494
def copy_table(db, src, dest):
1495
    '''Creates a copy of a table, including data'''
1496
    copy_table_struct(db, src, dest)
1497
    insert_select(db, dest, None, mk_select(db, src))
1498

    
1499
### Data
1500

    
1501
def truncate(db, table, schema='public', **kw_args):
1502
    '''For params, see run_query()'''
1503
    table = sql_gen.as_Table(table, schema)
1504
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1505

    
1506
def empty_temp(db, tables):
1507
    tables = lists.mk_seq(tables)
1508
    for table in tables: truncate(db, table, log_level=3)
1509

    
1510
def empty_db(db, schema='public', **kw_args):
1511
    '''For kw_args, see tables()'''
1512
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1513

    
1514
def distinct_table(db, table, distinct_on):
1515
    '''Creates a copy of a temp table which is distinct on the given columns.
1516
    Adds an index on table's distinct_on columns, to facilitate merge joins.
1517
    @param distinct_on If empty, creates a table with one row. This is useful if
1518
        your distinct_on columns are all literal values.
1519
    @return The new table.
1520
    '''
1521
    new_table = sql_gen.suffixed_table(table, '_distinct')
1522
    distinct_on = filter(sql_gen.is_table_col, distinct_on)
1523
    
1524
    copy_table_struct(db, table, new_table)
1525
    
1526
    limit = None
1527
    if distinct_on == []: limit = 1 # one sample row
1528
    else: add_index(db, distinct_on, table) # for join optimization
1529
    
1530
    insert_select(db, new_table, None, mk_select(db, table,
1531
        distinct_on=distinct_on, order_by=None, limit=limit))
1532
    analyze(db, new_table)
1533
    
1534
    return new_table
(33-33/47)