Project

General

Profile

1
# Database access
2

    
3
import copy
4
import re
5
import warnings
6

    
7
import exc
8
import dicts
9
import iters
10
import lists
11
from Proxy import Proxy
12
import rand
13
import sql_gen
14
import strings
15
import util
16

    
17
##### Exceptions
18

    
19
def get_cur_query(cur, input_query=None):
20
    raw_query = None
21
    if hasattr(cur, 'query'): raw_query = cur.query
22
    elif hasattr(cur, '_last_executed'): raw_query = cur._last_executed
23
    
24
    if raw_query != None: return raw_query
25
    else: return '[input] '+strings.ustr(input_query)
26

    
27
def _add_cursor_info(e, *args, **kw_args):
28
    '''For params, see get_cur_query()'''
29
    exc.add_msg(e, 'query: '+strings.ustr(get_cur_query(*args, **kw_args)))
30

    
31
class DbException(exc.ExceptionWithCause):
32
    def __init__(self, msg, cause=None, cur=None):
33
        exc.ExceptionWithCause.__init__(self, msg, cause, cause_newline=True)
34
        if cur != None: _add_cursor_info(self, cur)
35

    
36
class ExceptionWithName(DbException):
37
    def __init__(self, name, cause=None):
38
        DbException.__init__(self, 'for name: '+strings.as_tt(str(name)), cause)
39
        self.name = name
40

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

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

    
54
class ConstraintException(DbException):
55
    def __init__(self, name, cols, cause=None):
56
        DbException.__init__(self, 'Violated '+strings.as_tt(name)
57
            +' constraint on columns: '+strings.as_tt(', '.join(cols)), cause)
58
        self.name = name
59
        self.cols = cols
60

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

    
68
class NameException(DbException): pass
69

    
70
class DuplicateKeyException(ConstraintException): pass
71

    
72
class NullValueException(ConstraintException): pass
73

    
74
class InvalidValueException(ExceptionWithValue): pass
75

    
76
class DuplicateException(ExceptionWithNameType): pass
77

    
78
class EmptyRowException(DbException): pass
79

    
80
##### Warnings
81

    
82
class DbWarning(UserWarning): pass
83

    
84
##### Result retrieval
85

    
86
def col_names(cur): return (col[0] for col in cur.description)
87

    
88
def rows(cur): return iter(lambda: cur.fetchone(), None)
89

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

    
94
def next_row(cur): return rows(cur).next()
95

    
96
def row(cur):
97
    row_ = next_row(cur)
98
    consume_rows(cur)
99
    return row_
100

    
101
def next_value(cur): return next_row(cur)[0]
102

    
103
def value(cur): return row(cur)[0]
104

    
105
def values(cur): return iters.func_iter(lambda: next_value(cur))
106

    
107
def value_or_none(cur):
108
    try: return value(cur)
109
    except StopIteration: return None
110

    
111
##### Escaping
112

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

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

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

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

    
131
##### Database connections
132

    
133
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
134

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

    
140
DatabaseErrors_set = set([DbException])
141
DatabaseErrors = tuple(DatabaseErrors_set)
142

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

    
148
def db_config_str(db_config):
149
    return db_config['engine']+' database '+db_config['database']
150

    
151
log_debug_none = lambda msg, level=2: None
152

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

    
454
connect = DbConn
455

    
456
##### Recoverable querying
457

    
458
def with_savepoint(db, func): return db.with_savepoint(func)
459

    
460
def run_query(db, query, recover=None, cacheable=False, log_level=2,
461
    log_ignore_excs=None, **kw_args):
462
    '''For params, see DbConn.run_query()'''
463
    if recover == None: recover = False
464
    if log_ignore_excs == None: log_ignore_excs = ()
465
    log_ignore_excs = tuple(log_ignore_excs)
466
    
467
    debug_msg_ref = None # usually, db.run_query() logs query before running it
468
    # But if filtering with log_ignore_excs, wait until after exception parsing
469
    if log_ignore_excs != () or not db.can_mogrify(): debug_msg_ref = [None]
470
    
471
    try:
472
        try:
473
            def run(): return db.run_query(query, cacheable, log_level,
474
                debug_msg_ref, **kw_args)
