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: '+strings.as_tt(str(name)), cause)
41
        self.name = name
42

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

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

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

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

    
73
class NameException(DbException): pass
74

    
75
class DuplicateKeyException(ConstraintException): pass
76

    
77
class NullValueException(ConstraintException): pass
78

    
79
class CheckException(ConstraintException): pass
80

    
81
class InvalidValueException(ExceptionWithValue): pass
82

    
83
class DuplicateException(ExceptionWithNameType): pass
84

    
85
class DoesNotExistException(ExceptionWithNameType): pass
86

    
87
class EmptyRowException(DbException): pass
88

    
89
##### Warnings
90

    
91
class DbWarning(UserWarning): pass
92

    
93
##### Result retrieval
94

    
95
def col_names(cur): return (col[0] for col in cur.description)
96

    
97
def rows(cur): return iter(lambda: cur.fetchone(), None)
98

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

    
103
def next_row(cur): return rows(cur).next()
104

    
105
def row(cur):
106
    row_ = next_row(cur)
107
    consume_rows(cur)
108
    return row_
109

    
110
def next_value(cur): return next_row(cur)[0]
111

    
112
def value(cur): return row(cur)[0]
113

    
114
def values(cur): return iters.func_iter(lambda: next_value(cur))
115

    
116
def value_or_none(cur):
117
    try: return value(cur)
118
    except StopIteration: return None
119

    
120
##### Escaping
121

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

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

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

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

    
140
##### Database connections
141

    
142
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
143

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

    
149
DatabaseErrors_set = set([DbException])
150
DatabaseErrors = tuple(DatabaseErrors_set)
151

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

    
157
def db_config_str(db_config):
158
    return db_config['engine']+' database '+db_config['database']
159

    
160
log_debug_none = lambda msg, level=2: None
161

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

    
489
connect = DbConn
490

    
491
##### Recoverable querying
492

    
493
def with_savepoint(db, func): return db.with_savepoint(func)
494

    
495
def run_query(db, query, recover=None, cacheable=False, log_level=2,
496
    log_ignore_excs=None, **kw_args):
497
    '''For params, see DbConn.run_query()'''
498
    if recover == None: recover = False
499
    if log_ignore_excs == None: log_ignore_excs = ()
500
    log_ignore_excs = tuple(log_ignore_excs)
501
    debug_msg_ref = [None]
502
    
503
    query = with_explain_comment(db, query)
504
    
505
    try:
506
        try:
507
            def run(): return db.run_query(query, cacheable, log_level,
508
                debug_msg_ref, **kw_args)
509
            if recover and not db.is_cached(query):
510
                return with_savepoint(db, run)
511
            else: return run() # don't need savepoint if cached
512
        except Exception, e:
513
            msg = strings.ustr(e.args[0])
514
            msg = re.sub(r'^PL/Python: \w+: ', r'', msg)
515
            
516
            match = re.match(r'^duplicate key value violates unique constraint '
517
                r'"(.+?)"', msg)
518
            if match:
519
                constraint, = match.groups()
520
                cols = []
521
                if recover: # need auto-rollback to run index_cols()
522
                    try: cols = index_cols(db, constraint)
523
                    except NotImplementedError: pass
524
                raise DuplicateKeyException(constraint, None, cols, e)
525
            
526
            match = re.match(r'^null value in column "(.+?)" violates not-null'
527
                r' constraint', msg)
528
            if match:
529
                col, = match.groups()
530
                raise NullValueException('NOT NULL', None, [col], e)
531
            
532
            match = re.match(r'^new row for relation "(.+?)" violates check '
533
                r'constraint "(.+?)"', msg)
534
            if match:
535
                table, constraint = match.groups()
536
                constraint = sql_gen.Col(constraint, table)
537
                cond = None
538
                if recover: # need auto-rollback to run constraint_cond()
539
                    try: cond = constraint_cond(db, constraint)
540
                    except NotImplementedError: pass
541
                raise CheckException(constraint.to_str(db), cond, [], e)
542
            
543
            match = re.match(r'^(?:invalid input (?:syntax|value)\b.*?'
544
                r'|.+? out of range): "(.+?)"', msg)
545
            if match:
546
                value, = match.groups()
547
                raise InvalidValueException(strings.to_unicode(value), e)
548
            
549
            match = re.match(r'^column "(.+?)" is of type (.+?) but expression '
550
                r'is of type', msg)
551
            if match:
552
                col, type_ = match.groups()
553
                raise MissingCastException(type_, col, e)
554
            
555
            typed_name_re = r'^(\S+) "(.+?)"'
