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: '
41
            +strings.as_tt(strings.ustr(name)), cause)
42
        self.name = name
43

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

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

    
57
class ConstraintException(DbException):
58
    def __init__(self, name, cond, cols, cause=None):
59
        msg = 'Violated '+strings.as_tt(name)+' constraint'
60
        if cond != None: msg += ' with condition '+strings.as_tt(cond)
61
        if cols != []: msg += ' on columns: '+strings.as_tt(', '.join(cols))
62
        DbException.__init__(self, msg, cause)
63
        self.name = name
64
        self.cond = cond
65
        self.cols = cols
66

    
67
class MissingCastException(DbException):
68
    def __init__(self, type_, col=None, cause=None):
69
        msg = 'Missing cast to type '+strings.as_tt(type_)
70
        if col != None: msg += ' on column: '+strings.as_tt(col)
71
        DbException.__init__(self, msg, cause)
72
        self.type = type_
73
        self.col = col
74

    
75
class NameException(DbException): pass
76

    
77
class DuplicateKeyException(ConstraintException): pass
78

    
79
class NullValueException(ConstraintException): pass
80

    
81
class CheckException(ConstraintException): pass
82

    
83
class InvalidValueException(ExceptionWithValue): pass
84

    
85
class DuplicateException(ExceptionWithNameType): pass
86

    
87
class DoesNotExistException(ExceptionWithNameType): pass
88

    
89
class EmptyRowException(DbException): pass
90

    
91
##### Warnings
92

    
93
class DbWarning(UserWarning): pass
94

    
95
##### Result retrieval
96

    
97
def col_names(cur): return (col[0] for col in cur.description)
98

    
99
def rows(cur): return iter(lambda: cur.fetchone(), None)
100

    
101
def consume_rows(cur):
102
    '''Used to fetch all rows so result will be cached'''
103
    iters.consume_iter(rows(cur))
104

    
105
def next_row(cur): return rows(cur).next()
106

    
107
def row(cur):
108
    row_ = next_row(cur)
109
    consume_rows(cur)
110
    return row_
111

    
112
def next_value(cur): return next_row(cur)[0]
113

    
114
def value(cur): return row(cur)[0]
115

    
116
def values(cur): return iters.func_iter(lambda: next_value(cur))
117

    
118
def value_or_none(cur):
119
    try: return value(cur)
120
    except StopIteration: return None
121

    
122
##### Escaping
123

    
124
def esc_name_by_module(module, name):
125
    if module == 'psycopg2' or module == None: quote = '"'
126
    elif module == 'MySQLdb': quote = '`'
127
    else: raise NotImplementedError("Can't escape name for "+module+' database')
128
    return sql_gen.esc_name(name, quote)
129

    
130
def esc_name_by_engine(engine, name, **kw_args):
131
    return esc_name_by_module(db_engines[engine][0], name, **kw_args)
132

    
133
def esc_name(db, name, **kw_args):
134
    return esc_name_by_module(util.root_module(db.db), name, **kw_args)
135

    
136
def qual_name(db, schema, table):
137
    def esc_name_(name): return esc_name(db, name)
138
    table = esc_name_(table)
139
    if schema != None: return esc_name_(schema)+'.'+table
140
    else: return table
141

    
142
##### Database connections
143

    
144
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
145

    
146
db_engines = {
147
    'MySQL': ('MySQLdb', {'password': 'passwd', 'database': 'db'}),
148
    'PostgreSQL': ('psycopg2', {}),
149
}
150

    
151
DatabaseErrors_set = set([DbException])
152
DatabaseErrors = tuple(DatabaseErrors_set)
153

    
154
def _add_module(module):
155
    DatabaseErrors_set.add(module.DatabaseError)
156
    global DatabaseErrors
157
    DatabaseErrors = tuple(DatabaseErrors_set)
158

    
159
def db_config_str(db_config):
160
    return db_config['engine']+' database '+db_config['database']
161

    
162
log_debug_none = lambda msg, level=2: None
163

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

    
495
connect = DbConn
496

    
497
##### Recoverable querying
498

    
499
def with_savepoint(db, func): return db.with_savepoint(func)
500

    
501
def run_query(db, query, recover=None, cacheable=False, log_level=2,
502
    log_ignore_excs=None, **kw_args):
503
    '''For params, see DbConn.run_query()'''
504
    if recover == None: recover = False
505
    if log_ignore_excs == None: log_ignore_excs = ()
506
    log_ignore_excs = tuple(log_ignore_excs)
507
    debug_msg_ref = [None]
508
    
509
    query = with_explain_comment(db, query)
510
    
511
    try:
512
        try:
513
            def run(): return db.run_query(query, cacheable, log_level,
514
                debug_msg_ref, **kw_args)
515
            if recover and not db.is_cached(query):
516
                return with_savepoint(db, run)
517
            else: return run() # don't need savepoint if cached
518
        except Exception, e:
519
            msg = strings.ustr(e.args[0])
520
            msg = re.sub(r'^(?:PL/Python: )?ValueError: ', r'', msg)
521
            
