Project

General

Profile

1
# Database access
2

    
3
import copy
4
import re
5
import time
6
import warnings
7

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

    
19
##### Exceptions
20

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

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

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

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

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

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

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

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

    
70
class NameException(DbException): pass
71

    
72
class DuplicateKeyException(ConstraintException): pass
73

    
74
class NullValueException(ConstraintException): pass
75

    
76
class InvalidValueException(ExceptionWithValue): pass
77

    
78
class DuplicateException(ExceptionWithNameType): pass
79

    
80
class EmptyRowException(DbException): pass
81

    
82
##### Warnings
83

    
84
class DbWarning(UserWarning): pass
85

    
86
##### Result retrieval
87

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

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

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

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

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

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

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

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

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

    
113
##### Escaping
114

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

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

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

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

    
133
##### Database connections
134

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

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

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

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

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

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

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

    
473
connect = DbConn
474

    
475
##### Recoverable querying
476

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

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

    
538
##### Basic queries
539

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

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

    
556
def next_version(name):
557
    version = 1 # first existing name was version 0
558
    match = re.match(r'^(.*)#(\d+)$', name)
559
    if match:
560
        name, version = match.groups()
561
        version = int(version)+1
562
    return sql_gen.concat(name, '#'+str(version))
563

    
564
def lock_table(db, table, mode):
565
    table = sql_gen.as_Table(table)
566
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
567

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

    
611
order_by_pkey = object() # tells mk_select() to order by the pkey
612

    
613
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
614

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

    
700
def select(db, *args, **kw_args):
701
    '''For params, see mk_select() and run_query()'''
702
    recover = kw_args.pop('recover', None)
703
    cacheable = kw_args.pop('cacheable', True)
704
    log_level = kw_args.pop('log_level', 2)
705
    
706
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
707
        log_level=log_level)
708

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

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

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

    
842
def insert(db, table, row, *args, **kw_args):
843
    '''For params, see insert_select()'''
844
    if lists.is_seq(row): cols = None
845
    else:
846
        cols = row.keys()
847
        row = row.values()
848
    row = list(row) # ensure that "== []" works
849
    
850
    if row == []: query = None
851
    else: query = sql_gen.Values(row).to_str(db)
852
    
853
    return insert_select(db, table, cols, query, *args, **kw_args)
854

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

    
889
def update(db, table, *args, **kw_args):
890
    '''For params, see mk_update() and run_query()'''
891
    recover = kw_args.pop('recover', None)
892
    cacheable = kw_args.pop('cacheable', False)
893
    log_level = kw_args.pop('log_level', 2)
894
    
895
    cur = run_query(db, mk_update(db, table, *args, **kw_args), recover,
896
        cacheable, log_level=log_level)
897
    autoanalyze(db, table)
898
    return cur
899

    
900
def last_insert_id(db):
901
    module = util.root_module(db.db)
902
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
903
    elif module == 'MySQLdb': return db.insert_id()
904
    else: return None
905

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

    
938
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
939
    '''For params, see mk_flatten_mapping()
940
    @return See return value of mk_flatten_mapping()
941
    '''
942
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
943
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
944
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
945
        into=into)
946
    return dict(items)
947

    
948
##### Database structure introspection
949

    
950
#### Tables
951

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

    
967
def table_exists(db, table):
968
    table = sql_gen.as_Table(table)
969
    return list(tables(db, table.schema, table.name, exact=True)) != []
970

    
971
def table_row_count(db, table, recover=None):
972
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
973
        order_by=None, start=0), recover=recover, log_level=3))
974

    
975
def table_cols(db, table, recover=None):
976
    return list(col_names(select(db, table, limit=0, order_by=None,
977
        recover=recover, log_level=4)))
978

    
979
def pkey(db, table, recover=None):
980
    '''Assumed to be first column in table'''
981
    return table_cols(db, table, recover)[0]
982

    
983
not_null_col = 'not_null_col'
984

    
985
def table_not_null_col(db, table, recover=None):
986
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
987
    if not_null_col in table_cols(db, table, recover): return not_null_col
988
    else: return pkey(db, table, recover)
989

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

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

    
1048
#### Functions
1049

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

    
1064
##### Structural changes
1065

    
1066
#### Columns
1067

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

    
1089
def add_not_null(db, col):
1090
    table = col.table
1091
    col = sql_gen.to_name_only_col(col)
1092
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1093
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1094

    
1095
row_num_col = '_row_num'
1096

    
1097
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1098
    constraints='PRIMARY KEY')
1099

    
1100
def add_row_num(db, table):
1101
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1102
    be the primary key.'''
1103
    add_col(db, table, row_num_typed_col, log_level=3)
1104

    
1105
#### Indexes
1106

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

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

    
1168
already_indexed = object() # tells add_indexes() the pkey has already been added
1169

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

    
1182
#### Tables
1183

    
1184
### Maintenance
1185

    
1186
def analyze(db, table):
1187
    table = sql_gen.as_Table(table)
1188
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1189

    
1190
def autoanalyze(db, table):
1191
    if db.autoanalyze: analyze(db, table)
1192

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

    
1198
### Lifecycle
1199

    
1200
def drop(db, type_, name):
1201
    name = sql_gen.as_Name(name)
1202
    run_query(db, 'DROP '+type_+' IF EXISTS '+name.to_str(db)+' CASCADE')
1203

    
1204
def drop_table(db, table): drop(db, 'TABLE', table)
1205

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

    
1250
def copy_table_struct(db, src, dest):
1251
    '''Creates a structure-only copy of a table. (Does not copy data.)'''
1252
    create_table(db, dest, has_pkey=False, col_indexes=False, like=src)
1253

    
1254
### Data
1255

    
1256
def truncate(db, table, schema='public', **kw_args):
1257
    '''For params, see run_query()'''
1258
    table = sql_gen.as_Table(table, schema)
1259
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1260

    
1261
def empty_temp(db, tables):
1262
    tables = lists.mk_seq(tables)
1263
    for table in tables: truncate(db, table, log_level=3)
1264

    
1265
def empty_db(db, schema='public', **kw_args):
1266
    '''For kw_args, see tables()'''
1267
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1268

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