475
            if recover and not db.is_cached(query):
476
                return with_savepoint(db, run)
477
            else: return run() # don't need savepoint if cached
478
        except Exception, e:
479
            msg = strings.ustr(e.args[0])
480
            
481
            match = re.match(r'^duplicate key value violates unique constraint '
482
                r'"((_?[^\W_]+(?=[._]))?.+?)"', msg)
483
            if match:
484
                constraint, table = match.groups()
485
                cols = []
486
                if recover: # need auto-rollback to run index_cols()
487
                    try: cols = index_cols(db, table, constraint)
488
                    except NotImplementedError: pass
489
                raise DuplicateKeyException(constraint, cols, e)
490
            
491
            match = re.match(r'^null value in column "(.+?)" violates not-null'
492
                r' constraint', msg)
493
            if match: raise NullValueException('NOT NULL', [match.group(1)], e)
494
            
495
            match = re.match(r'^(?:invalid input (?:syntax|value)\b.*?'
496
                r'|.+? field value out of range): "(.+?)"', msg)
497
            if match:
498
                value, = match.groups()
499
                raise InvalidValueException(strings.to_unicode(value), e)
500
            
501
            match = re.match(r'^column "(.+?)" is of type (.+?) but expression '
502
                r'is of type', msg)
503
            if match:
504
                col, type_ = match.groups()
505
                raise MissingCastException(type_, col, e)
506
            
507
            match = re.match(r'^(\S+) "(.+?)".*? already exists', msg)
508
            if match:
509
                type_, name = match.groups()
510
                raise DuplicateException(type_, name, e)
511
            
512
            raise # no specific exception raised
513
    except log_ignore_excs:
514
        log_level += 2
515
        raise
516
    finally:
517
        if debug_msg_ref != None and debug_msg_ref[0] != None:
518
            db.log_debug(debug_msg_ref[0], log_level)
519

    
520
##### Basic queries
521

    
522
def next_version(name):
523
    version = 1 # first existing name was version 0
524
    match = re.match(r'^(.*)#(\d+)$', name)
525
    if match:
526
        name, version = match.groups()
527
        version = int(version)+1
528
    return sql_gen.concat(name, '#'+str(version))
529

    
530
def lock_table(db, table, mode):
531
    table = sql_gen.as_Table(table)
532
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
533

    
534
def run_query_into(db, query, into=None, add_indexes_=False, **kw_args):
535
    '''Outputs a query to a temp table.
536
    For params, see run_query().
537
    '''
538
    if into == None: return run_query(db, query, **kw_args)
539
    
540
    assert isinstance(into, sql_gen.Table)
541
    
542
    into.is_temp = True
543
    # "temporary tables cannot specify a schema name", so remove schema
544
    into.schema = None
545
    
546
    kw_args['recover'] = True
547
    kw_args.setdefault('log_ignore_excs', (DuplicateException,))
548
    
549
    temp = not db.debug_temp # tables are permanent in debug_temp mode
550
    
551
    # Create table
552
    while True:
553
        create_query = 'CREATE'
554
        if temp: create_query += ' TEMP'
555
        create_query += ' TABLE '+into.to_str(db)+' AS\n'+query
556
        
557
        try:
558
            cur = run_query(db, create_query, **kw_args)
559
                # CREATE TABLE AS sets rowcount to # rows in query
560
            break
561
        except DuplicateException, e:
562
            into.name = next_version(into.name)
563
            # try again with next version of name
564
    
565
    if add_indexes_: add_indexes(db, into)
566
    
567
    # According to the PostgreSQL doc, "The autovacuum daemon cannot access and
568
    # therefore cannot vacuum or analyze temporary tables. [...] if a temporary
569
    # table is going to be used in complex queries, it is wise to run ANALYZE on
570
    # the temporary table after it is populated."
571
    # (http://www.postgresql.org/docs/9.1/static/sql-createtable.html)
572
    # If into is not a temp table, ANALYZE is useful but not required.
573
    analyze(db, into)
574
    
575
    return cur
576

    
577
order_by_pkey = object() # tells mk_select() to order by the pkey
578

    
579
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
580

    
581
def mk_select(db, tables, fields=None, conds=None, distinct_on=[], limit=None,
582
    start=None, order_by=order_by_pkey, default_table=None):