556
            
557
            match = re.match(typed_name_re+r'.*? already exists', msg)
558
            if match:
559
                type_, name = match.groups()
560
                raise DuplicateException(type_, name, e)
561
            
562
            match = re.match(typed_name_re+r' does not exist', msg)
563
            if match:
564
                type_, name = match.groups()
565
                raise DoesNotExistException(type_, name, e)
566
            
567
            raise # no specific exception raised
568
    except log_ignore_excs:
569
        log_level += 2
570
        raise
571
    finally:
572
        if debug_msg_ref[0] != None: db.log_debug(debug_msg_ref[0], log_level)
573

    
574
##### Basic queries
575

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

    
581
def explain(db, query, **kw_args):
582
    '''
583
    For params, see run_query().
584
    '''
585
    kw_args.setdefault('log_level', 4)
586
    
587
    return strings.join_lines(values(run_query(db, 'EXPLAIN '+query,
588
        recover=True, cacheable=True, **kw_args)))
589
        # not a higher log_level because it's useful to see what query is being
590
        # run before it's executed, which EXPLAIN effectively provides
591

    
592
def has_comment(query): return query.endswith('*/')
593

    
594
def with_explain_comment(db, query, **kw_args):
595
    if db.autoexplain and not has_comment(query) and is_explainable(query):
596
        query += '\n'+sql_gen.esc_comment(' EXPLAIN:\n'
597
            +explain(db, query, **kw_args))
598
    return query
599

    
600
def next_version(name):
601
    version = 1 # first existing name was version 0
602
    match = re.match(r'^(.*)#(\d+)$', name)
603
    if match:
604
        name, version = match.groups()
605
        version = int(version)+1
606
    return sql_gen.concat(name, '#'+str(version))
607

    
608
def lock_table(db, table, mode):
609
    table = sql_gen.as_Table(table)
610
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
611

    
612
def run_query_into(db, query, into=None, add_pkey_=False, **kw_args):
613
    '''Outputs a query to a temp table.
614
    For params, see run_query().
615
    '''
616
    if into == None: return run_query(db, query, **kw_args)
617
    
618
    assert isinstance(into, sql_gen.Table)
619
    
620
    into.is_temp = True
621
    # "temporary tables cannot specify a schema name", so remove schema
622
    into.schema = None
623
    
624
    kw_args['recover'] = True
625
    kw_args.setdefault('log_ignore_excs', (DuplicateException,))
626
    
627
    temp = not db.debug_temp # tables are permanent in debug_temp mode
628
    
629
    # Create table
630
    while True:
631
        create_query = 'CREATE'
632
        if temp: create_query += ' TEMP'
633
        create_query += ' TABLE '+into.to_str(db)+' AS\n'+query
634
        
635
        try:
636
            cur = run_query(db, create_query, **kw_args)
637
                # CREATE TABLE AS sets rowcount to # rows in query
638
            break
639
        except DuplicateException, e:
640
            into.name = next_version(into.name)
641
            # try again with next version of name
642
    
643
    if add_pkey_: add_pkey(db, into)
644
    
645
    # According to the PostgreSQL doc, "The autovacuum daemon cannot access and
646
    # therefore cannot vacuum or analyze temporary tables. [...] if a temporary
647
    # table is going to be used in complex queries, it is wise to run ANALYZE on
648
    # the temporary table after it is populated."
649
    # (http://www.postgresql.org/docs/9.1/static/sql-createtable.html)
650
    # If into is not a temp table, ANALYZE is useful but not required.
651
    analyze(db, into)
652
    
653
    return cur
654

    
655
order_by_pkey = object() # tells mk_select() to order by the pkey
656

    
657
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
658

    
659
def mk_select(db, tables=None, fields=None, conds=None, distinct_on=[],
660
    limit=None, start=None, order_by=order_by_pkey, default_table=None,
661
    explain=True):
662
    '''
663
    @param tables The single table to select from, or a list of tables to join
664
        together, with tables after the first being sql_gen.Join objects
665
    @param fields Use None to select all fields in the table
666
    @param conds WHERE conditions: [(compare_left_side, compare_right_side),...]
667
        * container can be any iterable type
668
        * compare_left_side: sql_gen.Code|str (for col name)
669
        * compare_right_side: sql_gen.ValueCond|literal value
670
    @param distinct_on The columns to SELECT DISTINCT ON, or distinct_on_all to
671
        use all columns
672
    @return query
673
    '''
674
    # Parse tables param
675
    tables = lists.mk_seq(tables)
