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, cols, cause=None):
58
        DbException.__init__(self, 'Violated '+strings.as_tt(name)
59
            +' constraint on columns: '+strings.as_tt(', '.join(cols)), cause)
60
        self.name = name
61
        self.cols = cols
62

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

    
70
class NameException(DbException): pass
71

    
72
class DuplicateKeyException(ConstraintException): pass
73

    
74
class NullValueException(ConstraintException): pass
75

    
76
class InvalidValueException(ExceptionWithValue): pass
77

    
78
class DuplicateException(ExceptionWithNameType): pass
79

    
80
class EmptyRowException(DbException): pass
81

    
82
##### Warnings
83

    
84
class DbWarning(UserWarning): pass
85

    
86
##### Result retrieval
87

    
88
def col_names(cur): return (col[0] for col in cur.description)
89

    
90
def rows(cur): return iter(lambda: cur.fetchone(), None)
91

    
92
def consume_rows(cur):
93
    '''Used to fetch all rows so result will be cached'''
94
    iters.consume_iter(rows(cur))
95

    
96
def next_row(cur): return rows(cur).next()
97

    
98
def row(cur):
99
    row_ = next_row(cur)
100
    consume_rows(cur)
101
    return row_
102

    
103
def next_value(cur): return next_row(cur)[0]
104

    
105
def value(cur): return row(cur)[0]
106

    
107
def values(cur): return iters.func_iter(lambda: next_value(cur))
108

    
109
def value_or_none(cur):
110
    try: return value(cur)
111
    except StopIteration: return None
112

    
113
##### Escaping
114

    
115
def esc_name_by_module(module, name):
116
    if module == 'psycopg2' or module == None: quote = '"'
117
    elif module == 'MySQLdb': quote = '`'
118
    else: raise NotImplementedError("Can't escape name for "+module+' database')
119
    return sql_gen.esc_name(name, quote)
120

    
121
def esc_name_by_engine(engine, name, **kw_args):
122
    return esc_name_by_module(db_engines[engine][0], name, **kw_args)
123

    
124
def esc_name(db, name, **kw_args):
125
    return esc_name_by_module(util.root_module(db.db), name, **kw_args)
126

    
127
def qual_name(db, schema, table):
128
    def esc_name_(name): return esc_name(db, name)
129
    table = esc_name_(table)
130
    if schema != None: return esc_name_(schema)+'.'+table
131
    else: return table
132

    
133
##### Database connections
134

    
135
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
136

    
137
db_engines = {
138
    'MySQL': ('MySQLdb', {'password': 'passwd', 'database': 'db'}),
139
    'PostgreSQL': ('psycopg2', {}),
140
}
141

    
142
DatabaseErrors_set = set([DbException])
143
DatabaseErrors = tuple(DatabaseErrors_set)
144

    
145
def _add_module(module):
146
    DatabaseErrors_set.add(module.DatabaseError)
147
    global DatabaseErrors
148
    DatabaseErrors = tuple(DatabaseErrors_set)
149

    
150
def db_config_str(db_config):
151
    return db_config['engine']+' database '+db_config['database']
152

    
153
log_debug_none = lambda msg, level=2: None
154

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

    
473
connect = DbConn
474

    
475
##### Recoverable querying
476

    
477
def with_savepoint(db, func): return db.with_savepoint(func)
478

    
479
def run_query(db, query, recover=None, cacheable=False, log_level=2,
480
    log_ignore_excs=None, **kw_args):
481
    '''For params, see DbConn.run_query()'''
482
    if recover == None: recover = False
483
    if log_ignore_excs == None: log_ignore_excs = ()
484
    log_ignore_excs = tuple(log_ignore_excs)
485
    debug_msg_ref = [None]
486
    
487
    query = with_explain_comment(db, query, log_level=log_level+1)
488
    
489
    try:
490
        try:
491
            def run(): return db.run_query(query, cacheable, log_level,
492
                debug_msg_ref, **kw_args)
493
            if recover and not db.is_cached(query):
494
                return with_savepoint(db, run)
495
            else: return run() # don't need savepoint if cached
