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

    
535
##### Basic queries
536

    
537
def next_version(name):
538
    version = 1 # first existing name was version 0
539
    match = re.match(r'^(.*)#(\d+)$', name)
540
    if match:
541
        name, version = match.groups()
542
        version = int(version)+1
543
    return sql_gen.concat(name, '#'+str(version))
544

    
545
def lock_table(db, table, mode):
546
    table = sql_gen.as_Table(table)
547
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
548

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

    
592
order_by_pkey = object() # tells mk_select() to order by the pkey
593

    
594
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
595

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

    
681
def select(db, *args, **kw_args):
682
    '''For params, see mk_select() and run_query()'''
683
    recover = kw_args.pop('recover', None)
684
    cacheable = kw_args.pop('cacheable', True)
685
    log_level = kw_args.pop('log_level', 2)
686
    
687
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
688
        log_level=log_level)
689

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

    
797
def insert_select(db, table, *args, **kw_args):
798
    '''For params, see mk_insert_select() and run_query_into()
799
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
800
        values in
801
    '''
802
    returning = kw_args.get('returning', None)
803
    ignore = kw_args.get('ignore', False)
804
    
805
    into = kw_args.pop('into', None)
806
    if into != None: kw_args['embeddable'] = True
807
    recover = kw_args.pop('recover', None)
808
    if ignore: recover = True
809
    cacheable = kw_args.pop('cacheable', True)
810
    log_level = kw_args.pop('log_level', 2)
811
    
812
    rowcount_only = ignore and returning == None # keep NULL rows on server
813
    if rowcount_only: into = sql_gen.Table('rowcount')
814
    
815
    cur = run_query_into(db, mk_insert_select(db, table, *args, **kw_args),
816
        into, recover=recover, cacheable=cacheable, log_level=log_level)
817
    if rowcount_only: empty_temp(db, into)
818
    autoanalyze(db, table)
819
    return cur
820

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

    
823
def insert(db, table, row, *args, **kw_args):
824
    '''For params, see insert_select()'''
825
    if lists.is_seq(row): cols = None
826
    else:
827
        cols = row.keys()
828
        row = row.values()
829
    row = list(row) # ensure that "== []" works
830
    
831
    if row == []: query = None
832
    else: query = sql_gen.Values(row).to_str(db)
833
    
834
    return insert_select(db, table, cols, query, *args, **kw_args)
835

    
836
def mk_update(db, table, changes=None, cond=None, in_place=False,
837
    cacheable_=True):
838
    '''
839
    @param changes [(col, new_value),...]
840
        * container can be any iterable type
841
        * col: sql_gen.Code|str (for col name)
842
        * new_value: sql_gen.Code|literal value
843
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
844
    @param in_place If set, locks the table and updates rows in place.
845
        This avoids creating dead rows in PostgreSQL.
846
        * cond must be None
847
    @param cacheable_ Whether column structure information used to generate the
848
        query can be cached
849
    @return str query
850
    '''
851
    table = sql_gen.as_Table(table)
852
    changes = [(sql_gen.to_name_only_col(c, table), sql_gen.as_Value(v))
853
        for c, v in changes]
854
    
855
    if in_place:
856
        assert cond == None
857
        
858
        query = 'ALTER TABLE '+table.to_str(db)+'\n'
859
        query += ',\n'.join(('ALTER COLUMN '+c.to_str(db)+' TYPE '
860
            +db.col_info(sql_gen.with_default_table(c, table), cacheable_).type
861
            +'\nUSING '+v.to_str(db) for c, v in changes))
862
    else:
863
        query = 'UPDATE '+table.to_str(db)+'\nSET\n'
864
        query += ',\n'.join((c.to_str(db)+' = '+v.to_str(db)
865
            for c, v in changes))
866
        if cond != None: query += '\nWHERE\n'+cond.to_str(db)
867
    
868
    return query
869

    
870
def update(db, table, *args, **kw_args):
871
    '''For params, see mk_update() and run_query()'''
872
    recover = kw_args.pop('recover', None)
873
    cacheable = kw_args.pop('cacheable', False)
874
    log_level = kw_args.pop('log_level', 2)
875
    
876
    cur = run_query(db, mk_update(db, table, *args, **kw_args), recover,
877
        cacheable, log_level=log_level)
878
    autoanalyze(db, table)
879
    return cur
