Project

General

Profile

1
# Database access
2

    
3
import copy
4
import re
5
import warnings
6

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

    
17
##### Exceptions
18

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

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

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

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

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

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

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

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

    
68
class NameException(DbException): pass
69

    
70
class DuplicateKeyException(ConstraintException): pass
71

    
72
class NullValueException(ConstraintException): pass
73

    
74
class InvalidValueException(ExceptionWithValue): pass
75

    
76
class DuplicateException(ExceptionWithNameType): pass
77

    
78
class EmptyRowException(DbException): pass
79

    
80
##### Warnings
81

    
82
class DbWarning(UserWarning): pass
83

    
84
##### Result retrieval
85

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

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

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

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

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

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

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

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

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

    
111
##### Escaping
112

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

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

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

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

    
131
##### Database connections
132

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

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

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

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

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

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

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

    
461
connect = DbConn
462

    
463
##### Recoverable querying
464

    
465
def with_savepoint(db, func): return db.with_savepoint(func)
466

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

    
527
##### Basic queries
528

    
529
def next_version(name):
530
    version = 1 # first existing name was version 0
531
    match = re.match(r'^(.*)#(\d+)$', name)
532
    if match:
533
        name, version = match.groups()
534
        version = int(version)+1
535
    return sql_gen.concat(name, '#'+str(version))
536

    
537
def lock_table(db, table, mode):
538
    table = sql_gen.as_Table(table)
539
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
540

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

    
584
order_by_pkey = object() # tells mk_select() to order by the pkey
585

    
586
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
587

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

    
673
def select(db, *args, **kw_args):
674
    '''For params, see mk_select() and run_query()'''
675
    recover = kw_args.pop('recover', None)
676
    cacheable = kw_args.pop('cacheable', True)
677
    log_level = kw_args.pop('log_level', 2)
678
    
679
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
680
        log_level=log_level)
681

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

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

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

    
815
def insert(db, table, row, *args, **kw_args):
816
    '''For params, see insert_select()'''
817
    if lists.is_seq(row): cols = None
818
    else:
819
        cols = row.keys()
820
        row = row.values()
821
    row = list(row) # ensure that "== []" works
822
    
823
    if row == []: query = None
824
    else: query = sql_gen.Values(row).to_str(db)
825
    
826
    return insert_select(db, table, cols, query, *args, **kw_args)
827

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

    
862
def update(db, table, *args, **kw_args):
863
    '''For params, see mk_update() and run_query()'''
864
    recover = kw_args.pop('recover', None)
865
    cacheable = kw_args.pop('cacheable', False)
866
    log_level = kw_args.pop('log_level', 2)
867
    
868
    cur = run_query(db, mk_update(db, table, *args, **kw_args), recover,
869
        cacheable, log_level=log_level)
870
    autoanalyze(db, table)
871
    return cur
872

    
873
def last_insert_id(db):
874
    module = util.root_module(db.db)
875
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
876
    elif module == 'MySQLdb': return db.insert_id()
877
    else: return None
878

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

    
911
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
912
    '''For params, see mk_flatten_mapping()
913
    @return See return value of mk_flatten_mapping()
914
    '''
915
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
916
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
917
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
918
        into=into)
919
    return dict(items)
920

    
921
##### Database structure introspection
922

    
923
#### Tables
924

    
925
def tables(db, schema_like='public', table_like='%', exact=False):
926
    if exact: compare = '='
927
    else: compare = 'LIKE'
928
    
929
    module = util.root_module(db.db)
930
    if module == 'psycopg2':
931
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
932
            ('tablename', sql_gen.CompareCond(table_like, compare))]
933
        return values(select(db, 'pg_tables', ['tablename'], conds,
934
            order_by='tablename', log_level=4))
935
    elif module == 'MySQLdb':
936
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
937
            , cacheable=True, log_level=4))
938
    else: raise NotImplementedError("Can't list tables for "+module+' database')
939

    
940
def table_exists(db, table):
941
    table = sql_gen.as_Table(table)
942
    return list(tables(db, table.schema, table.name, exact=True)) != []
943

    
944
def table_row_count(db, table, recover=None):
945
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
946
        order_by=None, start=0), recover=recover, log_level=3))
947

    
948
def table_cols(db, table, recover=None):
949
    return list(col_names(select(db, table, limit=0, order_by=None,
950
        recover=recover, log_level=4)))
