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

    
482
connect = DbConn
483

    
484
##### Recoverable querying
485

    
486
def with_savepoint(db, func): return db.with_savepoint(func)
487

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

    
546
##### Basic queries
547

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

    
553
def explain(db, query, **kw_args):
554
    '''
555
    For params, see run_query().
556
    '''
557
    kw_args.setdefault('log_level', 4)
558
    
559
    return strings.join_lines(values(run_query(db, 'EXPLAIN '+query,
560
        recover=True, cacheable=True, **kw_args)))
561
        # not a higher log_level because it's useful to see what query is being
562
        # run before it's executed, which EXPLAIN effectively provides
563

    
564
def has_comment(query): return query.endswith('*/')
565

    
566
def with_explain_comment(db, query, **kw_args):
567
    if db.autoexplain and not has_comment(query) and is_explainable(query):
568
        query += '\n'+sql_gen.esc_comment(' EXPLAIN:\n'
569
            +explain(db, query, **kw_args))
570
    return query
571

    
572
def next_version(name):
573
    version = 1 # first existing name was version 0
574
    match = re.match(r'^(.*)#(\d+)$', name)
575
    if match:
576
        name, version = match.groups()
577
        version = int(version)+1
578
    return sql_gen.concat(name, '#'+str(version))
579

    
580
def lock_table(db, table, mode):
581
    table = sql_gen.as_Table(table)
582
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
583

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

    
627
order_by_pkey = object() # tells mk_select() to order by the pkey
628

    
629
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
630

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

    
718
def select(db, *args, **kw_args):
719
    '''For params, see mk_select() and run_query()'''
720
    recover = kw_args.pop('recover', None)
721
    cacheable = kw_args.pop('cacheable', True)
722
    log_level = kw_args.pop('log_level', 2)
723
    
724
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
725
        log_level=log_level)
726

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

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

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

    
860
def insert(db, table, row, *args, **kw_args):
861
    '''For params, see insert_select()'''
862
    if lists.is_seq(row): cols = None
863
    else:
864
        cols = row.keys()
865
        row = row.values()
866
    row = list(row) # ensure that "== []" works
867
    
868
    if row == []: query = None
869
    else: query = sql_gen.Values(row).to_str(db)
870
    
871
    return insert_select(db, table, cols, query, *args, **kw_args)
872

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

    
909
def update(db, table, *args, **kw_args):
910
    '''For params, see mk_update() and run_query()'''
911
    recover = kw_args.pop('recover', None)
912
    cacheable = kw_args.pop('cacheable', False)
913
    log_level = kw_args.pop('log_level', 2)
914
    
915
    cur = run_query(db, mk_update(db, table, *args, **kw_args), recover,
916
        cacheable, log_level=log_level)
917
    autoanalyze(db, table)
918
    return cur
919

    
920
def last_insert_id(db):
921
    module = util.root_module(db.db)
922
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
923
    elif module == 'MySQLdb': return db.insert_id()
924
    else: return None
925

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

    
958
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
959
    '''For params, see mk_flatten_mapping()
960
    @return See return value of mk_flatten_mapping()
961
    '''
962
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
963
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
964
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
965
        into=into)
966
    return dict(items)
967

    
968
##### Database structure introspection
969

    
970
#### Tables
971

    
972
def tables(db, schema_like='public', table_like='%', exact=False):
973
    if exact: compare = '='
974
    else: compare = 'LIKE'
975
    
976
    module = util.root_module(db.db)
977
    if module == 'psycopg2':
978
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
979
            ('tablename', sql_gen.CompareCond(table_like, compare))]
980
        return values(select(db, 'pg_tables', ['tablename'], conds,
981
            order_by='tablename', log_level=4))
982
    elif module == 'MySQLdb':
983
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
984
            , cacheable=True, log_level=4))
985
    else: raise NotImplementedError("Can't list tables for "+module+' database')
986

    
987
def table_exists(db, table):
988
    table = sql_gen.as_Table(table)
989
    return list(tables(db, table.schema, table.name, exact=True)) != []
990

    
991
def table_row_count(db, table, recover=None):
992
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
993
        order_by=None, start=0), recover=recover, log_level=3))
994

    
995
def table_cols(db, table, recover=None):
996
    return list(col_names(select(db, table, limit=0, order_by=None,
997
        recover=recover, log_level=4)))
998

    
999
def pkey(db, table, recover=None):
1000
    '''Assumed to be first column in table'''
1001
    return table_cols(db, table, recover)[0]
1002

    
1003
not_null_col = 'not_null_col'
1004

    
1005
def table_not_null_col(db, table, recover=None):
1006
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
1007
    if not_null_col in table_cols(db, table, recover): return not_null_col
1008
    else: return pkey(db, table, recover)
1009

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

    
1051
def constraint_cols(db, table, constraint):
1052
    module = util.root_module(db.db)
1053
    if module == 'psycopg2':
1054
        return list(values(run_query(db, '''\
1055
SELECT attname
1056
FROM pg_constraint
1057
JOIN pg_class ON pg_class.oid = conrelid
1058
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
1059
WHERE
1060
    relname = '''+db.esc_value(table)+'''
1061
    AND conname = '''+db.esc_value(constraint)+'''
1062
ORDER BY attnum
1063
'''
1064
            )))
1065
    else: raise NotImplementedError("Can't list constraint columns for "+module+
1066
        ' database')
1067

    
1068
#### Functions
1069

    
1070
def function_exists(db, function):
1071
    function = sql_gen.as_Function(function)
1072
    
1073
    info_table = sql_gen.Table('routines', 'information_schema')