496
        except Exception, e:
497
            msg = strings.ustr(e.args[0])
498
            
499
            match = re.match(r'^duplicate key value violates unique constraint '
500
                r'"((_?[^\W_]+(?=[._]))?.+?)"', msg)
501
            if match:
502
                constraint, table = match.groups()
503
                cols = []
504
                if recover: # need auto-rollback to run index_cols()
505
                    try: cols = index_cols(db, table, constraint)
506
                    except NotImplementedError: pass
507
                raise DuplicateKeyException(constraint, cols, e)
508
            
509
            match = re.match(r'^null value in column "(.+?)" violates not-null'
510
                r' constraint', msg)
511
            if match: raise NullValueException('NOT NULL', [match.group(1)], e)
512
            
513
            match = re.match(r'^(?:invalid input (?:syntax|value)\b.*?'
514
                r'|.+? field value out of range): "(.+?)"', msg)
515
            if match:
516
                value, = match.groups()
517
                raise InvalidValueException(strings.to_unicode(value), e)
518
            
519
            match = re.match(r'^column "(.+?)" is of type (.+?) but expression '
520
                r'is of type', msg)
521
            if match:
522
                col, type_ = match.groups()
523
                raise MissingCastException(type_, col, e)
524
            
525
            match = re.match(r'^(\S+) "(.+?)".*? already exists', msg)
526
            if match:
527
                type_, name = match.groups()
528
                raise DuplicateException(type_, name, e)
529
            
530
            raise # no specific exception raised
531
    except log_ignore_excs:
532
        log_level += 2
533
        raise
534
    finally:
535
        if debug_msg_ref[0] != None: db.log_debug(debug_msg_ref[0], log_level)
536

    
537
##### Basic queries
538

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

    
544
def explain(db, query, **kw_args):
545
    '''
546
    For params, see run_query().
547
    '''
548
    kw_args.setdefault('log_level', 3)
549
    
550
    return strings.join_lines(values(run_query(db, 'EXPLAIN '+query,
551
        recover=True, cacheable=True, **kw_args)))
552
        # not a higher log_level because it's useful to see what query is being
553
        # run before it's executed, which EXPLAIN effectively provides
554

    
555
def has_comment(query): return query.endswith('*/')
556

    
557
def with_explain_comment(db, query, **kw_args):
558
    if db.debug and not has_comment(query) and is_explainable(query):
559
        query += '\n'+sql_gen.esc_comment(' EXPLAIN:\n'
560
            +explain(db, query, **kw_args))
561
    return query
562

    
563
def next_version(name):
564
    version = 1 # first existing name was version 0
565
    match = re.match(r'^(.*)#(\d+)$', name)
566
    if match:
567
        name, version = match.groups()
568
        version = int(version)+1
569
    return sql_gen.concat(name, '#'+str(version))
570

    
571
def lock_table(db, table, mode):
572
    table = sql_gen.as_Table(table)
573
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
574

    
575
def run_query_into(db, query, into=None, add_indexes_=False, **kw_args):
576
    '''Outputs a query to a temp table.
577
    For params, see run_query().
578
    '''
579
    if into == None: return run_query(db, query, **kw_args)
580
    
581
    assert isinstance(into, sql_gen.Table)
582
    
583
    into.is_temp = True
584
    # "temporary tables cannot specify a schema name", so remove schema
585
    into.schema = None
586
    
587
    kw_args['recover'] = True
588
    kw_args.setdefault('log_ignore_excs', (DuplicateException,))
589
    
590
    temp = not db.debug_temp # tables are permanent in debug_temp mode
591
    
592
    # Create table
593
    while True:
594
        create_query = 'CREATE'
595
        if temp: create_query += ' TEMP'
596
        create_query += ' TABLE '+into.to_str(db)+' AS\n'+query
597
        
598
        try:
599
            cur = run_query(db, create_query, **kw_args)
600
                # CREATE TABLE AS sets rowcount to # rows in query
601
            break
602
        except DuplicateException, e:
603
            into.name = next_version(into.name)
604
            # try again with next version of name
605
    