880

    
881
def last_insert_id(db):
882
    module = util.root_module(db.db)
883
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
884
    elif module == 'MySQLdb': return db.insert_id()
885
    else: return None
886

    
887
def mk_flatten_mapping(db, into, cols, preserve=[], as_items=False):
888
    '''Creates a mapping from original column names (which may have collisions)
889
    to names that will be distinct among the columns' tables.
890
    This is meant to be used for several tables that are being joined together.
891
    @param cols The columns to combine. Duplicates will be removed.
892
    @param into The table for the new columns.
893
    @param preserve [sql_gen.Col...] Columns not to rename. Note that these
894
        columns will be included in the mapping even if they are not in cols.
895
        The tables of the provided Col objects will be changed to into, so make
896
        copies of them if you want to keep the original tables.
897
    @param as_items Whether to return a list of dict items instead of a dict
898
    @return dict(orig_col=new_col, ...)
899
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
900
        * new_col: sql_gen.Col(orig_col_name, into)
901
        * All mappings use the into table so its name can easily be
902
          changed for all columns at once
903
    '''
904
    cols = lists.uniqify(cols)
905
    
906
    items = []
907
    for col in preserve:
908
        orig_col = copy.copy(col)
909
        col.table = into
910
        items.append((orig_col, col))
911
    preserve = set(preserve)
912
    for col in cols:
913
        if col not in preserve:
914
            items.append((col, sql_gen.Col(str(col), into, col.srcs)))
915
    
916
    if not as_items: items = dict(items)
917
    return items
918

    
919
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
920
    '''For params, see mk_flatten_mapping()
921
    @return See return value of mk_flatten_mapping()
922
    '''
923
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
924
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
925
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
926
        into=into)
927
    return dict(items)
928

    
929
##### Database structure introspection
930

    
931
#### Tables
932

    
933
def tables(db, schema_like='public', table_like='%', exact=False):
934
    if exact: compare = '='
935
    else: compare = 'LIKE'
936
    
937
    module = util.root_module(db.db)
938
    if module == 'psycopg2':
939
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
940
            ('tablename', sql_gen.CompareCond(table_like, compare))]
941
        return values(select(db, 'pg_tables', ['tablename'], conds,
942
            order_by='tablename', log_level=4))
943
    elif module == 'MySQLdb':
944
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
945
            , cacheable=True, log_level=4))
946
    else: raise NotImplementedError("Can't list tables for "+module+' database')
947

    
948
def table_exists(db, table):
949
    table = sql_gen.as_Table(table)
950
    return list(tables(db, table.schema, table.name, exact=True)) != []
951

    
952
def table_row_count(db, table, recover=None):
953
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
954
        order_by=None, start=0), recover=recover, log_level=3))
955

    
956
def table_cols(db, table, recover=None):
957
    return list(col_names(select(db, table, limit=0, order_by=None,
958
        recover=recover, log_level=4)))
959

    
960
def pkey(db, table, recover=None):
961
    '''Assumed to be first column in table'''
962
    return table_cols(db, table, recover)[0]
963

    
964
not_null_col = 'not_null_col'
965

    
966
def table_not_null_col(db, table, recover=None):
967
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
968
    if not_null_col in table_cols(db, table, recover): return not_null_col
969
    else: return pkey(db, table, recover)
970

    
971
def index_cols(db, table, index):
972
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
973
    automatically created. When you don't know whether something is a UNIQUE
974
    constraint or a UNIQUE index, use this function.'''
975
    module = util.root_module(db.db)
976
    if module == 'psycopg2':
977
        return list(values(run_query(db, '''\
978
SELECT attname
979
FROM
980
(
981
        SELECT attnum, attname
982
        FROM pg_index
983
        JOIN pg_class index ON index.oid = indexrelid
984
        JOIN pg_class table_ ON table_.oid = indrelid
985
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
986
        WHERE
987
            table_.relname = '''+db.esc_value(table)+'''
988
            AND index.relname = '''+db.esc_value(index)+'''
989
    UNION
990
        SELECT attnum, attname
991
        FROM
992
        (
993
            SELECT
994
                indrelid
995
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
996
                    AS indkey
997
            FROM pg_index
998
            JOIN pg_class index ON index.oid = indexrelid
999
            JOIN pg_class table_ ON table_.oid = indrelid
1000
            WHERE
1001
                table_.relname = '''+db.esc_value(table)+'''
1002
                AND index.relname = '''+db.esc_value(index)+'''
1003
        ) s
1004
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
1005
) s
1006
ORDER BY attnum
1007
'''
1008
            , cacheable=True, log_level=4)))
1009
    else: raise NotImplementedError("Can't list index columns for "+module+
1010
        ' database')
1011

    
1012
def constraint_cols(db, table, constraint):
1013
    module = util.root_module(db.db)
1014
    if module == 'psycopg2':
1015
        return list(values(run_query(db, '''\