583
    '''
584
    @param tables The single table to select from, or a list of tables to join
585
        together, with tables after the first being sql_gen.Join objects
586
    @param fields Use None to select all fields in the table
587
    @param conds WHERE conditions: [(compare_left_side, compare_right_side),...]
588
        * container can be any iterable type
589
        * compare_left_side: sql_gen.Code|str (for col name)
590
        * compare_right_side: sql_gen.ValueCond|literal value
591
    @param distinct_on The columns to SELECT DISTINCT ON, or distinct_on_all to
592
        use all columns
593
    @return query
594
    '''
595
    # Parse tables param
596
    tables = lists.mk_seq(tables)
597
    tables = list(tables) # don't modify input! (list() copies input)
598
    table0 = sql_gen.as_Table(tables.pop(0)) # first table is separate
599
    
600
    # Parse other params
601
    if conds == None: conds = []
602
    elif dicts.is_dict(conds): conds = conds.items()
603
    conds = list(conds) # don't modify input! (list() copies input)
604
    assert limit == None or isinstance(limit, (int, long))
605
    assert start == None or isinstance(start, (int, long))
606
    if order_by is order_by_pkey:
607
        if distinct_on != []: order_by = None
608
        else: order_by = pkey(db, table0, recover=True)
609
    
610
    query = 'SELECT'
611
    
612
    def parse_col(col): return sql_gen.as_Col(col, default_table).to_str(db)
613
    
614
    # DISTINCT ON columns
615
    if distinct_on != []:
616
        query += '\nDISTINCT'
617
        if distinct_on is not distinct_on_all:
618
            query += ' ON ('+(', '.join(map(parse_col, distinct_on)))+')'
619
    
620
    # Columns
621
    if fields == None:
622
        if query.find('\n') >= 0: whitespace = '\n'
623
        else: whitespace = ' '
624
        query += whitespace+'*'
625
    else:
626
        assert fields != []
627
        query += '\n'+('\n, '.join(map(parse_col, fields)))
628
    
629
    # Main table
630
    query += '\nFROM '+table0.to_str(db)
631
    
632
    # Add joins
633
    left_table = table0
634
    for join_ in tables:
635
        table = join_.table
636
        
637
        # Parse special values
638
        if join_.type_ is sql_gen.filter_out: # filter no match
639
            conds.append((sql_gen.Col(table_not_null_col(db, table), table),
640
                sql_gen.CompareCond(None, '~=')))
641
        
642
        query += '\n'+join_.to_str(db, left_table)
643
        
644
        left_table = table
645
    
646
    missing = True
647
    if conds != []:
648
        if len(conds) == 1: whitespace = ' '
649
        else: whitespace = '\n'
650
        query += '\n'+sql_gen.combine_conds([sql_gen.ColValueCond(l, r)
651
            .to_str(db) for l, r in conds], 'WHERE')
652
        missing = False
653
    if order_by != None:
654
        query += '\nORDER BY '+sql_gen.as_Col(order_by, table0).to_str(db)
655
    if limit != None: query += '\nLIMIT '+str(limit); missing = False
656
    if start != None:
657
        if start != 0: query += '\nOFFSET '+str(start)
658
        missing = False