1074
    conds = [('routine_name', function.name)]
1075
    schema = function.schema
1076
    if schema != None: conds.append(('routine_schema', schema))
1077
    # Exclude trigger functions, since they cannot be called directly
1078
    conds.append(('data_type', sql_gen.CompareCond('trigger', '!=')))
1079
    
1080
    return list(values(select(db, info_table, ['routine_name'], conds,
1081
        order_by='routine_schema', limit=1, log_level=4))) != []
1082
        # TODO: order_by search_path schema order
1083

    
1084
##### Structural changes
1085

    
1086
#### Columns
1087

    
1088
def add_col(db, table, col, comment=None, **kw_args):
1089
    '''
1090
    @param col TypedCol Name may be versioned, so be sure to propagate any
1091
        renaming back to any source column for the TypedCol.
1092
    @param comment None|str SQL comment used to distinguish columns of the same
1093
        name from each other when they contain different data, to allow the
1094
        ADD COLUMN query to be cached. If not set, query will not be cached.
1095
    '''
1096
    assert isinstance(col, sql_gen.TypedCol)
1097
    
1098
    while True:
1099
        str_ = 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '+col.to_str(db)
1100
        if comment != None: str_ += ' '+sql_gen.esc_comment(comment)
1101
        
1102
        try:
1103
            run_query(db, str_, recover=True, cacheable=True, **kw_args)
1104
            break
1105
        except DuplicateException:
1106
            col.name = next_version(col.name)
1107
            # try again with next version of name
1108

    
1109
def add_not_null(db, col):
1110
    table = col.table
1111
    col = sql_gen.to_name_only_col(col)
1112
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1113
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1114

    
1115
row_num_col = '_row_num'
1116

    
1117
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1118
    constraints='PRIMARY KEY')
1119

    
1120
def add_row_num(db, table):
1121
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1122
    be the primary key.'''
1123
    add_col(db, table, row_num_typed_col, log_level=3)
1124

    
1125
#### Indexes
1126

    
1127
def add_pkey(db, table, cols=None, recover=None):
1128
    '''Adds a primary key.
1129
    @param cols [sql_gen.Col,...] The columns in the primary key.
1130
        Defaults to the first column in the table.
1131
    @pre The table must not already have a primary key.
1132
    '''
1133
    table = sql_gen.as_Table(table)
1134
    if cols == None: cols = [pkey(db, table, recover)]
1135
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1136
    
1137
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1138
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1139
        log_ignore_excs=(DuplicateException,))
1140

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

    
1188
already_indexed = object() # tells add_indexes() the pkey has already been added
1189

    
1190
def add_indexes(db, table, has_pkey=True):
1191
    '''Adds an index on all columns in a table.
1192
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1193
        index should be added on the first column.
1194
        * If already_indexed, the pkey is assumed to have already been added
1195
    '''
1196
    cols = table_cols(db, table)
1197
    if has_pkey:
1198
        if has_pkey is not already_indexed: add_pkey(db, table)
1199
        cols = cols[1:]
1200
    for col in cols: add_index(db, col, table)
1201

    
1202
#### Tables
1203

    
1204
### Maintenance
1205

    
1206
def analyze(db, table):
1207
    table = sql_gen.as_Table(table)
1208
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1209

    
1210
def autoanalyze(db, table):
1211
    if db.autoanalyze: analyze(db, table)
1212

    
1213
def vacuum(db, table):
1214
    table = sql_gen.as_Table(table)
1215
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1216
        log_level=3))
1217

    
1218
### Lifecycle
1219

    
1220
def drop(db, type_, name):
1221
    name = sql_gen.as_Name(name)
1222
    run_query(db, 'DROP '+type_+' IF EXISTS '+name.to_str(db)+' CASCADE')
1223

    
1224
def drop_table(db, table): drop(db, 'TABLE', table)
1225

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

    
1270
def copy_table_struct(db, src, dest):
1271
    '''Creates a structure-only copy of a table. (Does not copy data.)'''
1272
    create_table(db, dest, has_pkey=False, col_indexes=False, like=src)
1273

    
1274
### Data
1275

    
1276
def truncate(db, table, schema='public', **kw_args):
1277
    '''For params, see run_query()'''
1278
    table = sql_gen.as_Table(table, schema)
1279
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1280

    
1281
def empty_temp(db, tables):
1282
    tables = lists.mk_seq(tables)
1283
    for table in tables: truncate(db, table, log_level=3)
1284

    
1285
def empty_db(db, schema='public', **kw_args):
1286
    '''For kw_args, see tables()'''
1287
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1288

    
1289
def distinct_table(db, table, distinct_on):
1290
    '''Creates a copy of a temp table which is distinct on the given columns.
1291
    The old and new tables will both get an index on these columns, to
1292
    facilitate merge joins.
1293
    @param distinct_on If empty, creates a table with one row. This is useful if
1294
        your distinct_on columns are all literal values.
1295
    @return The new table.
1296
    '''
1297
    new_table = sql_gen.suffixed_table(table, '_distinct')
1298
    
1299
    copy_table_struct(db, table, new_table)
1300
    
1301
    limit = None
1302
    if distinct_on == []: limit = 1 # one sample row
1303
    else:
1304
        add_index(db, distinct_on, new_table, unique=True)
1305
        add_index(db, distinct_on, table) # for join optimization
1306
    
1307
    insert_select(db, new_table, None, mk_select(db, table, start=0,
1308
        limit=limit), ignore=True)
1309
    analyze(db, new_table)
1310
    
1311
    return new_table
(24-24/37)