522
            match = re.match(r'^duplicate key value violates unique constraint '
523
                r'"(.+?)"', msg)
524
            if match:
525
                constraint, = match.groups()
526
                cols = []
527
                cond = None
528
                if recover: # need auto-rollback to run index_cols()
529
                    try:
530
                        cols = index_cols(db, constraint)
531
                        cond = index_cond(db, constraint)
532
                    except NotImplementedError: pass
533
                raise DuplicateKeyException(constraint, cond, cols, e)
534
            
535
            match = re.match(r'^null value in column "(.+?)" violates not-null'
536
                r' constraint', msg)
537
            if match:
538
                col, = match.groups()
539
                raise NullValueException('NOT NULL', None, [col], e)
540
            
541
            match = re.match(r'^new row for relation "(.+?)" violates check '
542
                r'constraint "(.+?)"', msg)
543
            if match:
544
                table, constraint = match.groups()
545
                constraint = sql_gen.Col(constraint, table)
546
                cond = None
547
                if recover: # need auto-rollback to run constraint_cond()
548
                    try: cond = constraint_cond(db, constraint)
549
                    except NotImplementedError: pass
550
                raise CheckException(constraint.to_str(db), cond, [], e)
551
            
552
            match = re.match(r'^(?:invalid input (?:syntax|value)\b.*?'
553
                r'|.+? out of range): "(.+?)"', msg)
554
            if match:
555
                value, = match.groups()
556
                raise InvalidValueException(strings.to_unicode(value), e)
557
            
558
            match = re.match(r'^column "(.+?)" is of type (.+?) but expression '
559
                r'is of type', msg)
560
            if match:
561
                col, type_ = match.groups()
562
                raise MissingCastException(type_, col, e)
563
            
564
            match = re.match(r'^could not determine polymorphic type because '
565
                r'input has type "unknown"', msg)
566
            if match: raise MissingCastException('text', None, e)
567
            
568
            match = re.match(r'^.+? types .+? and .+? cannot be matched', msg)
569
            if match: raise MissingCastException('text', None, e)
570
            
571
            typed_name_re = r'^(\S+) "(.+?)"(?: of relation ".+?")?'
572
            
573
            match = re.match(typed_name_re+r'.*? already exists', msg)
574
            if match:
575
                type_, name = match.groups()
576
                raise DuplicateException(type_, name, e)
577
            
578
            match = re.match(r'more than one (\S+) named ""(.+?)""', msg)
579
            if match:
580
                type_, name = match.groups()
581
                raise DuplicateException(type_, name, e)
582
            
583
            match = re.match(typed_name_re+r' does not exist', msg)
584
            if match:
585
                type_, name = match.groups()
586
                raise DoesNotExistException(type_, name, e)
587
            
588
            raise # no specific exception raised
589
    except log_ignore_excs:
590
        log_level += 2
591
        raise
592
    finally:
593
        if debug_msg_ref[0] != None: db.log_debug(debug_msg_ref[0], log_level)
594

    
595
##### Basic queries
596

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

    
602
def explain(db, query, **kw_args):
603
    '''
604
    For params, see run_query().
605
    '''
606
    kw_args.setdefault('log_level', 4)
607
    
608
    return strings.ustr(strings.join_lines(values(run_query(db,
609
        'EXPLAIN '+query, recover=True, cacheable=True, **kw_args))))
610
        # not a higher log_level because it's useful to see what query is being
611
        # run before it's executed, which EXPLAIN effectively provides
612

    
613
def has_comment(query): return query.endswith('*/')
614

    
615
def with_explain_comment(db, query, **kw_args):
616
    if db.autoexplain and not has_comment(query) and is_explainable(query):
617
        query += '\n'+sql_gen.esc_comment(' EXPLAIN:\n'
618
            +explain(db, query, **kw_args))
619
    return query
620

    
621
def next_version(name):
622
    version = 1 # first existing name was version 0
623
    match = re.match(r'^(.*)#(\d+)$', name)
624
    if match:
625
        name, version = match.groups()
626
        version = int(version)+1
627
    return sql_gen.concat(name, '#'+str(version))
628

    
629
def lock_table(db, table, mode):
630
    table = sql_gen.as_Table(table)
631
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
632

    
633
def run_query_into(db, query, into=None, add_pkey_=False, **kw_args):
634
    '''Outputs a query to a temp table.
635
    For params, see run_query().
636
    '''
637
    if into == None: return run_query(db, query, **kw_args)
638
    
639
    assert isinstance(into, sql_gen.Table)
640
    
641
    into.is_temp = True
642
    # "temporary tables cannot specify a schema name", so remove schema
643
    into.schema = None
644
    
645
    kw_args['recover'] = True
646
    kw_args.setdefault('log_ignore_excs', (DuplicateException,))
647
    
648
    temp = not db.debug_temp # tables are permanent in debug_temp mode
649
    
650
    # Create table
651
    while True:
652
        create_query = 'CREATE'
653
        if temp: create_query += ' TEMP'
654
        create_query += ' TABLE '+into.to_str(db)+' AS\n'+query
655
        
656
        try:
657
            cur = run_query(db, create_query, **kw_args)
658
                # CREATE TABLE AS sets rowcount to # rows in query
659
            break
660
        except DuplicateException, e:
661
            into.name = next_version(into.name)
662
            # try again with next version of name
663
    
664
    if add_pkey_: add_pkey(db, into)
665
    
666
    # According to the PostgreSQL doc, "The autovacuum daemon cannot access and
667
    # therefore cannot vacuum or analyze temporary tables. [...] if a temporary
668
    # table is going to be used in complex queries, it is wise to run ANALYZE on
669
    # the temporary table after it is populated."
670
    # (http://www.postgresql.org/docs/9.1/static/sql-createtable.html)
671
    # If into is not a temp table, ANALYZE is useful but not required.
672
    analyze(db, into)
673
    
674
    return cur
675

    
676
order_by_pkey = object() # tells mk_select() to order by the pkey
677

    
678
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
679

    
680
def mk_select(db, tables=None, fields=None, conds=None, distinct_on=[],
681
    limit=None, start=None, order_by=order_by_pkey, default_table=None,
682
    explain=True):
683
    '''
684
    @param tables The single table to select from, or a list of tables to join
685
        together, with tables after the first being sql_gen.Join objects
686
    @param fields Use None to select all fields in the table
687
    @param conds WHERE conditions: [(compare_left_side, compare_right_side),...]
688
        * container can be any iterable type
689
        * compare_left_side: sql_gen.Code|str (for col name)
690
        * compare_right_side: sql_gen.ValueCond|literal value
691
    @param distinct_on The columns to SELECT DISTINCT ON, or distinct_on_all to
692
        use all columns
693
    @return query
694
    '''
695
    # Parse tables param
696
    tables = lists.mk_seq(tables)
697
    tables = list(tables) # don't modify input! (list() copies input)
698
    table0 = sql_gen.as_Table(tables.pop(0)) # first table is separate
699
    
700
    # Parse other params
701
    if conds == None: conds = []
702
    elif dicts.is_dict(conds): conds = conds.items()
703
    conds = list(conds) # don't modify input! (list() copies input)
704
    assert limit == None or isinstance(limit, (int, long))
705
    assert start == None or isinstance(start, (int, long))
706
    if order_by is order_by_pkey:
707
        if table0 == None or distinct_on != []: order_by = None
708
        else: order_by = pkey_name(db, table0, recover=True)
709
    
710
    query = 'SELECT'
711
    
712
    def parse_col(col): return sql_gen.as_Col(col, default_table).to_str(db)
713
    
714
    # DISTINCT ON columns
715
    if distinct_on != []:
716
        query += '\nDISTINCT'
717
        if distinct_on is not distinct_on_all:
718
            query += ' ON ('+(', '.join(map(parse_col, distinct_on)))+')'
719
    
720
    # Columns
721
    if query.find('\n') >= 0: whitespace = '\n'
722
    else: whitespace = ' '
723
    if fields == None: query += whitespace+'*'
724
    else:
725
        assert fields != []
726
        if len(fields) > 1: whitespace = '\n'
727
        query += whitespace+('\n, '.join(map(parse_col, fields)))
728
    
729
    # Main table
730
    if query.find('\n') >= 0 or len(tables) > 0: whitespace = '\n'
731
    else: whitespace = ' '
732
    if table0 != None: query += whitespace+'FROM '+table0.to_str(db)
733
    
734
    # Add joins
735
    left_table = table0
736
    for join_ in tables:
737
        table = join_.table
738
        
739
        # Parse special values
740
        if join_.type_ is sql_gen.filter_out: # filter no match
741
            conds.append((sql_gen.Col(table_not_null_col(db, table), table),
742
                sql_gen.CompareCond(None, '~=')))
743
        
744
        query += '\n'+join_.to_str(db, left_table)
745
        
746
        left_table = table
747
    
748
    missing = True
749
    if conds != []:
750
        if len(conds) == 1: whitespace = ' '
751
        else: whitespace = '\n'
752
        query += '\n'+sql_gen.combine_conds([sql_gen.ColValueCond(l, r)
753
            .to_str(db) for l, r in conds], 'WHERE')
754
    if order_by != None:
755
        query += '\nORDER BY '+sql_gen.as_Col(order_by, table0).to_str(db)
756
    if limit != None: query += '\nLIMIT '+str(limit)
757
    if start != None:
758
        if start != 0: query += '\nOFFSET '+str(start)
759
    
760
    if explain: query = with_explain_comment(db, query)
761
    
762
    return query
763

    
764
def select(db, *args, **kw_args):
765
    '''For params, see mk_select() and run_query()'''
766
    recover = kw_args.pop('recover', None)
767
    cacheable = kw_args.pop('cacheable', True)
768
    log_level = kw_args.pop('log_level', 2)
769
    
770
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
771
        log_level=log_level)
772

    
773
def mk_insert_select(db, table, cols=None, select_query=None, returning=None,
774
    embeddable=False, ignore=False, src=None):