659
    if missing: warnings.warn(DbWarning(
660
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
661
    
662
    return query
663

    
664
def select(db, *args, **kw_args):
665
    '''For params, see mk_select() and run_query()'''
666
    recover = kw_args.pop('recover', None)
667
    cacheable = kw_args.pop('cacheable', True)
668
    log_level = kw_args.pop('log_level', 2)
669
    
670
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
671
        log_level=log_level)
672

    
673
def mk_insert_select(db, table, cols=None, select_query=None, returning=None,
674
    embeddable=False, ignore=False):
675
    '''
676
    @param returning str|None An inserted column (such as pkey) to return
677
    @param embeddable Whether the query should be embeddable as a nested SELECT.
678
        Warning: If you set this and cacheable=True when the query is run, the
679
        query will be fully cached, not just if it raises an exception.
680
    @param ignore Whether to ignore duplicate keys.
681
    '''
682
    table = sql_gen.remove_table_rename(sql_gen.as_Table(table))
683
    if cols == []: cols = None # no cols (all defaults) = unknown col names
684
    if cols != None: cols = [sql_gen.to_name_only_col(c, table) for c in cols]
685
    if select_query == None: select_query = 'DEFAULT VALUES'
686
    if returning != None: returning = sql_gen.as_Col(returning, table)
687
    
688
    first_line = 'INSERT INTO '+table.to_str(db)
689
    
690
    def mk_insert(select_query):
691
        query = first_line
692
        if cols != None:
693
            query += '\n('+(', '.join((c.to_str(db) for c in cols)))+')'
694
        query += '\n'+select_query
695
        
696
        if returning != None:
697
            returning_name_col = sql_gen.to_name_only_col(returning)
698
            query += '\nRETURNING '+returning_name_col.to_str(db)
699
        
700
        return query
701
    
702
    return_type = 'unknown'
703
    if returning != None: return_type = returning.to_str(db)+'%TYPE'
704
    
705
    lang = 'sql'
706
    if ignore:
707
        # Always return something to set the correct rowcount
708
        if returning == None: returning = sql_gen.NamedCol('NULL', None)
709
        
710
        embeddable = True # must use function
711
        lang = 'plpgsql'
712
        
713
        if cols == None:
714
            row = [sql_gen.Col(sql_gen.all_cols, 'row')]
715
            row_vars = [sql_gen.Table('row')]
716
        else:
717
            row_vars = row = [sql_gen.Col(c.name, 'row') for c in cols]
718
        
719
        query = '''\
720
DECLARE
721
    row '''+table.to_str(db)+'''%ROWTYPE;
722
BEGIN
723
    /* Need an EXCEPTION block for each individual row because "When an error is
724
    caught by an EXCEPTION clause, [...] all changes to persistent database
725
    state within the block are rolled back."
726
    This is unfortunate because "A block containing an EXCEPTION clause is
727
    significantly more expensive to enter and exit than a block without one."
728
    (http://www.postgresql.org/docs/8.3/static/plpgsql-control-structures.html\
729
#PLPGSQL-ERROR-TRAPPING)
730
    */
731
    FOR '''+(', '.join((v.to_str(db) for v in row_vars)))+''' IN
732
'''+select_query+'''
733
    LOOP
734
        BEGIN
735
            RETURN QUERY
736
'''+mk_insert(sql_gen.Values(row).to_str(db))+'''
737
;
738
        EXCEPTION
739
            WHEN unique_violation THEN NULL; -- continue to next row
740
        END;
741
    END LOOP;
742
END;\
743
'''
744
    else: query = mk_insert(select_query)
745
    
746
    if embeddable:
747
        # Create function
748
        function_name = sql_gen.clean_name(first_line)
749
        while True:
750
            try:
751
                function = db.TempFunction(function_name)
752
                
753
                function_query = '''\
754
CREATE FUNCTION '''+function.to_str(db)+'''()
755
RETURNS SETOF '''+return_type+'''
756
LANGUAGE '''+lang+'''
757
AS $$
758
'''+query+'''
759
$$;
760
'''
761
                run_query(db, function_query, recover=True, cacheable=True,
762
                    log_ignore_excs=(DuplicateException,))
763
                break # this version was successful
764
            except DuplicateException, e:
765
                function_name = next_version(function_name)
766
                # try again with next version of name
767
        
768
        # Return query that uses function
769
        cols = None
770
        if returning != None: cols = [returning]
771
        func_table = sql_gen.NamedTable('f', sql_gen.FunctionCall(function),
772
            cols) # AS clause requires function alias
773
        return mk_select(db, func_table, start=0, order_by=None)
774
    
775
    return query
776

    
777
def insert_select(db, table, *args, **kw_args):
778
    '''For params, see mk_insert_select() and run_query_into()
779
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
780
        values in
781
    '''
782
    returning = kw_args.get('returning', None)
783
    ignore = kw_args.get('ignore', False)
784
    
785
    into = kw_args.pop('into', None)
786
    if into != None: kw_args['embeddable'] = True
787
    recover = kw_args.pop('recover', None)
788
    if ignore: recover = True
789
    cacheable = kw_args.pop('cacheable', True)
790
    log_level = kw_args.pop('log_level', 2)
791
    
792
    rowcount_only = ignore and returning == None # keep NULL rows on server
793
    if rowcount_only: into = sql_gen.Table('rowcount')
794
    
795
    cur = run_query_into(db, mk_insert_select(db, table, *args, **kw_args),
796
        into, recover=recover, cacheable=cacheable, log_level=log_level)
797
    if rowcount_only: empty_temp(db, into)
798
    autoanalyze(db, table)
799
    return cur
800

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

    
803
def insert(db, table, row, *args, **kw_args):
804
    '''For params, see insert_select()'''
805
    if lists.is_seq(row): cols = None
806
    else:
807
        cols = row.keys()
808
        row = row.values()
809
    row = list(row) # ensure that "== []" works
810
    
811
    if row == []: query = None
812
    else: query = sql_gen.Values(row).to_str(db)
813
    
814
    return insert_select(db, table, cols, query, *args, **kw_args)
815

    
816
def mk_update(db, table, changes=None, cond=None, in_place=False,
817
    cacheable_=True):
818
    '''
819
    @param changes [(col, new_value),...]
820
        * container can be any iterable type
821
        * col: sql_gen.Code|str (for col name)
822
        * new_value: sql_gen.Code|literal value
823
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
824
    @param in_place If set, locks the table and updates rows in place.
825
        This avoids creating dead rows in PostgreSQL.
826
        * cond must be None
827
    @param cacheable_ Whether column structure information used to generate the
828
        query can be cached
829
    @return str query
830
    '''
831
    table = sql_gen.as_Table(table)
832
    changes = [(sql_gen.to_name_only_col(c, table), sql_gen.as_Value(v))
833
        for c, v in changes]
834
    
835
    if in_place:
836
        assert cond == None
837
        
838
        query = 'ALTER TABLE '+table.to_str(db)+'\n'
839
        query += ',\n'.join(('ALTER COLUMN '+c.to_str(db)+' TYPE '
840
            +db.col_info(sql_gen.with_default_table(c, table), cacheable_).type
841
            +'\nUSING '+v.to_str(db) for c, v in changes))
842
    else:
843
        query = 'UPDATE '+table.to_str(db)+'\nSET\n'
844
        query += ',\n'.join((c.to_str(db)+' = '+v.to_str(db)
845
            for c, v in changes))
846
        if cond != None: query += '\nWHERE\n'+cond.to_str(db)
847
    
848
    return query
849

    
850
def update(db, table, *args, **kw_args):
851
    '''For params, see mk_update() and run_query()'''
852
    recover = kw_args.pop('recover', None)
853
    cacheable = kw_args.pop('cacheable', False)
854
    log_level = kw_args.pop('log_level', 2)
855
    
856
    cur = run_query(db, mk_update(db, table, *args, **kw_args), recover,
857
        cacheable, log_level=log_level)
858
    autoanalyze(db, table)
859
    return cur
860

    
861
def last_insert_id(db):
862
    module = util.root_module(db.db)
863
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
864
    elif module == 'MySQLdb': return db.insert_id()
865
    else: return None
866

    
867
def mk_flatten_mapping(db, into, cols, preserve=[], as_items=False):
868
    '''Creates a mapping from original column names (which may have collisions)
869
    to names that will be distinct among the columns' tables.
870
    This is meant to be used for several tables that are being joined together.
871
    @param cols The columns to combine. Duplicates will be removed.
872
    @param into The table for the new columns.
873
    @param preserve [sql_gen.Col...] Columns not to rename. Note that these
874
        columns will be included in the mapping even if they are not in cols.
875
        The tables of the provided Col objects will be changed to into, so make
876
        copies of them if you want to keep the original tables.
877
    @param as_items Whether to return a list of dict items instead of a dict
878
    @return dict(orig_col=new_col, ...)
879
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
880
        * new_col: sql_gen.Col(orig_col_name, into)
881
        * All mappings use the into table so its name can easily be
882
          changed for all columns at once
883
    '''
884
    cols = lists.uniqify(cols)
885
    
886
    items = []
887
    for col in preserve:
888
        orig_col = copy.copy(col)
889
        col.table = into
890
        items.append((orig_col, col))
891
    preserve = set(preserve)
892
    for col in cols:
893
        if col not in preserve:
894
            items.append((col, sql_gen.Col(str(col), into, col.srcs)))
895
    
896
    if not as_items: items = dict(items)
897
    return items
898

    
899
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
900
    '''For params, see mk_flatten_mapping()
901
    @return See return value of mk_flatten_mapping()
902
    '''
903
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
904
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
905
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
906
        into=into, add_indexes_=True)