606
    if add_indexes_: add_indexes(db, into)
607
    
608
    # According to the PostgreSQL doc, "The autovacuum daemon cannot access and
609
    # therefore cannot vacuum or analyze temporary tables. [...] if a temporary
610
    # table is going to be used in complex queries, it is wise to run ANALYZE on
611
    # the temporary table after it is populated."
612
    # (http://www.postgresql.org/docs/9.1/static/sql-createtable.html)
613
    # If into is not a temp table, ANALYZE is useful but not required.
614
    analyze(db, into)
615
    
616
    return cur
617

    
618
order_by_pkey = object() # tells mk_select() to order by the pkey
619

    
620
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
621

    
622
def mk_select(db, tables, fields=None, conds=None, distinct_on=[], limit=None,
623
    start=None, order_by=order_by_pkey, default_table=None):
624
    '''
625
    @param tables The single table to select from, or a list of tables to join
626
        together, with tables after the first being sql_gen.Join objects
627
    @param fields Use None to select all fields in the table
628
    @param conds WHERE conditions: [(compare_left_side, compare_right_side),...]
629
        * container can be any iterable type
630
        * compare_left_side: sql_gen.Code|str (for col name)
631
        * compare_right_side: sql_gen.ValueCond|literal value
632
    @param distinct_on The columns to SELECT DISTINCT ON, or distinct_on_all to
633
        use all columns
634
    @return query
635
    '''
636
    # Parse tables param
637
    tables = lists.mk_seq(tables)
638
    tables = list(tables) # don't modify input! (list() copies input)
639
    table0 = sql_gen.as_Table(tables.pop(0)) # first table is separate
640
    
641
    # Parse other params
642
    if conds == None: conds = []
643
    elif dicts.is_dict(conds): conds = conds.items()
644
    conds = list(conds) # don't modify input! (list() copies input)
645
    assert limit == None or isinstance(limit, (int, long))
646
    assert start == None or isinstance(start, (int, long))
647
    if order_by is order_by_pkey:
648
        if distinct_on != []: order_by = None
649
        else: order_by = pkey(db, table0, recover=True)
650
    
651
    query = 'SELECT'
652
    
653
    def parse_col(col): return sql_gen.as_Col(col, default_table).to_str(db)
654
    
655
    # DISTINCT ON columns
656
    if distinct_on != []:
657
        query += '\nDISTINCT'
658
        if distinct_on is not distinct_on_all:
659
            query += ' ON ('+(', '.join(map(parse_col, distinct_on)))+')'
660
    
661
    # Columns
662
    if query.find('\n') >= 0: whitespace = '\n'
663
    else: whitespace = ' '
664
    if fields == None: query += whitespace+'*'
665
    else:
666
        assert fields != []
667
        if len(fields) > 1: whitespace = '\n'
668
        query += whitespace+('\n, '.join(map(parse_col, fields)))
669
    
670
    # Main table
671
    if query.find('\n') >= 0 or len(tables) > 0: whitespace = '\n'
672
    else: whitespace = ' '
673
    query += whitespace+'FROM '+table0.to_str(db)
674
    
675
    # Add joins
676
    left_table = table0
677
    for join_ in tables:
678
        table = join_.table
679
        
680
        # Parse special values
681
        if join_.type_ is sql_gen.filter_out: # filter no match
682
            conds.append((sql_gen.Col(table_not_null_col(db, table), table),
683
                sql_gen.CompareCond(None, '~=')))
684
        
685
        query += '\n'+join_.to_str(db, left_table)
686
        
687
        left_table = table
688
    
689
    missing = True
690
    if conds != []:
691
        if len(conds) == 1: whitespace = ' '
692
        else: whitespace = '\n'
693
        query += '\n'+sql_gen.combine_conds([sql_gen.ColValueCond(l, r)
694
            .to_str(db) for l, r in conds], 'WHERE')
695
        missing = False
696
    if order_by != None:
697
        query += '\nORDER BY '+sql_gen.as_Col(order_by, table0).to_str(db)
698
    if limit != None: query += '\nLIMIT '+str(limit); missing = False