775
    '''
776
    @param returning str|None An inserted column (such as pkey) to return
777
    @param embeddable Whether the query should be embeddable as a nested SELECT.
778
        Warning: If you set this and cacheable=True when the query is run, the
779
        query will be fully cached, not just if it raises an exception.
780
    @param ignore Whether to ignore duplicate keys.
781
    @param src Will be included in the name of any created function, to help
782
        identify the data source in pg_stat_activity.
783
    '''
784
    table = sql_gen.remove_table_rename(sql_gen.as_Table(table))
785
    if cols == []: cols = None # no cols (all defaults) = unknown col names
786
    if cols != None: cols = [sql_gen.to_name_only_col(c, table) for c in cols]
787
    if select_query == None: select_query = 'DEFAULT VALUES'
788
    if returning != None: returning = sql_gen.as_Col(returning, table)
789
    
790
    first_line = 'INSERT INTO '+table.to_str(db)
791
    
792
    def mk_insert(select_query):
793
        query = first_line
794
        if cols != None:
795
            query += '\n('+(', '.join((c.to_str(db) for c in cols)))+')'
796
        query += '\n'+select_query
797
        
798
        if returning != None:
799
            returning_name_col = sql_gen.to_name_only_col(returning)
800
            query += '\nRETURNING '+returning_name_col.to_str(db)
801
        
802
        return query
803
    
804
    return_type = sql_gen.CustomCode('unknown')
805
    if returning != None: return_type = sql_gen.ColType(returning)
806
    
807
    if ignore:
808
        # Always return something to set the correct rowcount
809
        if returning == None: returning = sql_gen.NamedCol('NULL', None)
810
        
811
        embeddable = True # must use function
812
        
813
        if cols == None: row = [sql_gen.Col(sql_gen.all_cols, 'row')]
814
        else: row = [sql_gen.Col(c.name, 'row') for c in cols]
815
        
816
        query = sql_gen.RowExcIgnore(sql_gen.RowType(table), select_query,
817
            sql_gen.ReturnQuery(mk_insert(sql_gen.Values(row).to_str(db))),
818
            cols)
819
    else: query = mk_insert(select_query)
820
    
821
    if embeddable:
822
        # Create function
823
        function_name = sql_gen.clean_name(first_line)
824
        if src != None: function_name = src+': '+function_name
825
        while True:
826
            try:
827
                func = db.TempFunction(function_name)
828
                def_ = sql_gen.FunctionDef(func, sql_gen.SetOf(return_type),
829
                    query)
830
                
831
                run_query(db, def_.to_str(db), recover=True, cacheable=True,
832
                    log_ignore_excs=(DuplicateException,))
833
                break # this version was successful
834
            except DuplicateException, e:
835
                function_name = next_version(function_name)
836
                # try again with next version of name
837
        
838
        # Return query that uses function
839
        cols = None
840
        if returning != None: cols = [returning]
841
        func_table = sql_gen.NamedTable('f', sql_gen.FunctionCall(func), cols)
842
            # AS clause requires function alias
843
        return mk_select(db, func_table, order_by=None)
844
    
845
    return query
846

    
847
def insert_select(db, table, *args, **kw_args):
848
    '''For params, see mk_insert_select() and run_query_into()
849
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
850
        values in
851
    '''
852
    returning = kw_args.get('returning', None)
853
    ignore = kw_args.get('ignore', False)
854
    
855
    into = kw_args.pop('into', None)
856
    if into != None: kw_args['embeddable'] = True
857
    recover = kw_args.pop('recover', None)
858
    if ignore: recover = True
859
    cacheable = kw_args.pop('cacheable', True)
860
    log_level = kw_args.pop('log_level', 2)
861
    
862
    rowcount_only = ignore and returning == None # keep NULL rows on server
863
    if rowcount_only: into = sql_gen.Table('rowcount')
864
    
865
    cur = run_query_into(db, mk_insert_select(db, table, *args, **kw_args),
866
        into, recover=recover, cacheable=cacheable, log_level=log_level)
867
    if rowcount_only: empty_temp(db, into)
868
    autoanalyze(db, table)
869
    return cur
870

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

    
873
def insert(db, table, row, *args, **kw_args):
874
    '''For params, see insert_select()'''
875
    ignore = kw_args.pop('ignore', False)
876
    if ignore: kw_args.setdefault('recover', True)
877
    
878
    if lists.is_seq(row): cols = None
879
    else:
880
        cols = row.keys()
881
        row = row.values()
882
    row = list(row) # ensure that "== []" works
883
    
884
    if row == []: query = None
885
    else: query = sql_gen.Values(row).to_str(db)
886
    
887
    try: return insert_select(db, table, cols, query, *args, **kw_args)
888
    except (DuplicateKeyException, NullValueException):
889
        if not ignore: raise
890
        return None
891

    
892
def mk_update(db, table, changes=None, cond=None, in_place=False,
893
    cacheable_=True):
894
    '''
895
    @param changes [(col, new_value),...]
896
        * container can be any iterable type
897
        * col: sql_gen.Code|str (for col name)
898
        * new_value: sql_gen.Code|literal value
899
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
900
    @param in_place If set, locks the table and updates rows in place.
901
        This avoids creating dead rows in PostgreSQL.
902
        * cond must be None
903
    @param cacheable_ Whether column structure information used to generate the
904
        query can be cached
905
    @return str query
906
    '''