907
    return dict(items)
908

    
909
##### Database structure introspection
910

    
911
#### Tables
912

    
913
def tables(db, schema_like='public', table_like='%', exact=False):
914
    if exact: compare = '='
915
    else: compare = 'LIKE'
916
    
917
    module = util.root_module(db.db)
918
    if module == 'psycopg2':
919
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
920
            ('tablename', sql_gen.CompareCond(table_like, compare))]
921
        return values(select(db, 'pg_tables', ['tablename'], conds,
922
            order_by='tablename', log_level=4))
923
    elif module == 'MySQLdb':
924
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
925
            , cacheable=True, log_level=4))
926
    else: raise NotImplementedError("Can't list tables for "+module+' database')
927

    
928
def table_exists(db, table):
929
    table = sql_gen.as_Table(table)
930
    return list(tables(db, table.schema, table.name, exact=True)) != []
931

    
932
def table_row_count(db, table, recover=None):
933
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
934
        order_by=None, start=0), recover=recover, log_level=3))
935

    
936
def table_cols(db, table, recover=None):
937
    return list(col_names(select(db, table, limit=0, order_by=None,
938
        recover=recover, log_level=4)))
939

    
940
def pkey(db, table, recover=None):
941
    '''Assumed to be first column in table'''
942
    return table_cols(db, table, recover)[0]