676
    tables = list(tables) # don't modify input! (list() copies input)
677
    table0 = sql_gen.as_Table(tables.pop(0)) # first table is separate
678
    
679
    # Parse other params
680
    if conds == None: conds = []
681
    elif dicts.is_dict(conds): conds = conds.items()
682
    conds = list(conds) # don't modify input! (list() copies input)
683
    assert limit == None or isinstance(limit, (int, long))
684
    assert start == None or isinstance(start, (int, long))
685
    if order_by is order_by_pkey:
686
        if table0 == None or distinct_on != []: order_by = None
687
        else: order_by = pkey(db, table0, recover=True)
688
    
689
    query = 'SELECT'
690
    
691
    def parse_col(col): return sql_gen.as_Col(col, default_table).to_str(db)
692
    
693
    # DISTINCT ON columns
694
    if distinct_on != []:
695
        query += '\nDISTINCT'
696
        if distinct_on is not distinct_on_all:
697
            query += ' ON ('+(', '.join(map(parse_col, distinct_on)))+')'
698
    
699
    # Columns
700
    if query.find('\n') >= 0: whitespace = '\n'
701
    else: whitespace = ' '
702
    if fields == None: query += whitespace+'*'
703
    else:
704
        assert fields != []
705
        if len(fields) > 1: whitespace = '\n'
706
        query += whitespace+('\n, '.join(map(parse_col, fields)))
707
    
708
    # Main table
709
    if query.find('\n') >= 0 or len(tables) > 0: whitespace = '\n'
710
    else: whitespace = ' '
711
    if table0 != None: query += whitespace+'FROM '+table0.to_str(db)
712
    
713
    # Add joins
714
    left_table = table0
715
    for join_ in tables:
716
        table = join_.table
717
        
718
        # Parse special values
719
        if join_.type_ is sql_gen.filter_out: # filter no match
720
            conds.append((sql_gen.Col(table_not_null_col(db, table), table),
721
                sql_gen.CompareCond(None, '~=')))
722
        
723
        query += '\n'+join_.to_str(db, left_table)
724
        
725
        left_table = table
726
    
727
    missing = True
728
    if conds != []:
729
        if len(conds) == 1: whitespace = ' '
730
        else: whitespace = '\n'
731
        query += '\n'+sql_gen.combine_conds([sql_gen.ColValueCond(l, r)
732
            .to_str(db) for l, r in conds], 'WHERE')
733
    if order_by != None:
734
        query += '\nORDER BY '+sql_gen.as_Col(order_by, table0).to_str(db)
735
    if limit != None: query += '\nLIMIT '+str(limit)
736
    if start != None:
737
        if start != 0: query += '\nOFFSET '+str(start)
738
    
739
    if explain: query = with_explain_comment(db, query)
740
    
741
    return query
742

    
743
def select(db, *args, **kw_args):
744
    '''For params, see mk_select() and run_query()'''
745
    recover = kw_args.pop('recover', None)
746
    cacheable = kw_args.pop('cacheable', True)
747
    log_level = kw_args.pop('log_level', 2)
748
    
749
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
750
        log_level=log_level)
751

    
752
def mk_insert_select(db, table, cols=None, select_query=None, returning=None,
753
    embeddable=False, ignore=False, src=None):
754
    '''
755
    @param returning str|None An inserted column (such as pkey) to return
756
    @param embeddable Whether the query should be embeddable as a nested SELECT.
757
        Warning: If you set this and cacheable=True when the query is run, the
758
        query will be fully cached, not just if it raises an exception.
759
    @param ignore Whether to ignore duplicate keys.
760
    @param src Will be included in the name of any created function, to help
761
        identify the data source in pg_stat_activity.
762
    '''
763
    table = sql_gen.remove_table_rename(sql_gen.as_Table(table))
764
    if cols == []: cols = None # no cols (all defaults) = unknown col names
765
    if cols != None: cols = [sql_gen.to_name_only_col(c, table) for c in cols]
766
    if select_query == None: select_query = 'DEFAULT VALUES'
767
    if returning != None: returning = sql_gen.as_Col(returning, table)
768
    
769
    first_line = 'INSERT INTO '+table.to_str(db)
770
    
771
    def mk_insert(select_query):
772
        query = first_line
773
        if cols != None:
774
            query += '\n('+(', '.join((c.to_str(db) for c in cols)))+')'
775
        query += '\n'+select_query
776
        
777
        if returning != None:
778
            returning_name_col = sql_gen.to_name_only_col(returning)
779
            query += '\nRETURNING '+returning_name_col.to_str(db)