1016
SELECT attname
1017
FROM pg_constraint
1018
JOIN pg_class ON pg_class.oid = conrelid
1019
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
1020
WHERE
1021
    relname = '''+db.esc_value(table)+'''
1022
    AND conname = '''+db.esc_value(constraint)+'''
1023
ORDER BY attnum
1024
'''
1025
            )))
1026
    else: raise NotImplementedError("Can't list constraint columns for "+module+
1027
        ' database')
1028

    
1029
#### Functions
1030

    
1031
def function_exists(db, function):
1032
    function = sql_gen.as_Function(function)
1033
    
1034
    info_table = sql_gen.Table('routines', 'information_schema')
1035
    conds = [('routine_name', function.name)]
1036
    schema = function.schema
1037
    if schema != None: conds.append(('routine_schema', schema))
1038
    # Exclude trigger functions, since they cannot be called directly
1039
    conds.append(('data_type', sql_gen.CompareCond('trigger', '!=')))
1040
    
1041
    return list(values(select(db, info_table, ['routine_name'], conds,
1042
        order_by='routine_schema', limit=1, log_level=4))) != []
1043
        # TODO: order_by search_path schema order
1044

    
1045
##### Structural changes
1046

    
1047
#### Columns
1048

    
1049
def add_col(db, table, col, comment=None, **kw_args):
1050
    '''
1051
    @param col TypedCol Name may be versioned, so be sure to propagate any
1052
        renaming back to any source column for the TypedCol.
1053
    @param comment None|str SQL comment used to distinguish columns of the same
1054
        name from each other when they contain different data, to allow the
1055
        ADD COLUMN query to be cached. If not set, query will not be cached.
1056
    '''
1057
    assert isinstance(col, sql_gen.TypedCol)
1058
    
1059
    while True:
1060
        str_ = 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '+col.to_str(db)
1061
        if comment != None: str_ += ' '+sql_gen.esc_comment(comment)
1062
        
1063
        try:
1064
            run_query(db, str_, recover=True, cacheable=True, **kw_args)
1065
            break
1066
        except DuplicateException:
1067
            col.name = next_version(col.name)
1068
            # try again with next version of name
1069

    
1070
def add_not_null(db, col):
1071
    table = col.table
1072
    col = sql_gen.to_name_only_col(col)
1073
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1074
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1075

    
1076
row_num_col = '_row_num'
1077

    
1078
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1079
    constraints='PRIMARY KEY')
1080

    
1081
def add_row_num(db, table):
1082
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1083
    be the primary key.'''
1084
    add_col(db, table, row_num_typed_col, log_level=3)
1085

    
1086
#### Indexes
1087

    
1088
def add_pkey(db, table, cols=None, recover=None):
1089
    '''Adds a primary key.
1090
    @param cols [sql_gen.Col,...] The columns in the primary key.
1091
        Defaults to the first column in the table.
1092
    @pre The table must not already have a primary key.
1093
    '''
1094
    table = sql_gen.as_Table(table)
1095
    if cols == None: cols = [pkey(db, table, recover)]
1096
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1097
    
1098
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1099
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1100
        log_ignore_excs=(DuplicateException,))
1101

    
1102
def add_index(db, exprs, table=None, unique=False, ensure_not_null_=True):
1103
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
1104
    Currently, only function calls are supported as expressions.
1105
    @param ensure_not_null_ If set, translates NULL values to sentinel values.
1106
        This allows indexes to be used for comparisons where NULLs are equal.