907
    table = sql_gen.as_Table(table)
908
    changes = [(sql_gen.to_name_only_col(c, table), sql_gen.as_Value(v))
909
        for c, v in changes]
910
    
911
    if in_place:
912
        assert cond == None
913
        
914
        def col_type(col):
915
            return sql_gen.canon_type(db.col_info(
916
                sql_gen.with_default_table(c, table), cacheable_).type)
917
        changes = [(c, v, col_type(c)) for c, v in changes]
918
        query = 'ALTER TABLE '+table.to_str(db)+'\n'
919
        query += ',\n'.join(('ALTER COLUMN '+c.to_str(db)+' TYPE '+t+'\nUSING '
920
            +v.to_str(db) for c, v, t in changes))
921
    else:
922
        query = 'UPDATE '+table.to_str(db)+'\nSET\n'
923
        query += ',\n'.join((c.to_str(db)+' = '+v.to_str(db)
924
            for c, v in changes))
925
        if cond != None: query += '\nWHERE\n'+cond.to_str(db)
926
    
927
    query = with_explain_comment(db, query)
928
    
929
    return query
930

    
931
def update(db, table, *args, **kw_args):
932
    '''For params, see mk_update() and run_query()'''
933
    recover = kw_args.pop('recover', None)
934
    cacheable = kw_args.pop('cacheable', False)
935
    log_level = kw_args.pop('log_level', 2)
936
    
937
    cur = run_query(db, mk_update(db, table, *args, **kw_args), recover,
938
        cacheable, log_level=log_level)
939
    autoanalyze(db, table)
940
    return cur
941

    
942
def mk_delete(db, table, cond=None):
943
    '''
944
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
945
    @return str query
946
    '''
947
    query = 'DELETE FROM '+table.to_str(db)
948
    if cond != None: query += '\nWHERE '+cond.to_str(db)
949
    
950
    query = with_explain_comment(db, query)
951
    
952
    return query
953

    
954
def delete(db, table, *args, **kw_args):
955
    '''For params, see mk_delete() and run_query()'''
956
    recover = kw_args.pop('recover', None)
957
    cacheable = kw_args.pop('cacheable', True)
958
    log_level = kw_args.pop('log_level', 2)
959
    
960
    cur = run_query(db, mk_delete(db, table, *args, **kw_args), recover,
961
        cacheable, log_level=log_level)
962
    autoanalyze(db, table)
963
    return cur
964

    
965
def last_insert_id(db):
966
    module = util.root_module(db.db)
967
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
968
    elif module == 'MySQLdb': return db.insert_id()
969
    else: return None
970

    
971
def define_func(db, def_):
972
    func = def_.function
973
    while True:
974
        try:
975
            run_query(db, def_.to_str(db), recover=True, cacheable=True,
976
                log_ignore_excs=(DuplicateException,))
977
            break # successful
978
        except DuplicateException:
979
            func.name = next_version(func.name)
980
            # try again with next version of name
981

    
982
def mk_flatten_mapping(db, into, cols, preserve=[], as_items=False):
983
    '''Creates a mapping from original column names (which may have collisions)
984
    to names that will be distinct among the columns' tables.
985
    This is meant to be used for several tables that are being joined together.
986
    @param cols The columns to combine. Duplicates will be removed.
987
    @param into The table for the new columns.
988
    @param preserve [sql_gen.Col...] Columns not to rename. Note that these
989
        columns will be included in the mapping even if they are not in cols.
990
        The tables of the provided Col objects will be changed to into, so make
991
        copies of them if you want to keep the original tables.
992
    @param as_items Whether to return a list of dict items instead of a dict
993
    @return dict(orig_col=new_col, ...)
994
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
995
        * new_col: sql_gen.Col(orig_col_name, into)
996
        * All mappings use the into table so its name can easily be
997
          changed for all columns at once
998
    '''
999
    cols = lists.uniqify(cols)
1000
    
1001
    items = []
1002
    for col in preserve:
1003
        orig_col = copy.copy(col)
1004
        col.table = into
1005
        items.append((orig_col, col))
1006
    preserve = set(preserve)
1007
    for col in cols:
1008
        if col not in preserve:
1009
            items.append((col, sql_gen.Col(strings.ustr(col), into, col.srcs)))
1010
    
1011
    if not as_items: items = dict(items)
1012
    return items
1013

    
1014
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
1015
    '''For params, see mk_flatten_mapping()
1016
    @return See return value of mk_flatten_mapping()
1017
    '''
1018
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
1019
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
1020
    run_query_into(db, mk_select(db, joins, cols, order_by=None, limit=limit,
1021
        start=start), into=into, add_pkey_=True)
1022
        # don't cache because the temp table will usually be truncated after use
1023
    return dict(items)
1024

    
1025
##### Database structure introspection
1026

    
1027
#### Tables
1028

    
1029
def tables(db, schema_like='public', table_like='%', exact=False,
1030
    cacheable=True):