780
        
781
        return query
782
    
783
    return_type = sql_gen.CustomCode('unknown')
784
    if returning != None: return_type = sql_gen.ColType(returning)
785
    
786
    if ignore:
787
        # Always return something to set the correct rowcount
788
        if returning == None: returning = sql_gen.NamedCol('NULL', None)
789
        
790
        embeddable = True # must use function
791
        
792
        if cols == None: row = [sql_gen.Col(sql_gen.all_cols, 'row')]
793
        else: row = [sql_gen.Col(c.name, 'row') for c in cols]
794
        
795
        query = sql_gen.RowExcIgnore(sql_gen.RowType(table), select_query,
796
            sql_gen.ReturnQuery(mk_insert(sql_gen.Values(row).to_str(db))),
797
            cols)
798
    else: query = mk_insert(select_query)
799
    
800
    if embeddable:
801
        # Create function
802
        function_name = sql_gen.clean_name(first_line)
803
        if src != None: function_name = src+': '+function_name
804
        while True:
805
            try:
806
                func = db.TempFunction(function_name)
807
                def_ = sql_gen.FunctionDef(func, sql_gen.SetOf(return_type),
808
                    query)
809
                
810
                run_query(db, def_.to_str(db), recover=True, cacheable=True,
811
                    log_ignore_excs=(DuplicateException,))
812
                break # this version was successful
813
            except DuplicateException, e:
814
                function_name = next_version(function_name)
815
                # try again with next version of name
816
        
817
        # Return query that uses function
818
        cols = None
819
        if returning != None: cols = [returning]
820
        func_table = sql_gen.NamedTable('f', sql_gen.FunctionCall(func), cols)
821
            # AS clause requires function alias
822
        return mk_select(db, func_table, order_by=None)
823
    
824
    return query
825

    
826
def insert_select(db, table, *args, **kw_args):
827
    '''For params, see mk_insert_select() and run_query_into()
828
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
829
        values in
830
    '''
831
    returning = kw_args.get('returning', None)
832
    ignore = kw_args.get('ignore', False)
833
    
834
    into = kw_args.pop('into', None)
835
    if into != None: kw_args['embeddable'] = True
836
    recover = kw_args.pop('recover', None)
837
    if ignore: recover = True
838
    cacheable = kw_args.pop('cacheable', True)
839
    log_level = kw_args.pop('log_level', 2)
840
    
841
    rowcount_only = ignore and returning == None # keep NULL rows on server
842
    if rowcount_only: into = sql_gen.Table('rowcount')
843
    
844
    cur = run_query_into(db, mk_insert_select(db, table, *args, **kw_args),
845
        into, recover=recover, cacheable=cacheable, log_level=log_level)
846
    if rowcount_only: empty_temp(db, into)
847
    autoanalyze(db, table)
848
    return cur
849

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

    
852
def insert(db, table, row, *args, **kw_args):
853
    '''For params, see insert_select()'''
854
    if lists.is_seq(row): cols = None
855
    else:
856
        cols = row.keys()
857
        row = row.values()
858
    row = list(row) # ensure that "== []" works
859
    
860
    if row == []: query = None
861
    else: query = sql_gen.Values(row).to_str(db)
862
    
863
    return insert_select(db, table, cols, query, *args, **kw_args)
864

    
865
def mk_update(db, table, changes=None, cond=None, in_place=False,
866
    cacheable_=True):
867
    '''
868
    @param changes [(col, new_value),...]
869
        * container can be any iterable type
870
        * col: sql_gen.Code|str (for col name)
871
        * new_value: sql_gen.Code|literal value
872
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
873
    @param in_place If set, locks the table and updates rows in place.
874
        This avoids creating dead rows in PostgreSQL.
875
        * cond must be None
876
    @param cacheable_ Whether column structure information used to generate the
877
        query can be cached
878
    @return str query
879
    '''
880
    table = sql_gen.as_Table(table)
881
    changes = [(sql_gen.to_name_only_col(c, table), sql_gen.as_Value(v))
882
        for c, v in changes]
883
    
884
    if in_place:
885
        assert cond == None
886
        
887
        query = 'ALTER TABLE '+table.to_str(db)+'\n'
888
        query += ',\n'.join(('ALTER COLUMN '+c.to_str(db)+' TYPE '
889
            +db.col_info(sql_gen.with_default_table(c, table), cacheable_).type
890
            +'\nUSING '+v.to_str(db) for c, v in changes))
891
    else:
892
        query = 'UPDATE '+table.to_str(db)+'\nSET\n'