943

    
944
not_null_col = 'not_null_col'
945

    
946
def table_not_null_col(db, table, recover=None):
947
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
948
    if not_null_col in table_cols(db, table, recover): return not_null_col
949
    else: return pkey(db, table, recover)
950

    
951
def index_cols(db, table, index):
952
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
953
    automatically created. When you don't know whether something is a UNIQUE
954
    constraint or a UNIQUE index, use this function.'''
955
    module = util.root_module(db.db)
956
    if module == 'psycopg2':
957
        return list(values(run_query(db, '''\
958
SELECT attname
959
FROM
960
(
961
        SELECT attnum, attname
962
        FROM pg_index
963
        JOIN pg_class index ON index.oid = indexrelid
964
        JOIN pg_class table_ ON table_.oid = indrelid
965
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
966
        WHERE
967
            table_.relname = '''+db.esc_value(table)+'''
968
            AND index.relname = '''+db.esc_value(index)+'''
969
    UNION
970
        SELECT attnum, attname
971
        FROM
972
        (
973
            SELECT
974
                indrelid
975
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
976
                    AS indkey
977
            FROM pg_index
978
            JOIN pg_class index ON index.oid = indexrelid
979
            JOIN pg_class table_ ON table_.oid = indrelid
980
            WHERE
981
                table_.relname = '''+db.esc_value(table)+'''
982
                AND index.relname = '''+db.esc_value(index)+'''
983
        ) s
984
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
985
) s
986
ORDER BY attnum
987
'''
988
            , cacheable=True, log_level=4)))
989
    else: raise NotImplementedError("Can't list index columns for "+module+
990
        ' database')
991

    
992
def constraint_cols(db, table, constraint):
993
    module = util.root_module(db.db)
994
    if module == 'psycopg2':
995
        return list(values(run_query(db, '''\
996
SELECT attname
997
FROM pg_constraint
998
JOIN pg_class ON pg_class.oid = conrelid
999
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
1000
WHERE
1001
    relname = '''+db.esc_value(table)+'''
1002
    AND conname = '''+db.esc_value(constraint)+'''