1031
    if exact: compare = '='
1032
    else: compare = 'LIKE'
1033
    
1034
    module = util.root_module(db.db)
1035
    if module == 'psycopg2':
1036
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1037
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1038
        return values(select(db, 'pg_tables', ['tablename'], conds,
1039
            order_by='tablename', cacheable=cacheable, log_level=4))
1040
    elif module == 'MySQLdb':
1041
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1042
            , cacheable=True, log_level=4))
1043
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1044

    
1045
def table_exists(db, table, cacheable=True):
1046
    table = sql_gen.as_Table(table)
1047
    return list(tables(db, table.schema, table.name, True, cacheable)) != []
1048

    
1049
def table_row_count(db, table, recover=None):
1050
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
1051
        order_by=None), recover=recover, log_level=3))
1052

    
1053
def table_col_names(db, table, recover=None):
1054
    return list(col_names(select(db, table, limit=0, order_by=None,
1055
        recover=recover, log_level=4)))
1056

    
1057
def table_cols(db, table, *args, **kw_args):
1058
    return [sql_gen.as_Col(strings.ustr(c), table)
1059
        for c in table_col_names(db, table, *args, **kw_args)]
1060

    
1061
def table_pkey_col(db, table, recover=None):
1062
    table = sql_gen.as_Table(table)
1063
    
1064
    join_cols = ['table_schema', 'table_name', 'constraint_schema',
1065
        'constraint_name']
1066
    tables = [sql_gen.Table('key_column_usage', 'information_schema'),
1067
        sql_gen.Join(sql_gen.Table('table_constraints', 'information_schema'),
1068
            dict(((c, sql_gen.join_same_not_null) for c in join_cols)))]
1069
    cols = [sql_gen.Col('column_name')]
1070
    
1071
    conds = [('constraint_type', 'PRIMARY KEY'), ('table_name', table.name)]
1072
    schema = table.schema
1073
    if schema != None: conds.append(('table_schema', schema))
1074
    order_by = 'position_in_unique_constraint'
1075
    
1076
    try: return sql_gen.Col(value(select(db, tables, cols, conds,
1077
        order_by=order_by, limit=1, log_level=4)), table)
1078
    except StopIteration: raise DoesNotExistException('primary key', '')
1079

    
1080
def pkey_name(db, table, recover=None):
1081
    '''If no pkey, returns the first column in the table.'''
1082
    return pkey_col(db, table, recover).name
1083

    
1084
def pkey_col(db, table, recover=None):
1085
    '''If no pkey, returns the first column in the table.'''
1086
    try: return table_pkey_col(db, table, recover)
1087
    except DoesNotExistException: return table_cols(db, table, recover)[0]
1088

    
1089
not_null_col = 'not_null_col'
1090

    
1091
def table_not_null_col(db, table, recover=None):
1092
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
1093
    if not_null_col in table_col_names(db, table, recover): return not_null_col
1094
    else: return pkey_name(db, table, recover)
1095

    
1096
def constraint_cond(db, constraint):
1097
    module = util.root_module(db.db)
1098
    if module == 'psycopg2':
1099
        table_str = sql_gen.Literal(constraint.table.to_str(db))
1100
        name_str = sql_gen.Literal(constraint.name)
1101
        return value(run_query(db, '''\
1102
SELECT consrc
1103
FROM pg_constraint
1104
WHERE
1105
conrelid = '''+table_str.to_str(db)+'''::regclass
1106
AND conname = '''+name_str.to_str(db)+'''
1107
'''
1108
            , cacheable=True, log_level=4))
1109
    else: raise NotImplementedError("Can't get constraint condition for "
1110
        +module+' database')
1111

    
1112
def index_cols(db, index):
1113
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
1114
    automatically created. When you don't know whether something is a UNIQUE
1115
    constraint or a UNIQUE index, use this function.'''
1116
    index = sql_gen.as_Table(index)
1117
    module = util.root_module(db.db)
1118
    if module == 'psycopg2':
1119
        qual_index = sql_gen.Literal(index.to_str(db))
1120
        return map(sql_gen.parse_expr_col, values(run_query(db, '''\
1121
SELECT pg_get_indexdef(indexrelid, generate_series(1, indnatts), true)
1122
FROM pg_index
1123
WHERE indexrelid = '''+qual_index.to_str(db)+'''::regclass
1124
'''
1125
            , cacheable=True, log_level=4)))
1126
    else: raise NotImplementedError("Can't list index columns for "+module+
1127
        ' database')
1128

    
1129
def index_cond(db, index):
1130
    index = sql_gen.as_Table(index)
1131
    module = util.root_module(db.db)
1132
    if module == 'psycopg2':
1133
        qual_index = sql_gen.Literal(index.to_str(db))
1134
        return value(run_query(db, '''\