893
        query += ',\n'.join((c.to_str(db)+' = '+v.to_str(db)
894
            for c, v in changes))
895
        if cond != None: query += '\nWHERE\n'+cond.to_str(db)
896
    
897
    query = with_explain_comment(db, query)
898
    
899
    return query
900

    
901
def update(db, table, *args, **kw_args):
902
    '''For params, see mk_update() and run_query()'''
903
    recover = kw_args.pop('recover', None)
904
    cacheable = kw_args.pop('cacheable', False)
905
    log_level = kw_args.pop('log_level', 2)
906
    
907
    cur = run_query(db, mk_update(db, table, *args, **kw_args), recover,
908
        cacheable, log_level=log_level)
909
    autoanalyze(db, table)
910
    return cur
911

    
912
def mk_delete(db, table, cond=None):
913
    '''
914
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
915
    @return str query
916
    '''
917
    query = 'DELETE FROM '+table.to_str(db)
918
    if cond != None: query += '\nWHERE '+cond.to_str(db)
919
    
920
    query = with_explain_comment(db, query)
921
    
922
    return query
923

    
924
def delete(db, table, *args, **kw_args):
925
    '''For params, see mk_delete() and run_query()'''
926
    recover = kw_args.pop('recover', None)
927
    cacheable = kw_args.pop('cacheable', True)
928
    log_level = kw_args.pop('log_level', 2)
929
    
930
    cur = run_query(db, mk_delete(db, table, *args, **kw_args), recover,
931
        cacheable, log_level=log_level)
932
    autoanalyze(db, table)
933
    return cur
934

    
935
def last_insert_id(db):
936
    module = util.root_module(db.db)
937
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
938
    elif module == 'MySQLdb': return db.insert_id()
939
    else: return None
940

    
941
def define_func(db, def_):
942
    func = def_.function
943
    while True:
944
        try:
945
            run_query(db, def_.to_str(db), recover=True, cacheable=True,
946
                log_ignore_excs=(DuplicateException,))
947
            break # successful
948
        except DuplicateException:
949
            func.name = next_version(func.name)
950
            # try again with next version of name
951

    
952
def mk_flatten_mapping(db, into, cols, preserve=[], as_items=False):
953
    '''Creates a mapping from original column names (which may have collisions)
954
    to names that will be distinct among the columns' tables.
955
    This is meant to be used for several tables that are being joined together.
956
    @param cols The columns to combine. Duplicates will be removed.
957
    @param into The table for the new columns.
958
    @param preserve [sql_gen.Col...] Columns not to rename. Note that these
959
        columns will be included in the mapping even if they are not in cols.
960
        The tables of the provided Col objects will be changed to into, so make
961
        copies of them if you want to keep the original tables.
962
    @param as_items Whether to return a list of dict items instead of a dict
963
    @return dict(orig_col=new_col, ...)
964
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
965
        * new_col: sql_gen.Col(orig_col_name, into)
966
        * All mappings use the into table so its name can easily be
967
          changed for all columns at once
968
    '''
969
    cols = lists.uniqify(cols)
970
    
971
    items = []
972
    for col in preserve:
973
        orig_col = copy.copy(col)
974
        col.table = into
975
        items.append((orig_col, col))
976
    preserve = set(preserve)
977
    for col in cols:
978
        if col not in preserve:
979
            items.append((col, sql_gen.Col(str(col), into, col.srcs)))
980
    
981
    if not as_items: items = dict(items)
982
    return items
983

    
984
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
985
    '''For params, see mk_flatten_mapping()
986
    @return See return value of mk_flatten_mapping()
987
    '''
988
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
989
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
990
    run_query_into(db, mk_select(db, joins, cols, order_by=None, limit=limit,
991
        start=start), into=into, add_pkey_=True)
992
    return dict(items)
993

    
994
##### Database structure introspection
995

    
996
#### Expressions
997

    
998
bool_re = r'(?:true|false)'
999

    
1000
def simplify_expr(expr):
1001
    expr = expr.replace('(NULL IS NULL)', 'true')
1002
    expr = expr.replace('(NULL IS NOT NULL)', 'false')
1003
    expr = re.sub(r' OR '+bool_re, r'', expr)
1004
    expr = re.sub(bool_re+r' OR ', r'', expr)
1005
    while True:
1006
        expr, n = re.subn(r'\((\([^()]*\))\)', r'\1', expr)
1007
        if n == 0: break
1008
    return expr