699
    if start != None:
700
        if start != 0: query += '\nOFFSET '+str(start)
701
        missing = False
702
    if missing: warnings.warn(DbWarning(
703
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
704
    
705
    return query
706

    
707
def select(db, *args, **kw_args):
708
    '''For params, see mk_select() and run_query()'''
709
    recover = kw_args.pop('recover', None)
710
    cacheable = kw_args.pop('cacheable', True)
711
    log_level = kw_args.pop('log_level', 2)
712
    
713
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
714
        log_level=log_level)
715

    
716
def mk_insert_select(db, table, cols=None, select_query=None, returning=None,
717
    embeddable=False, ignore=False, src=None):
718
    '''
719
    @param returning str|None An inserted column (such as pkey) to return
720
    @param embeddable Whether the query should be embeddable as a nested SELECT.
721
        Warning: If you set this and cacheable=True when the query is run, the
722
        query will be fully cached, not just if it raises an exception.
723
    @param ignore Whether to ignore duplicate keys.
724
    @param src Will be included in the name of any created function, to help
725
        identify the data source in pg_stat_activity.
726
    '''
727
    table = sql_gen.remove_table_rename(sql_gen.as_Table(table))
728
    if cols == []: cols = None # no cols (all defaults) = unknown col names
729
    if cols != None: cols = [sql_gen.to_name_only_col(c, table) for c in cols]
730
    if select_query == None: select_query = 'DEFAULT VALUES'
731
    if returning != None: returning = sql_gen.as_Col(returning, table)
732
    
733
    first_line = 'INSERT INTO '+table.to_str(db)
734
    
735
    def mk_insert(select_query):
736
        query = first_line
737
        if cols != None:
738
            query += '\n('+(', '.join((c.to_str(db) for c in cols)))+')'
739
        query += '\n'+select_query
740
        
741
        if returning != None:
742
            returning_name_col = sql_gen.to_name_only_col(returning)
743
            query += '\nRETURNING '+returning_name_col.to_str(db)
744
        
745
        return query
746
    
747
    return_type = 'unknown'
748
    if returning != None: return_type = returning.to_str(db)+'%TYPE'
749
    
750
    lang = 'sql'
751
    if ignore:
752
        # Always return something to set the correct rowcount
753
        if returning == None: returning = sql_gen.NamedCol('NULL', None)
754
        
755
        embeddable = True # must use function
756
        lang = 'plpgsql'
757
        
758
        if cols == None:
759
            row = [sql_gen.Col(sql_gen.all_cols, 'row')]
760
            row_vars = [sql_gen.Table('row')]
761
        else:
762
            row_vars = row = [sql_gen.Col(c.name, 'row') for c in cols]
763
        
764
        query = '''\
765
DECLARE
766
    row '''+table.to_str(db)+'''%ROWTYPE;
767
BEGIN
768
    /* Need an EXCEPTION block for each individual row because "When an error is
769
    caught by an EXCEPTION clause, [...] all changes to persistent database
770
    state within the block are rolled back."
771
    This is unfortunate because "A block containing an EXCEPTION clause is
772
    significantly more expensive to enter and exit than a block without one."
773
    (http://www.postgresql.org/docs/8.3/static/plpgsql-control-structures.html\
774
#PLPGSQL-ERROR-TRAPPING)
775
    */
776
    FOR '''+(', '.join((v.to_str(db) for v in row_vars)))+''' IN
777
'''+select_query+'''
778
    LOOP
779
        BEGIN
780
            RETURN QUERY
781
'''+mk_insert(sql_gen.Values(row).to_str(db))+'''
782
;
783
        EXCEPTION
784
            WHEN unique_violation THEN NULL; -- continue to next row
785
        END;
786
    END LOOP;
787
END;\
788
'''
789
    else: query = mk_insert(select_query)
790
    
791
    if embeddable:
792
        # Create function
793
        function_name = sql_gen.clean_name(first_line)
794
        if src != None: function_name = src+': '+function_name
795
        while True:
796
            try:
797
                function = db.TempFunction(function_name)
798
                
799
                function_query = '''\
800
CREATE FUNCTION '''+function.to_str(db)+'''()
801
RETURNS SETOF '''+return_type+'''
802
LANGUAGE '''+lang+'''
803
AS $$
804
'''+query+'''
805
$$;
806
'''
807
                run_query(db, function_query, recover=True, cacheable=True,
808
                    log_ignore_excs=(DuplicateException,))
809
                break # this version was successful
810
            except DuplicateException, e:
811
                function_name = next_version(function_name)
812
                # try again with next version of name
813
        
814
        # Return query that uses function
815
        cols = None
816
        if returning != None: cols = [returning]
817
        func_table = sql_gen.NamedTable('f', sql_gen.FunctionCall(function),
818
            cols) # AS clause requires function alias
819
        return mk_select(db, func_table, start=0, order_by=None)
820
    
821
    return query
822

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

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

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

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

    
896
def update(db, table, *args, **kw_args):
897
    '''For params, see mk_update() and run_query()'''
898
    recover = kw_args.pop('recover', None)
899
    cacheable = kw_args.pop('cacheable', False)
900
    log_level = kw_args.pop('log_level', 2)
901
    
902
    cur = run_query(db, mk_update(db, table, *args, **kw_args), recover,
903
        cacheable, log_level=log_level)
904
    autoanalyze(db, table)
905
    return cur
906

    
907
def last_insert_id(db):
908
    module = util.root_module(db.db)
909
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
910
    elif module == 'MySQLdb': return db.insert_id()
911
    else: return None
912

    
913
def mk_flatten_mapping(db, into, cols, preserve=[], as_items=False):
914
    '''Creates a mapping from original column names (which may have collisions)
915
    to names that will be distinct among the columns' tables.
916
    This is meant to be used for several tables that are being joined together.
917
    @param cols The columns to combine. Duplicates will be removed.
918
    @param into The table for the new columns.
919
    @param preserve [sql_gen.Col...] Columns not to rename. Note that these
920
        columns will be included in the mapping even if they are not in cols.
921
        The tables of the provided Col objects will be changed to into, so make
922
        copies of them if you want to keep the original tables.
923
    @param as_items Whether to return a list of dict items instead of a dict
924
    @return dict(orig_col=new_col, ...)
925
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
926
        * new_col: sql_gen.Col(orig_col_name, into)
927
        * All mappings use the into table so its name can easily be
928
          changed for all columns at once
929
    '''
930
    cols = lists.uniqify(cols)
931
    
932
    items = []
933
    for col in preserve:
934
        orig_col = copy.copy(col)
935
        col.table = into
936
        items.append((orig_col, col))
937
    preserve = set(preserve)
938
    for col in cols:
939
        if col not in preserve:
940
            items.append((col, sql_gen.Col(str(col), into, col.srcs)))
941
    
942
    if not as_items: items = dict(items)
943
    return items
944

    
945
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
946
    '''For params, see mk_flatten_mapping()
947
    @return See return value of mk_flatten_mapping()
948
    '''
949
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
950
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
951
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
952
        into=into)