1135
SELECT pg_get_expr(indpred, indrelid, true)
1136
FROM pg_index
1137
WHERE indexrelid = '''+qual_index.to_str(db)+'''::regclass
1138
'''
1139
            , cacheable=True, log_level=4))
1140
    else: raise NotImplementedError()
1141

    
1142
#### Functions
1143

    
1144
def function_exists(db, function):
1145
    qual_function = sql_gen.Literal(function.to_str(db))
1146
    try:
1147
        select(db, fields=[sql_gen.Cast('regproc', qual_function)],
1148
            recover=True, cacheable=True, log_level=4)
1149
    except DoesNotExistException: return False
1150
    except DuplicateException: return True # overloaded function
1151
    else: return True
1152

    
1153
##### Structural changes
1154

    
1155
#### Columns
1156

    
1157
def add_col(db, table, col, comment=None, if_not_exists=False, **kw_args):
1158
    '''
1159
    @param col TypedCol Name may be versioned, so be sure to propagate any
1160
        renaming back to any source column for the TypedCol.
1161
    @param comment None|str SQL comment used to distinguish columns of the same
1162
        name from each other when they contain different data, to allow the
1163
        ADD COLUMN query to be cached. If not set, query will not be cached.
1164
    '''
1165
    assert isinstance(col, sql_gen.TypedCol)
1166
    
1167
    while True:
1168
        str_ = 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '+col.to_str(db)
1169
        if comment != None: str_ += ' '+sql_gen.esc_comment(comment)
1170
        
1171
        try:
1172
            run_query(db, str_, recover=True, cacheable=True, **kw_args)
1173
            break
1174
        except DuplicateException:
1175
            if if_not_exists: raise
1176
            col.name = next_version(col.name)
1177
            # try again with next version of name
1178

    
1179
def add_not_null(db, col):
1180
    table = col.table
1181
    col = sql_gen.to_name_only_col(col)
1182
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1183
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1184

    
1185
def drop_not_null(db, col):
1186
    table = col.table
1187
    col = sql_gen.to_name_only_col(col)
1188
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1189
        +col.to_str(db)+' DROP NOT NULL', cacheable=True, log_level=3)
1190

    
1191
row_num_col = '_row_num'
1192

    
1193
row_num_col_def = sql_gen.TypedCol('', 'serial', nullable=False,
1194
    constraints='PRIMARY KEY')
1195

    
1196
def add_row_num(db, table, name=row_num_col):
1197
    '''Adds a row number column to a table. Its definition is in
1198
    row_num_col_def. It will be the primary key.'''
1199
    col_def = copy.copy(row_num_col_def)
1200
    col_def.name = name
1201
    add_col(db, table, col_def, comment='', if_not_exists=True, log_level=3)
1202

    
1203
#### Indexes
1204

    
1205
def add_pkey(db, table, cols=None, recover=None):
1206
    '''Adds a primary key.
1207
    @param cols [sql_gen.Col,...] The columns in the primary key.
1208
        Defaults to the first column in the table.
1209
    @pre The table must not already have a primary key.
1210
    '''
1211
    table = sql_gen.as_Table(table)
1212
    if cols == None: cols = [pkey_name(db, table, recover)]
1213
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1214
    
1215
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1216
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1217
        log_ignore_excs=(DuplicateException,))
1218

    
1219
def add_index(db, exprs, table=None, unique=False, ensure_not_null_=True):
1220
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
1221
    Currently, only function calls and literal values are supported expressions.
1222
    @param ensure_not_null_ If set, translates NULL values to sentinel values.
1223
        This allows indexes to be used for comparisons where NULLs are equal.
1224
    '''
1225
    exprs = lists.mk_seq(exprs)
1226
    
1227
    # Parse exprs
1228
    old_exprs = exprs[:]
1229
    exprs = []
1230
    cols = []
1231
    for i, expr in enumerate(old_exprs):
1232
        expr = sql_gen.as_Col(expr, table)
1233
        
1234
        # Handle nullable columns
1235
        if ensure_not_null_:
1236
            try: expr = sql_gen.ensure_not_null(db, expr)
1237
            except KeyError: pass # unknown type, so just create plain index
1238
        
1239
        # Extract col
1240
        expr = copy.deepcopy(expr) # don't modify input!
1241
        col = expr
1242
        if isinstance(expr, sql_gen.FunctionCall): col = expr.args[0]
1243
        expr = sql_gen.cast_literal(expr)
1244
        if not isinstance(expr, (sql_gen.Expr, sql_gen.Col)):
1245
            expr = sql_gen.Expr(expr)
1246
            
1247
        
1248
        # Extract table
1249
        if table == None:
1250
            assert sql_gen.is_table_col(col)
1251
            table = col.table
1252
        
1253
        if isinstance(col, sql_gen.Col): col.table = None
1254
        
1255
        exprs.append(expr)
1256
        cols.append(col)
1257
    
1258
    table = sql_gen.as_Table(table)
1259
    
1260
    # Add index
1261
    str_ = 'CREATE'
1262
    if unique: str_ += ' UNIQUE'
1263
    str_ += ' INDEX ON '+table.to_str(db)+' ('+(
1264
        ', '.join((v.to_str(db) for v in exprs)))+')'
1265
    run_query(db, str_, recover=True, cacheable=True, log_level=3)