1009

    
1010
name_re = r'(?:\w+|(?:"[^"]*")+)'
1011

    
1012
def parse_expr_col(str_):
1013
    match = re.match(r'^\('+name_re+r'\(('+name_re+r').*\)\)$', str_)
1014
    if match: str_ = match.group(1)
1015
    return sql_gen.unesc_name(str_)
1016

    
1017
def map_expr(db, expr, mapping, in_cols_found=None):
1018
    '''Replaces output columns with input columns in an expression.
1019
    @param in_cols_found If set, will be filled in with the expr's (input) cols
1020
    '''
1021
    for out, in_ in mapping.iteritems():
1022
        orig_expr = expr
1023
        out = sql_gen.to_name_only_col(out)
1024
        in_str = sql_gen.to_name_only_col(sql_gen.remove_col_rename(in_)
1025
            ).to_str(db)
1026
        
1027
        # Replace out both with and without quotes
1028
        expr = expr.replace(out.to_str(db), in_str)
1029
        expr = re.sub(r'\b'+out.name+r'\b', in_str, expr)
1030
        
1031
        if in_cols_found != None and expr != orig_expr: # replaced something
1032
            in_cols_found.append(in_)
1033
    
1034
    return simplify_expr(expr)
1035

    
1036
#### Tables
1037

    
1038
def tables(db, schema_like='public', table_like='%', exact=False):
1039
    if exact: compare = '='
1040
    else: compare = 'LIKE'
1041
    
1042
    module = util.root_module(db.db)
1043
    if module == 'psycopg2':
1044
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1045
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1046
        return values(select(db, 'pg_tables', ['tablename'], conds,
1047
            order_by='tablename', log_level=4))
1048
    elif module == 'MySQLdb':
1049
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1050
            , cacheable=True, log_level=4))
1051
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1052

    
1053
def table_exists(db, table):
1054
    table = sql_gen.as_Table(table)
1055
    return list(tables(db, table.schema, table.name, exact=True)) != []
1056

    
1057
def table_row_count(db, table, recover=None):
1058
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
1059
        order_by=None), recover=recover, log_level=3))
1060

    
1061
def table_cols(db, table, recover=None):
1062
    return list(col_names(select(db, table, limit=0, order_by=None,
1063
        recover=recover, log_level=4)))
1064

    
1065
def pkey(db, table, recover=None):
1066
    '''Assumed to be first column in table'''
1067
    return table_cols(db, table, recover)[0]
1068

    
1069
not_null_col = 'not_null_col'
1070

    
1071
def table_not_null_col(db, table, recover=None):
1072
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
1073
    if not_null_col in table_cols(db, table, recover): return not_null_col
1074
    else: return pkey(db, table, recover)
1075

    
1076
def constraint_cond(db, constraint):
1077
    module = util.root_module(db.db)
1078
    if module == 'psycopg2':
1079
        table_str = sql_gen.Literal(constraint.table.to_str(db))
1080
        name_str = sql_gen.Literal(constraint.name)
1081
        return value(run_query(db, '''\
1082
SELECT consrc
1083
FROM pg_constraint
1084
WHERE
1085
conrelid = '''+table_str.to_str(db)+'''::regclass
1086
AND conname = '''+name_str.to_str(db)+'''
1087
'''
1088
            , cacheable=True, log_level=4))
1089
    else: raise NotImplementedError("Can't list index columns for "+module+
1090
        ' database')
1091

    
1092
def index_cols(db, index):
1093
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
1094
    automatically created. When you don't know whether something is a UNIQUE
1095
    constraint or a UNIQUE index, use this function.'''
1096
    index = sql_gen.as_Table(index)
1097
    module = util.root_module(db.db)
1098
    if module == 'psycopg2':
1099
        qual_index = sql_gen.Literal(index.to_str(db))
1100
        return map(parse_expr_col, values(run_query(db, '''\
1101
SELECT pg_get_indexdef(indexrelid, generate_series(1, indnatts), true)
1102
FROM pg_index
1103
WHERE indexrelid = '''+qual_index.to_str(db)+'''::regclass
1104
'''
1105
            , cacheable=True, log_level=4)))
1106
    else: raise NotImplementedError("Can't list index columns for "+module+
1107
        ' database')
1108

    
1109
#### Functions
1110

    
1111
def function_exists(db, function):
1112
    qual_function = sql_gen.Literal(function.to_str(db))
1113
    try:
1114
        select(db, fields=[sql_gen.Cast('regproc', qual_function)],
1115
            recover=True, cacheable=True, log_level=4)
1116
    except DoesNotExistException: return False
1117
    else: return True
1118

    
1119
##### Structural changes
1120

    
1121
#### Columns
1122

    
1123
def add_col(db, table, col, comment=None, **kw_args):
1124
    '''