953
    return dict(items)
954

    
955
##### Database structure introspection
956

    
957
#### Tables
958

    
959
def tables(db, schema_like='public', table_like='%', exact=False):
960
    if exact: compare = '='
961
    else: compare = 'LIKE'
962
    
963
    module = util.root_module(db.db)
964
    if module == 'psycopg2':
965
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
966
            ('tablename', sql_gen.CompareCond(table_like, compare))]
967
        return values(select(db, 'pg_tables', ['tablename'], conds,
968
            order_by='tablename', log_level=4))
969
    elif module == 'MySQLdb':
970
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
971
            , cacheable=True, log_level=4))
972
    else: raise NotImplementedError("Can't list tables for "+module+' database')
973

    
974
def table_exists(db, table):
975
    table = sql_gen.as_Table(table)
976
    return list(tables(db, table.schema, table.name, exact=True)) != []
977

    
978
def table_row_count(db, table, recover=None):
979
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
980
        order_by=None, start=0), recover=recover, log_level=3))
981

    
982
def table_cols(db, table, recover=None):
983
    return list(col_names(select(db, table, limit=0, order_by=None,
984
        recover=recover, log_level=4)))
985

    
986
def pkey(db, table, recover=None):
987
    '''Assumed to be first column in table'''
988
    return table_cols(db, table, recover)[0]