1266

    
1267
already_indexed = object() # tells add_indexes() the pkey has already been added
1268

    
1269
def add_indexes(db, table, has_pkey=True):
1270
    '''Adds an index on all columns in a table.
1271
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1272
        index should be added on the first column.
1273
        * If already_indexed, the pkey is assumed to have already been added
1274
    '''
1275
    cols = table_col_names(db, table)
1276
    if has_pkey:
1277
        if has_pkey is not already_indexed: add_pkey(db, table)
1278
        cols = cols[1:]
1279
    for col in cols: add_index(db, col, table)
1280

    
1281
#### Tables
1282

    
1283
### Maintenance
1284

    
1285
def analyze(db, table):
1286
    table = sql_gen.as_Table(table)
1287
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1288

    
1289
def autoanalyze(db, table):
1290
    if db.autoanalyze: analyze(db, table)
1291

    
1292
def vacuum(db, table):
1293
    table = sql_gen.as_Table(table)
1294
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1295
        log_level=3))
1296

    
1297
### Lifecycle
1298

    
1299
def drop(db, type_, name):
1300
    name = sql_gen.as_Name(name)
1301
    run_query(db, 'DROP '+type_+' IF EXISTS '+name.to_str(db)+' CASCADE')
1302

    
1303
def drop_table(db, table): drop(db, 'TABLE', table)
1304

    
1305
def create_table(db, table, cols=[], has_pkey=True, col_indexes=True,
1306
    like=None):
1307
    '''Creates a table.
1308
    @param cols [sql_gen.TypedCol,...] The column names and types
1309
    @param has_pkey If set, the first column becomes the primary key.
1310
    @param col_indexes bool|[ref]
1311
        * If True, indexes will be added on all non-pkey columns.
1312
        * If a list reference, [0] will be set to a function to do this.
1313
          This can be used to delay index creation until the table is populated.
1314
    '''
1315
    table = sql_gen.as_Table(table)
1316
    
1317
    if like != None:
1318
        cols = [sql_gen.CustomCode('LIKE '+like.to_str(db)+' INCLUDING ALL')
1319
            ]+cols
1320
    if has_pkey:
1321
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1322
        pkey.constraints = 'PRIMARY KEY'
1323
    
1324
    temp = table.is_temp and not db.debug_temp
1325
        # temp tables permanent in debug_temp mode
1326
    
1327
    # Create table
1328
    def create():
1329
        str_ = 'CREATE'
1330
        if temp: str_ += ' TEMP'
1331
        str_ += ' TABLE '+table.to_str(db)+' (\n'
1332
        str_ += '\n, '.join(c.to_str(db) for c in cols)
1333
        str_ += '\n);'
1334
        
1335
        run_query(db, str_, recover=True, cacheable=True, log_level=2,
1336
            log_ignore_excs=(DuplicateException,))
1337
    if table.is_temp:
1338
        while True:
1339
            try:
1340
                create()
1341
                break
1342
            except DuplicateException:
1343
                table.name = next_version(table.name)
1344
                # try again with next version of name
1345
    else: create()
1346
    
1347
    # Add indexes
1348
    if has_pkey: has_pkey = already_indexed
1349
    def add_indexes_(): add_indexes(db, table, has_pkey)
1350
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1351
    elif col_indexes: add_indexes_() # add now
1352

    
1353
def copy_table_struct(db, src, dest):
1354
    '''Creates a structure-only copy of a table. (Does not copy data.)'''
1355
    create_table(db, dest, has_pkey=False, col_indexes=False, like=src)
1356

    
1357
### Data
1358

    
1359
def truncate(db, table, schema='public', **kw_args):
1360
    '''For params, see run_query()'''
1361
    table = sql_gen.as_Table(table, schema)
1362
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1363

    
1364
def empty_temp(db, tables):
1365
    tables = lists.mk_seq(tables)
1366
    for table in tables: truncate(db, table, log_level=3)
1367

    
1368
def empty_db(db, schema='public', **kw_args):
1369
    '''For kw_args, see tables()'''
1370
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1371

    
1372
def distinct_table(db, table, distinct_on):
1373
    '''Creates a copy of a temp table which is distinct on the given columns.
1374
    The old and new tables will both get an index on these columns, to
1375
    facilitate merge joins.
1376
    @param distinct_on If empty, creates a table with one row. This is useful if
1377
        your distinct_on columns are all literal values.
1378
    @return The new table.
1379
    '''
1380
    new_table = sql_gen.suffixed_table(table, '_distinct')
1381
    distinct_on = filter(sql_gen.is_table_col, distinct_on)
1382
    
1383
    copy_table_struct(db, table, new_table)
1384
    
1385
    limit = None
1386
    if distinct_on == []: limit = 1 # one sample row
1387
    else:
1388
        add_index(db, distinct_on, new_table, unique=True)
1389
        add_index(db, distinct_on, table) # for join optimization
1390
    
1391
    insert_select(db, new_table, None, mk_select(db, table, order_by=None,
1392
        limit=limit), ignore=True)
1393
    analyze(db, new_table)
1394
    
1395
    return new_table
(28-28/42)