1003
ORDER BY attnum
1004
'''
1005
            )))
1006
    else: raise NotImplementedError("Can't list constraint columns for "+module+
1007
        ' database')
1008

    
1009
#### Functions
1010

    
1011
def function_exists(db, function):
1012
    function = sql_gen.as_Function(function)
1013
    
1014
    info_table = sql_gen.Table('routines', 'information_schema')
1015
    conds = [('routine_name', function.name)]
1016
    schema = function.schema
1017
    if schema != None: conds.append(('routine_schema', schema))
1018
    # Exclude trigger functions, since they cannot be called directly
1019
    conds.append(('data_type', sql_gen.CompareCond('trigger', '!=')))
1020
    
1021
    return list(values(select(db, info_table, ['routine_name'], conds,
1022
        order_by='routine_schema', limit=1, log_level=4))) != []
1023
        # TODO: order_by search_path schema order
1024

    
1025
##### Structural changes
1026

    
1027
#### Columns
1028

    
1029
def add_col(db, table, col, comment=None, **kw_args):
1030
    '''
1031
    @param col TypedCol Name may be versioned, so be sure to propagate any
1032
        renaming back to any source column for the TypedCol.
1033
    @param comment None|str SQL comment used to distinguish columns of the same
1034
        name from each other when they contain different data, to allow the
1035
        ADD COLUMN query to be cached. If not set, query will not be cached.
1036
    '''
1037
    assert isinstance(col, sql_gen.TypedCol)
1038
    
1039
    while True:
1040
        str_ = 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '+col.to_str(db)
1041
        if comment != None: str_ += ' '+sql_gen.esc_comment(comment)
1042
        
1043
        try:
1044
            run_query(db, str_, recover=True, cacheable=True, **kw_args)
1045
            break
1046
        except DuplicateException:
1047
            col.name = next_version(col.name)
1048
            # try again with next version of name
1049

    
1050
def add_not_null(db, col):
1051
    table = col.table
1052
    col = sql_gen.to_name_only_col(col)
1053
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1054
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1055

    
1056
row_num_col = '_row_num'
1057

    
1058
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1059
    constraints='PRIMARY KEY')
1060

    
1061
def add_row_num(db, table):
1062
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1063
    be the primary key.'''
1064
    add_col(db, table, row_num_typed_col, log_level=3)
1065

    
1066
#### Indexes
1067

    
1068
def add_pkey(db, table, cols=None, recover=None):
1069
    '''Adds a primary key.
1070
    @param cols [sql_gen.Col,...] The columns in the primary key.
1071
        Defaults to the first column in the table.
1072
    @pre The table must not already have a primary key.
1073
    '''
1074
    table = sql_gen.as_Table(table)
1075
    if cols == None: cols = [pkey(db, table, recover)]
1076
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1077
    
1078
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1079
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1080
        log_ignore_excs=(DuplicateException,))
1081

    
1082
def add_index(db, exprs, table=None, unique=False, ensure_not_null_=True):
1083
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
1084
    Currently, only function calls are supported as expressions.
1085
    @param ensure_not_null_ If set, translates NULL values to sentinel values.
1086
        This allows indexes to be used for comparisons where NULLs are equal.