989

    
990
not_null_col = 'not_null_col'
991

    
992
def table_not_null_col(db, table, recover=None):
993
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
994
    if not_null_col in table_cols(db, table, recover): return not_null_col
995
    else: return pkey(db, table, recover)
996

    
997
def index_cols(db, table, index):
998
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
999
    automatically created. When you don't know whether something is a UNIQUE
1000
    constraint or a UNIQUE index, use this function.'''
1001
    module = util.root_module(db.db)
1002
    if module == 'psycopg2':
1003
        return list(values(run_query(db, '''\
1004
SELECT attname
1005
FROM
1006
(
1007
        SELECT attnum, attname
1008
        FROM pg_index
1009
        JOIN pg_class index ON index.oid = indexrelid
1010
        JOIN pg_class table_ ON table_.oid = indrelid
1011
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
1012
        WHERE
1013
            table_.relname = '''+db.esc_value(table)+'''
1014
            AND index.relname = '''+db.esc_value(index)+'''
1015
    UNION
1016
        SELECT attnum, attname
1017
        FROM
1018
        (
1019
            SELECT
1020
                indrelid
1021
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
1022
                    AS indkey
1023
            FROM pg_index
1024
            JOIN pg_class index ON index.oid = indexrelid
1025
            JOIN pg_class table_ ON table_.oid = indrelid
1026
            WHERE
1027
                table_.relname = '''+db.esc_value(table)+'''
1028
                AND index.relname = '''+db.esc_value(index)+'''
1029
        ) s
1030
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
1031
) s
1032
ORDER BY attnum
1033
'''
1034
            , cacheable=True, log_level=4)))
1035
    else: raise NotImplementedError("Can't list index columns for "+module+
1036
        ' database')
1037

    
1038
def constraint_cols(db, table, constraint):
1039
    module = util.root_module(db.db)
1040
    if module == 'psycopg2':
1041
        return list(values(run_query(db, '''\
1042
SELECT attname
1043
FROM pg_constraint
1044
JOIN pg_class ON pg_class.oid = conrelid
1045
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
1046
WHERE
1047
    relname = '''+db.esc_value(table)+'''
1048
    AND conname = '''+db.esc_value(constraint)+'''
1049
ORDER BY attnum
1050
'''
1051
            )))
1052
    else: raise NotImplementedError("Can't list constraint columns for "+module+
1053
        ' database')
1054

    
1055
#### Functions
1056

    
1057
def function_exists(db, function):
1058
    function = sql_gen.as_Function(function)
1059
    
1060
    info_table = sql_gen.Table('routines', 'information_schema')
1061
    conds = [('routine_name', function.name)]
1062
    schema = function.schema
1063
    if schema != None: conds.append(('routine_schema', schema))
1064
    # Exclude trigger functions, since they cannot be called directly
1065
    conds.append(('data_type', sql_gen.CompareCond('trigger', '!=')))
1066
    
1067
    return list(values(select(db, info_table, ['routine_name'], conds,
1068
        order_by='routine_schema', limit=1, log_level=4))) != []
1069
        # TODO: order_by search_path schema order
1070

    
1071
##### Structural changes
1072

    
1073
#### Columns
1074

    
1075
def add_col(db, table, col, comment=None, **kw_args):
1076
    '''
1077
    @param col TypedCol Name may be versioned, so be sure to propagate any
1078
        renaming back to any source column for the TypedCol.
1079
    @param comment None|str SQL comment used to distinguish columns of the same
1080
        name from each other when they contain different data, to allow the
1081
        ADD COLUMN query to be cached. If not set, query will not be cached.
