Project

General

Profile

1
# Database access
2

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

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

    
19
##### Exceptions
20

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

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

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

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

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

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

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

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

    
70
class NameException(DbException): pass
71

    
72
class DuplicateKeyException(ConstraintException): pass
73

    
74
class NullValueException(ConstraintException): pass
75

    
76
class InvalidValueException(ExceptionWithValue): pass
77

    
78
class DuplicateException(ExceptionWithNameType): pass
79

    
80
class EmptyRowException(DbException): pass
81

    
82
##### Warnings
83

    
84
class DbWarning(UserWarning): pass
85

    
86
##### Result retrieval
87

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

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

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

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

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

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

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

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

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

    
113
##### Escaping
114

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

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

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

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

    
133
##### Database connections
134

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

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

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

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

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

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

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

    
471
connect = DbConn
472

    
473
##### Recoverable querying
474

    
475
def with_savepoint(db, func): return db.with_savepoint(func)
476

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

    
533
##### Basic queries
534

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

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

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

    
590
order_by_pkey = object() # tells mk_select() to order by the pkey
591

    
592
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
593

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

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

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

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

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

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

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

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

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

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

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

    
927
##### Database structure introspection
928

    
929
#### Tables
930

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

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

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

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

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

    
962
not_null_col = 'not_null_col'
963

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

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

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

    
1027
#### Functions
1028

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

    
1043
##### Structural changes
1044

    
1045
#### Columns
1046

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

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

    
1074
row_num_col = '_row_num'
1075

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

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

    
1084
#### Indexes
1085

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

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

    
1147
already_indexed = object() # tells add_indexes() the pkey has already been added
1148

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

    
1161
#### Tables
1162

    
1163
### Maintenance
1164

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

    
1169
def autoanalyze(db, table):
1170
    if db.autoanalyze: analyze(db, table)
1171

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

    
1177
### Lifecycle
1178

    
1179
def drop_table(db, table):
1180
    table = sql_gen.as_Table(table)
1181
    return run_query(db, 'DROP TABLE IF EXISTS '+table.to_str(db)+' CASCADE')
1182

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

    
1227
def copy_table_struct(db, src, dest):
1228
    '''Creates a structure-only copy of a table. (Does not copy data.)'''
1229
    create_table(db, dest, has_pkey=False, col_indexes=False, like=src)
1230

    
1231
### Data
1232

    
1233
def truncate(db, table, schema='public', **kw_args):
1234
    '''For params, see run_query()'''
1235
    table = sql_gen.as_Table(table, schema)
1236
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1237

    
1238
def empty_temp(db, tables):
1239
    tables = lists.mk_seq(tables)
1240
    for table in tables: truncate(db, table, log_level=3)
1241

    
1242
def empty_db(db, schema='public', **kw_args):
1243
    '''For kw_args, see tables()'''
1244
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1245

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