1107
    '''
1108
    exprs = lists.mk_seq(exprs)
1109
    
1110
    # Parse exprs
1111
    old_exprs = exprs[:]
1112
    exprs = []
1113
    cols = []
1114
    for i, expr in enumerate(old_exprs):
1115
        expr = sql_gen.as_Col(expr, table)
1116
        
1117
        # Handle nullable columns
1118
        if ensure_not_null_:
1119
            try: expr = sql_gen.ensure_not_null(db, expr)
1120
            except KeyError: pass # unknown type, so just create plain index
1121
        
1122
        # Extract col
1123
        expr = copy.deepcopy(expr) # don't modify input!
1124
        if isinstance(expr, sql_gen.FunctionCall):
1125
            col = expr.args[0]
1126
            expr = sql_gen.Expr(expr)
1127
        else: col = expr
1128
        assert isinstance(col, sql_gen.Col)
1129
        
1130
        # Extract table
1131
        if table == None:
1132
            assert sql_gen.is_table_col(col)
1133
            table = col.table
1134
        
1135
        col.table = None
1136
        
1137
        exprs.append(expr)
1138
        cols.append(col)
1139
    
1140
    table = sql_gen.as_Table(table)
1141
    
1142
    # Add index
1143
    str_ = 'CREATE'
1144
    if unique: str_ += ' UNIQUE'
1145
    str_ += ' INDEX ON '+table.to_str(db)+' ('+(
1146
        ', '.join((v.to_str(db) for v in exprs)))+')'
1147
    run_query(db, str_, recover=True, cacheable=True, log_level=3)
1148

    
1149
already_indexed = object() # tells add_indexes() the pkey has already been added
1150

    
1151
def add_indexes(db, table, has_pkey=True):
1152
    '''Adds an index on all columns in a table.
1153
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1154
        index should be added on the first column.
1155
        * If already_indexed, the pkey is assumed to have already been added
1156
    '''
1157
    cols = table_cols(db, table)
1158
    if has_pkey:
1159
        if has_pkey is not already_indexed: add_pkey(db, table)
1160
        cols = cols[1:]
1161
    for col in cols: add_index(db, col, table)
1162

    
1163
#### Tables
1164

    
1165
### Maintenance
1166

    
1167
def analyze(db, table):
1168
    table = sql_gen.as_Table(table)
1169
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1170

    
1171
def autoanalyze(db, table):
1172
    if db.autoanalyze: analyze(db, table)
1173

    
1174
def vacuum(db, table):
1175
    table = sql_gen.as_Table(table)
1176
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1177
        log_level=3))
1178

    
1179
### Lifecycle
1180

    
1181
def drop(db, type_, name):
1182
    name = sql_gen.as_Name(name)
1183
    run_query(db, 'DROP '+type_+' IF EXISTS '+name.to_str(db)+' CASCADE')
1184

    
1185
def drop_table(db, table): drop(db, 'TABLE', table)
1186

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

    
1231
def copy_table_struct(db, src, dest):
1232
    '''Creates a structure-only copy of a table. (Does not copy data.)'''
1233
    create_table(db, dest, has_pkey=False, col_indexes=False, like=src)
1234

    
1235
### Data
1236

    
1237
def truncate(db, table, schema='public', **kw_args):
1238
    '''For params, see run_query()'''
1239
    table = sql_gen.as_Table(table, schema)
1240
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1241

    
1242
def empty_temp(db, tables):
1243
    tables = lists.mk_seq(tables)
1244
    for table in tables: truncate(db, table, log_level=3)
1245

    
1246
def empty_db(db, schema='public', **kw_args):
1247
    '''For kw_args, see tables()'''
1248
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1249

    
1250
def distinct_table(db, table, distinct_on):
1251
    '''Creates a copy of a temp table which is distinct on the given columns.
1252
    The old and new tables will both get an index on these columns, to
1253
    facilitate merge joins.
1254
    @param distinct_on If empty, creates a table with one row. This is useful if
1255
        your distinct_on columns are all literal values.
1256
    @return The new table.
1257
    '''
1258
    new_table = sql_gen.suffixed_table(table, '_distinct')
1259
    
1260
    copy_table_struct(db, table, new_table)
1261
    
1262
    limit = None
1263
    if distinct_on == []: limit = 1 # one sample row
1264
    else:
1265
        add_index(db, distinct_on, new_table, unique=True)
1266
        add_index(db, distinct_on, table) # for join optimization
1267
    
1268
    insert_select(db, new_table, None, mk_select(db, table, start=0,
1269
        limit=limit), ignore=True)
1270
    analyze(db, new_table)
1271
    
1272
    return new_table
(24-24/37)