1125
    @param col TypedCol Name may be versioned, so be sure to propagate any
1126
        renaming back to any source column for the TypedCol.
1127
    @param comment None|str SQL comment used to distinguish columns of the same
1128
        name from each other when they contain different data, to allow the
1129
        ADD COLUMN query to be cached. If not set, query will not be cached.
1130
    '''
1131
    assert isinstance(col, sql_gen.TypedCol)
1132
    
1133
    while True:
1134
        str_ = 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '+col.to_str(db)
1135
        if comment != None: str_ += ' '+sql_gen.esc_comment(comment)
1136
        
1137
        try:
1138
            run_query(db, str_, recover=True, cacheable=True, **kw_args)
1139
            break
1140
        except DuplicateException:
1141
            col.name = next_version(col.name)
1142
            # try again with next version of name
1143

    
1144
def add_not_null(db, col):
1145
    table = col.table
1146
    col = sql_gen.to_name_only_col(col)
1147
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1148
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1149

    
1150
row_num_col = '_row_num'
1151

    
1152
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1153
    constraints='PRIMARY KEY')
1154

    
1155
def add_row_num(db, table):
1156
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1157
    be the primary key.'''
1158
    add_col(db, table, row_num_typed_col, log_level=3)
1159

    
1160
#### Indexes
1161

    
1162
def add_pkey(db, table, cols=None, recover=None):
1163
    '''Adds a primary key.
1164
    @param cols [sql_gen.Col,...] The columns in the primary key.
1165
        Defaults to the first column in the table.
1166
    @pre The table must not already have a primary key.
1167
    '''
1168
    table = sql_gen.as_Table(table)
1169
    if cols == None: cols = [pkey(db, table, recover)]
1170
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1171
    
1172
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1173
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1174
        log_ignore_excs=(DuplicateException,))
1175

    
1176
def add_index(db, exprs, table=None, unique=False, ensure_not_null_=True):
1177
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
1178
    Currently, only function calls and literal values are supported expressions.
1179
    @param ensure_not_null_ If set, translates NULL values to sentinel values.
1180
        This allows indexes to be used for comparisons where NULLs are equal.
1181
    '''
1182
    exprs = lists.mk_seq(exprs)
1183
    
1184
    # Parse exprs
1185
    old_exprs = exprs[:]
1186
    exprs = []
1187
    cols = []
1188
    for i, expr in enumerate(old_exprs):
1189
        expr = sql_gen.as_Col(expr, table)
1190
        
1191
        # Handle nullable columns
1192
        if ensure_not_null_:
1193
            try: expr = sql_gen.ensure_not_null(db, expr)
1194
            except KeyError: pass # unknown type, so just create plain index
1195
        
1196
        # Extract col
1197
        expr = copy.deepcopy(expr) # don't modify input!
1198
        col = expr
1199
        if isinstance(expr, sql_gen.FunctionCall): col = expr.args[0]
1200
        expr = sql_gen.cast_literal(expr)
1201
        if not isinstance(expr, (sql_gen.Expr, sql_gen.Col)):
1202
            expr = sql_gen.Expr(expr)
1203
            
1204
        
1205
        # Extract table
1206
        if table == None:
1207
            assert sql_gen.is_table_col(col)
1208
            table = col.table
1209
        
1210
        if isinstance(col, sql_gen.Col): col.table = None
1211
        
1212
        exprs.append(expr)
1213
        cols.append(col)
1214
    
1215
    table = sql_gen.as_Table(table)
1216
    
1217
    # Add index
1218
    str_ = 'CREATE'
1219
    if unique: str_ += ' UNIQUE'
1220
    str_ += ' INDEX ON '+table.to_str(db)+' ('+(
1221
        ', '.join((v.to_str(db) for v in exprs)))+')'
1222
    run_query(db, str_, recover=True, cacheable=True, log_level=3)
1223

    
1224
already_indexed = object() # tells add_indexes() the pkey has already been added
1225

    
1226
def add_indexes(db, table, has_pkey=True):
1227
    '''Adds an index on all columns in a table.
1228
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1229
        index should be added on the first column.
1230
        * If already_indexed, the pkey is assumed to have already been added