951

    
952
def pkey(db, table, recover=None):
953
    '''Assumed to be first column in table'''
954
    return table_cols(db, table, recover)[0]
955

    
956
not_null_col = 'not_null_col'
957

    
958
def table_not_null_col(db, table, recover=None):
959
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
960
    if not_null_col in table_cols(db, table, recover): return not_null_col
961
    else: return pkey(db, table, recover)
962

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

    
1004
def constraint_cols(db, table, constraint):
1005
    module = util.root_module(db.db)
1006
    if module == 'psycopg2':
1007
        return list(values(run_query(db, '''\
1008
SELECT attname
1009
FROM pg_constraint
1010
JOIN pg_class ON pg_class.oid = conrelid
1011
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
1012
WHERE
1013
    relname = '''+db.esc_value(table)+'''
1014
    AND conname = '''+db.esc_value(constraint)+'''
1015
ORDER BY attnum
1016
'''
1017
            )))
1018
    else: raise NotImplementedError("Can't list constraint columns for "+module+
1019
        ' database')
1020

    
1021
#### Functions
1022

    
1023
def function_exists(db, function):
1024
    function = sql_gen.as_Function(function)
1025
    
1026
    info_table = sql_gen.Table('routines', 'information_schema')
1027
    conds = [('routine_name', function.name)]
1028
    schema = function.schema
1029
    if schema != None: conds.append(('routine_schema', schema))
1030
    # Exclude trigger functions, since they cannot be called directly
1031
    conds.append(('data_type', sql_gen.CompareCond('trigger', '!=')))
1032
    
1033
    return list(values(select(db, info_table, ['routine_name'], conds,
1034
        order_by='routine_schema', limit=1, log_level=4))) != []
1035
        # TODO: order_by search_path schema order
1036

    
1037
##### Structural changes
1038

    
1039
#### Columns
1040

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

    
1062
def add_not_null(db, col):
1063
    table = col.table
1064
    col = sql_gen.to_name_only_col(col)
1065
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1066
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1067

    
1068
row_num_col = '_row_num'
1069

    
1070
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1071
    constraints='PRIMARY KEY')
1072

    
1073
def add_row_num(db, table):
1074
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1075
    be the primary key.'''
1076
    add_col(db, table, row_num_typed_col, log_level=3)
1077

    
1078
#### Indexes
1079

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

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

    
1141
already_indexed = object() # tells add_indexes() the pkey has already been added
1142

    
1143
def add_indexes(db, table, has_pkey=True):
1144
    '''Adds an index on all columns in a table.
1145
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1146
        index should be added on the first column.
1147
        * If already_indexed, the pkey is assumed to have already been added
1148
    '''
1149
    cols = table_cols(db, table)
1150
    if has_pkey:
1151
        if has_pkey is not already_indexed: add_pkey(db, table)
1152
        cols = cols[1:]
1153
    for col in cols: add_index(db, col, table)
1154

    
1155
#### Tables
1156

    
1157
### Maintenance
1158

    
1159
def analyze(db, table):
1160
    table = sql_gen.as_Table(table)
1161
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1162

    
1163
def autoanalyze(db, table):
1164
    if db.autoanalyze: analyze(db, table)
1165

    
1166
def vacuum(db, table):
1167
    table = sql_gen.as_Table(table)
1168
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1169
        log_level=3))
1170

    
1171
### Lifecycle
1172

    
1173
def drop_table(db, table):
1174
    table = sql_gen.as_Table(table)
1175
    return run_query(db, 'DROP TABLE IF EXISTS '+table.to_str(db)+' CASCADE')
1176

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

    
1221
def copy_table_struct(db, src, dest):
1222
    '''Creates a structure-only copy of a table. (Does not copy data.)'''
1223
    create_table(db, dest, has_pkey=False, col_indexes=False, like=src)
1224

    
1225
### Data
1226

    
1227
def truncate(db, table, schema='public', **kw_args):
1228
    '''For params, see run_query()'''
1229
    table = sql_gen.as_Table(table, schema)
1230
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1231

    
1232
def empty_temp(db, tables):
1233
    tables = lists.mk_seq(tables)
1234
    for table in tables: truncate(db, table, log_level=3)
1235

    
1236
def empty_db(db, schema='public', **kw_args):
1237
    '''For kw_args, see tables()'''
1238
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1239

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