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_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
    typed_name_re = r'^(\S+) "?(.+?)"?(?: of relation ".+?")?'
597
    
598
    match = re.match(typed_name_re+r'.*? already exists', msg)
599
    if match:
600
        type_, name = match.groups()
601
        raise DuplicateException(type_, name, e)
602
    
603
    match = re.match(r'more than one (\S+) named ""(.+?)""', msg)
604
    if match:
605
        type_, name = match.groups()
606
        raise DuplicateException(type_, name, e)
607
    
608
    match = re.match(typed_name_re+r' does not exist', msg)
609
    if match:
610
        type_, name = match.groups()
611
        if type_ == 'function':
612
            match = re.match(r'^(.+?)\(.*\)$', name)
613
            if match: # includes params, so is call rather than cast to regproc
614
                function_name, = match.groups()
615
                func = sql_gen.Function(function_name)
616
                if function_exists(db, func) and msg.find('CAST') < 0:
617
                    # not found only because of a missing cast
618
                    type_ = function_param0_type(db, func)
619
                    col = None
620
                    if type_ == 'anyelement': type_ = 'text'
621
                    elif type_ == 'hstore': # cast just the value param
622
                        type_ = 'text'
623
                        col = 'value'
624
                    raise MissingCastException(type_, col, e)
625
        raise DoesNotExistException(type_, name, e)
626
    
627
    raise # no specific exception raised
628

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

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

    
659
##### Basic queries
660

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

    
1091
##### Database structure introspection
1092

    
1093
#### Tables
1094

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

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

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

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

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

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

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

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

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

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

    
1180
not_null_col = 'not_null_col'
1181

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

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

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

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

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

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

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

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

    
1262
#### Functions
1263

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

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

    
1282
##### Structural changes
1283

    
1284
#### Columns
1285

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

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

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

    
1320
row_num_col = '_row_num'
1321

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

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

    
1332
#### Indexes
1333

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

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

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

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

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

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

    
1418
#### Tables
1419

    
1420
### Maintenance
1421

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

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

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

    
1434
### Lifecycle
1435

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

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

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

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

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

    
1500
### Data
1501

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

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

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

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