1231
    '''
1232
    cols = table_cols(db, table)
1233
    if has_pkey:
1234
        if has_pkey is not already_indexed: add_pkey(db, table)
1235
        cols = cols[1:]
1236
    for col in cols: add_index(db, col, table)
1237

    
1238
#### Tables
1239

    
1240
### Maintenance
1241

    
1242
def analyze(db, table):
1243
    table = sql_gen.as_Table(table)
1244
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1245

    
1246
def autoanalyze(db, table):
1247
    if db.autoanalyze: analyze(db, table)
1248

    
1249
def vacuum(db, table):
1250
    table = sql_gen.as_Table(table)
1251
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1252
        log_level=3))
1253

    
1254
### Lifecycle
1255

    
1256
def drop(db, type_, name):
1257
    name = sql_gen.as_Name(name)
1258
    run_query(db, 'DROP '+type_+' IF EXISTS '+name.to_str(db)+' CASCADE')
1259

    
1260
def drop_table(db, table): drop(db, 'TABLE', table)
1261

    
1262
def create_table(db, table, cols=[], has_pkey=True, col_indexes=True,
1263
    like=None):
1264
    '''Creates a table.
1265
    @param cols [sql_gen.TypedCol,...] The column names and types
1266
    @param has_pkey If set, the first column becomes the primary key.
1267
    @param col_indexes bool|[ref]
1268
        * If True, indexes will be added on all non-pkey columns.
1269
        * If a list reference, [0] will be set to a function to do this.
1270
          This can be used to delay index creation until the table is populated.
1271
    '''
1272
    table = sql_gen.as_Table(table)
1273
    
1274
    if like != None:
1275
        cols = [sql_gen.CustomCode('LIKE '+like.to_str(db)+' INCLUDING ALL')
1276
            ]+cols
1277
    if has_pkey:
1278
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1279
        pkey.constraints = 'PRIMARY KEY'
1280
    
1281
    temp = table.is_temp and not db.debug_temp
1282
        # temp tables permanent in debug_temp mode
1283
    
1284
    # Create table
1285
    def create():
1286
        str_ = 'CREATE'
1287
        if temp: str_ += ' TEMP'
1288
        str_ += ' TABLE '+table.to_str(db)+' (\n'
1289
        str_ += '\n, '.join(c.to_str(db) for c in cols)
1290
        str_ += '\n);'
1291
        
1292
        run_query(db, str_, recover=True, cacheable=True, log_level=2,
1293
            log_ignore_excs=(DuplicateException,))
1294
    if table.is_temp:
1295
        while True:
1296
            try:
1297
                create()
1298
                break
1299
            except DuplicateException:
1300
                table.name = next_version(table.name)
1301
                # try again with next version of name
1302
    else: create()
1303
    
1304
    # Add indexes
1305
    if has_pkey: has_pkey = already_indexed
1306
    def add_indexes_(): add_indexes(db, table, has_pkey)
1307
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1308
    elif col_indexes: add_indexes_() # add now
1309

    
1310
def copy_table_struct(db, src, dest):
1311
    '''Creates a structure-only copy of a table. (Does not copy data.)'''
1312
    create_table(db, dest, has_pkey=False, col_indexes=False, like=src)
1313

    
1314
### Data
1315

    
1316
def truncate(db, table, schema='public', **kw_args):
1317
    '''For params, see run_query()'''
1318
    table = sql_gen.as_Table(table, schema)
1319
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1320

    
1321
def empty_temp(db, tables):
1322
    tables = lists.mk_seq(tables)
1323
    for table in tables: truncate(db, table, log_level=3)
1324

    
1325
def empty_db(db, schema='public', **kw_args):
1326
    '''For kw_args, see tables()'''
1327
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1328

    
1329
def distinct_table(db, table, distinct_on):
1330
    '''Creates a copy of a temp table which is distinct on the given columns.
1331
    The old and new tables will both get an index on these columns, to
1332
    facilitate merge joins.
1333
    @param distinct_on If empty, creates a table with one row. This is useful if
1334
        your distinct_on columns are all literal values.
1335
    @return The new table.
1336
    '''
1337
    new_table = sql_gen.suffixed_table(table, '_distinct')
1338
    distinct_on = filter(sql_gen.is_table_col, distinct_on)
1339
    
1340
    copy_table_struct(db, table, new_table)
1341
    
1342
    limit = None
1343
    if distinct_on == []: limit = 1 # one sample row
1344
    else:
1345
        add_index(db, distinct_on, new_table, unique=True)
1346
        add_index(db, distinct_on, table) # for join optimization
1347
    
1348
    insert_select(db, new_table, None, mk_select(db, table, order_by=None,
1349
        limit=limit), ignore=True)
1350
    analyze(db, new_table)
1351
    
1352
    return new_table
(24-24/37)