1087
    '''
1088
    exprs = lists.mk_seq(exprs)
1089
    
1090
    # Parse exprs
1091
    old_exprs = exprs[:]
1092
    exprs = []
1093
    cols = []
1094
    for i, expr in enumerate(old_exprs):
1095
        expr = sql_gen.as_Col(expr, table)
1096
        
1097
        # Handle nullable columns
1098
        if ensure_not_null_:
1099
            try: expr = sql_gen.ensure_not_null(db, expr)
1100
            except KeyError: pass # unknown type, so just create plain index
1101
        
1102
        # Extract col
1103
        expr = copy.deepcopy(expr) # don't modify input!
1104
        if isinstance(expr, sql_gen.FunctionCall):
1105
            col = expr.args[0]
1106
            expr = sql_gen.Expr(expr)
1107
        else: col = expr
1108
        assert isinstance(col, sql_gen.Col)
1109
        
1110
        # Extract table
1111
        if table == None:
1112
            assert sql_gen.is_table_col(col)
1113
            table = col.table
1114
        
1115
        col.table = None
1116
        
1117
        exprs.append(expr)
1118
        cols.append(col)
1119
    
1120
    table = sql_gen.as_Table(table)
1121
    
1122
    # Add index
1123
    str_ = 'CREATE'
1124
    if unique: str_ += ' UNIQUE'
1125
    str_ += ' INDEX ON '+table.to_str(db)+' ('+(
1126
        ', '.join((v.to_str(db) for v in exprs)))+')'
1127
    run_query(db, str_, recover=True, cacheable=True, log_level=3)
1128

    
1129
def add_index_col(db, col, suffix, expr, nullable=True):
1130
    if sql_gen.index_col(col) != None: return # already has index col
1131
    
1132
    new_col = sql_gen.suffixed_col(col, suffix)
1133
    
1134
    # Add column
1135
    new_typed_col = sql_gen.TypedCol(new_col.name,
1136
        db.col_info(col, cacheable=nullable).type)
1137
        # if not nullable, col_info will be changed later by add_not_null()
1138
    add_col(db, col.table, new_typed_col, comment='src: '+repr(col),
1139
        log_level=3)
1140
    new_col.name = new_typed_col.name # propagate any renaming
1141
    
1142
    update(db, col.table, [(new_col, expr)], in_place=True, cacheable_=nullable,
1143
        cacheable=True, log_level=3)
1144
    if not nullable: add_not_null(db, new_col)
1145
    add_index(db, new_col)
1146
    
1147
    col.table.index_cols[col.name] = new_col.name
1148

    
1149
# Controls when ensure_not_null() will use index columns
1150
not_null_index_cols_min_rows = 0 # rows; initially always use index columns
1151

    
1152
def ensure_not_null(db, col):
1153
    '''For params, see sql_gen.ensure_not_null()'''
1154
    expr = sql_gen.ensure_not_null(db, col)
1155
    
1156
    # If a nullable column in a temp table, add separate index column instead.
1157
    # Note that for small datasources, this adds 6-25% to the total import time.
1158
    if (sql_gen.is_temp_col(col) and isinstance(expr, sql_gen.EnsureNotNull)
1159
        and table_row_count(db, col.table) >= not_null_index_cols_min_rows):
1160
        add_index_col(db, col, '::NOT NULL', expr, nullable=False)
1161
        expr = sql_gen.index_col(col)
1162
    
1163
    return expr
1164

    
1165
already_indexed = object() # tells add_indexes() the pkey has already been added
1166

    
1167
def add_indexes(db, table, has_pkey=True):
1168
    '''Adds an index on all columns in a table.
1169
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1170
        index should be added on the first column.
1171
        * If already_indexed, the pkey is assumed to have already been added
1172
    '''
1173
    cols = table_cols(db, table)
1174
    if has_pkey:
1175
        if has_pkey is not already_indexed: add_pkey(db, table)
1176
        cols = cols[1:]
1177
    for col in cols: add_index(db, col, table)
1178

    
1179
#### Tables
1180

    
1181
### Maintenance
1182

    
1183
def analyze(db, table):
1184
    table = sql_gen.as_Table(table)
1185
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1186

    
1187
def autoanalyze(db, table):
1188
    if db.autoanalyze: analyze(db, table)
1189

    
1190
def vacuum(db, table):
1191
    table = sql_gen.as_Table(table)
1192
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1193
        log_level=3))
1194

    
1195
### Lifecycle
1196

    
1197
def drop_table(db, table):
1198
    table = sql_gen.as_Table(table)
1199
    return run_query(db, 'DROP TABLE IF EXISTS '+table.to_str(db)+' CASCADE')
1200

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

    
1245
def copy_table_struct(db, src, dest):
1246
    '''Creates a structure-only copy of a table. (Does not copy data.)'''
1247
    create_table(db, dest, has_pkey=False, col_indexes=False, like=src)
1248

    
1249
### Data
1250

    
1251
def truncate(db, table, schema='public', **kw_args):
1252
    '''For params, see run_query()'''
1253
    table = sql_gen.as_Table(table, schema)
1254
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1255

    
1256
def empty_temp(db, tables):
1257
    tables = lists.mk_seq(tables)
1258
    for table in tables: truncate(db, table, log_level=3)
1259

    
1260
def empty_db(db, schema='public', **kw_args):
1261
    '''For kw_args, see tables()'''
1262
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1263

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