1082
    '''
1083
    assert isinstance(col, sql_gen.TypedCol)
1084
    
1085
    while True:
1086
        str_ = 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '+col.to_str(db)
1087
        if comment != None: str_ += ' '+sql_gen.esc_comment(comment)
1088
        
1089
        try:
1090
            run_query(db, str_, recover=True, cacheable=True, **kw_args)
1091
            break
1092
        except DuplicateException:
1093
            col.name = next_version(col.name)
1094
            # try again with next version of name
1095

    
1096
def add_not_null(db, col):
1097
    table = col.table
1098
    col = sql_gen.to_name_only_col(col)
1099
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1100
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1101

    
1102
row_num_col = '_row_num'
1103

    
1104
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1105
    constraints='PRIMARY KEY')
1106

    
1107
def add_row_num(db, table):
1108
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1109
    be the primary key.'''
1110
    add_col(db, table, row_num_typed_col, log_level=3)
1111

    
1112
#### Indexes
1113

    
1114
def add_pkey(db, table, cols=None, recover=None):
1115
    '''Adds a primary key.
1116
    @param cols [sql_gen.Col,...] The columns in the primary key.
1117
        Defaults to the first column in the table.
1118
    @pre The table must not already have a primary key.
1119
    '''
1120
    table = sql_gen.as_Table(table)
1121
    if cols == None: cols = [pkey(db, table, recover)]
1122
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1123
    
1124
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1125
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1126
        log_ignore_excs=(DuplicateException,))
1127

    
1128
def add_index(db, exprs, table=None, unique=False, ensure_not_null_=True):
1129
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
1130
    Currently, only function calls are supported as expressions.
1131
    @param ensure_not_null_ If set, translates NULL values to sentinel values.
1132
        This allows indexes to be used for comparisons where NULLs are equal.
1133
    '''
1134
    exprs = lists.mk_seq(exprs)
1135
    
1136
    # Parse exprs
1137
    old_exprs = exprs[:]
1138
    exprs = []
1139
    cols = []
1140
    for i, expr in enumerate(old_exprs):
1141
        expr = sql_gen.as_Col(expr, table)
1142
        
1143
        # Handle nullable columns
1144
        if ensure_not_null_:
1145
            try: expr = sql_gen.ensure_not_null(db, expr)
1146
            except KeyError: pass # unknown type, so just create plain index
1147
        
1148
        # Extract col
1149
        expr = copy.deepcopy(expr) # don't modify input!
1150
        if isinstance(expr, sql_gen.FunctionCall):
1151
            col = expr.args[0]
1152
            expr = sql_gen.Expr(expr)
1153
        else: col = expr
1154
        assert isinstance(col, sql_gen.Col)
1155
        
1156
        # Extract table
1157
        if table == None:
1158
            assert sql_gen.is_table_col(col)
1159
            table = col.table
1160
        
1161
        col.table = None
1162
        
1163
        exprs.append(expr)
1164
        cols.append(col)
1165
    
1166
    table = sql_gen.as_Table(table)
1167
    
1168
    # Add index
1169
    str_ = 'CREATE'
1170
    if unique: str_ += ' UNIQUE'
1171
    str_ += ' INDEX ON '+table.to_str(db)+' ('+(
1172
        ', '.join((v.to_str(db) for v in exprs)))+')'
1173
    run_query(db, str_, recover=True, cacheable=True, log_level=3)
1174

    
1175
already_indexed = object() # tells add_indexes() the pkey has already been added
1176

    
1177
def add_indexes(db, table, has_pkey=True):
1178
    '''Adds an index on all columns in a table.
1179
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1180
        index should be added on the first column.
1181
        * If already_indexed, the pkey is assumed to have already been added
1182
    '''
1183
    cols = table_cols(db, table)
1184
    if has_pkey:
1185
        if has_pkey is not already_indexed: add_pkey(db, table)
1186
        cols = cols[1:]
1187
    for col in cols: add_index(db, col, table)
1188

    
1189
#### Tables
1190

    
1191
### Maintenance
1192

    
1193
def analyze(db, table):
1194
    table = sql_gen.as_Table(table)
1195
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1196

    
1197
def autoanalyze(db, table):
1198
    if db.autoanalyze: analyze(db, table)
1199

    
1200
def vacuum(db, table):
1201
    table = sql_gen.as_Table(table)
1202
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1203
        log_level=3))
1204

    
1205
### Lifecycle
1206

    
1207
def drop(db, type_, name):
1208
    name = sql_gen.as_Name(name)
1209
    run_query(db, 'DROP '+type_+' IF EXISTS '+name.to_str(db)+' CASCADE')
1210

    
1211
def drop_table(db, table): drop(db, 'TABLE', table)
1212

    
1213
def create_table(db, table, cols=[], has_pkey=True, col_indexes=True,
1214
    like=None):
1215
    '''Creates a table.
1216
    @param cols [sql_gen.TypedCol,...] The column names and types
1217
    @param has_pkey If set, the first column becomes the primary key.
1218
    @param col_indexes bool|[ref]
1219
        * If True, indexes will be added on all non-pkey columns.
1220
        * If a list reference, [0] will be set to a function to do this.
1221
          This can be used to delay index creation until the table is populated.
1222
    '''
1223
    table = sql_gen.as_Table(table)
1224
    
1225
    if like != None:
1226
        cols = [sql_gen.CustomCode('LIKE '+like.to_str(db)+' INCLUDING ALL')
1227
            ]+cols
1228
    if has_pkey:
1229
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1230
        pkey.constraints = 'PRIMARY KEY'
1231
    
1232
    temp = table.is_temp and not db.debug_temp
1233
        # temp tables permanent in debug_temp mode
1234
    
1235
    # Create table
1236
    while True:
1237
        str_ = 'CREATE'
1238
        if temp: str_ += ' TEMP'
1239
        str_ += ' TABLE '+table.to_str(db)+' (\n'
1240
        str_ += '\n, '.join(c.to_str(db) for c in cols)
1241
        str_ += '\n);'
1242
        
1243
        try:
1244
            run_query(db, str_, recover=True, cacheable=True, log_level=2,
1245
                log_ignore_excs=(DuplicateException,))
1246
            break
1247
        except DuplicateException:
1248
            table.name = next_version(table.name)
1249
            # try again with next version of name
1250
    
1251
    # Add indexes
1252
    if has_pkey: has_pkey = already_indexed
1253
    def add_indexes_(): add_indexes(db, table, has_pkey)
1254
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1255
    elif col_indexes: add_indexes_() # add now
1256

    
1257
def copy_table_struct(db, src, dest):
1258
    '''Creates a structure-only copy of a table. (Does not copy data.)'''
1259
    create_table(db, dest, has_pkey=False, col_indexes=False, like=src)
1260

    
1261
### Data
1262

    
1263
def truncate(db, table, schema='public', **kw_args):
1264
    '''For params, see run_query()'''
1265
    table = sql_gen.as_Table(table, schema)
1266
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1267

    
1268
def empty_temp(db, tables):
1269
    tables = lists.mk_seq(tables)
1270
    for table in tables: truncate(db, table, log_level=3)
1271

    
1272
def empty_db(db, schema='public', **kw_args):
1273
    '''For kw_args, see tables()'''
1274
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1275

    
1276
def distinct_table(db, table, distinct_on):
1277
    '''Creates a copy of a temp table which is distinct on the given columns.
1278
    The old and new tables will both get an index on these columns, to
1279
    facilitate merge joins.
1280
    @param distinct_on If empty, creates a table with one row. This is useful if
1281
        your distinct_on columns are all literal values.
1282
    @return The new table.
1283
    '''
1284
    new_table = sql_gen.suffixed_table(table, '_distinct')
1285
    
1286
    copy_table_struct(db, table, new_table)
1287
    
1288
    limit = None
1289
    if distinct_on == []: limit = 1 # one sample row
1290
    else:
1291
        add_index(db, distinct_on, new_table, unique=True)
1292
        add_index(db, distinct_on, table) # for join optimization
1293
    
1294
    insert_select(db, new_table, None, mk_select(db, table, start=0,
1295
        limit=limit), ignore=True)
1296
    analyze(db, new_table)
1297
    
1298
    return new_table
(24-24/37)