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 '+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
                if recover: # need auto-rollback to run index_cols()
528
                    try: cols = index_cols(db, constraint)
529
                    except NotImplementedError: pass
530
                raise DuplicateKeyException(constraint, None, cols, e)
531
            
532
            match = re.match(r'^null value in column "(.+?)" violates not-null'
533
                r' constraint', msg)
534
            if match:
535
                col, = match.groups()
536
                raise NullValueException('NOT NULL', None, [col], e)
537
            
538
            match = re.match(r'^new row for relation "(.+?)" violates check '
539
                r'constraint "(.+?)"', msg)
540
            if match:
541
                table, constraint = match.groups()
542
                constraint = sql_gen.Col(constraint, table)
543
                cond = None
544
                if recover: # need auto-rollback to run constraint_cond()
545
                    try: cond = constraint_cond(db, constraint)
546
                    except NotImplementedError: pass
547
                raise CheckException(constraint.to_str(db), cond, [], e)
548
            
549
            match = re.match(r'^(?:invalid input (?:syntax|value)\b.*?'
550
                r'|.+? out of range): "(.+?)"', msg)
551
            if match:
552
                value, = match.groups()
553
                raise InvalidValueException(strings.to_unicode(value), e)
554
            
555
            match = re.match(r'^column "(.+?)" is of type (.+?) but expression '
556
                r'is of type', msg)
557
            if match:
558
                col, type_ = match.groups()
559
                raise MissingCastException(type_, col, e)
560
            
561
            match = re.match(r'^could not determine polymorphic type because '
562
                r'input has type "unknown"', msg)
563
            if match: raise MissingCastException('text', None, e)
564
            
565
            match = re.match(r'^.+? types .+? and .+? cannot be matched', msg)
566
            if match: raise MissingCastException('text', None, e)
567
            
568
            typed_name_re = r'^(\S+) "(.+?)"(?: of relation ".+?")?'
569
            
570
            match = re.match(typed_name_re+r'.*? already exists', msg)
571
            if match:
572
                type_, name = match.groups()
573
                raise DuplicateException(type_, name, e)
574
            
575
            match = re.match(r'more than one (\S+) named ""(.+?)""', msg)
576
            if match:
577
                type_, name = match.groups()
578
                raise DuplicateException(type_, name, e)
579
            
580
            match = re.match(typed_name_re+r' does not exist', msg)
581
            if match:
582
                type_, name = match.groups()
583
                raise DoesNotExistException(type_, name, e)
584
            
585
            raise # no specific exception raised
586
    except log_ignore_excs:
587
        log_level += 2
588
        raise
589
    finally:
590
        if debug_msg_ref[0] != None: db.log_debug(debug_msg_ref[0], log_level)
591

    
592
##### Basic queries
593

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

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

    
610
def has_comment(query): return query.endswith('*/')
611

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

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

    
626
def lock_table(db, table, mode):
627
    table = sql_gen.as_Table(table)
628
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
629

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

    
673
order_by_pkey = object() # tells mk_select() to order by the pkey
674

    
675
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
676

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

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

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

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

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

    
870
def insert(db, table, row, *args, **kw_args):
871
    '''For params, see insert_select()'''
872
    if lists.is_seq(row): cols = None
873
    else:
874
        cols = row.keys()
875
        row = row.values()
876
    row = list(row) # ensure that "== []" works
877
    
878
    if row == []: query = None
879
    else: query = sql_gen.Values(row).to_str(db)
880
    
881
    return insert_select(db, table, cols, query, *args, **kw_args)
882

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

    
919
def update(db, table, *args, **kw_args):
920
    '''For params, see mk_update() and run_query()'''
921
    recover = kw_args.pop('recover', None)
922
    cacheable = kw_args.pop('cacheable', False)
923
    log_level = kw_args.pop('log_level', 2)
924
    
925
    cur = run_query(db, mk_update(db, table, *args, **kw_args), recover,
926
        cacheable, log_level=log_level)
927
    autoanalyze(db, table)
928
    return cur
929

    
930
def mk_delete(db, table, cond=None):
931
    '''
932
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
933
    @return str query
934
    '''
935
    query = 'DELETE FROM '+table.to_str(db)
936
    if cond != None: query += '\nWHERE '+cond.to_str(db)
937
    
938
    query = with_explain_comment(db, query)
939
    
940
    return query
941

    
942
def delete(db, table, *args, **kw_args):
943
    '''For params, see mk_delete() and run_query()'''
944
    recover = kw_args.pop('recover', None)
945
    cacheable = kw_args.pop('cacheable', True)
946
    log_level = kw_args.pop('log_level', 2)
947
    
948
    cur = run_query(db, mk_delete(db, table, *args, **kw_args), recover,
949
        cacheable, log_level=log_level)
950
    autoanalyze(db, table)
951
    return cur
952

    
953
def last_insert_id(db):
954
    module = util.root_module(db.db)
955
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
956
    elif module == 'MySQLdb': return db.insert_id()
957
    else: return None
958

    
959
def define_func(db, def_):
960
    func = def_.function
961
    while True:
962
        try:
963
            run_query(db, def_.to_str(db), recover=True, cacheable=True,
964
                log_ignore_excs=(DuplicateException,))
965
            break # successful
966
        except DuplicateException:
967
            func.name = next_version(func.name)
968
            # try again with next version of name
969

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

    
1002
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
1003
    '''For params, see mk_flatten_mapping()
1004
    @return See return value of mk_flatten_mapping()
1005
    '''
1006
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
1007
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
1008
    run_query_into(db, mk_select(db, joins, cols, order_by=None, limit=limit,
1009
        start=start), into=into, add_pkey_=True)
1010
        # don't cache because the temp table will usually be truncated after use
1011
    return dict(items)
1012

    
1013
##### Database structure introspection
1014

    
1015
#### Expressions
1016

    
1017
bool_re = r'(?:true|false)'
1018

    
1019
def simplify_expr(expr):
1020
    expr = expr.replace('(NULL IS NULL)', 'true')
1021
    expr = expr.replace('(NULL IS NOT NULL)', 'false')
1022
    expr = re.sub(r' OR '+bool_re, r'', expr)
1023
    expr = re.sub(bool_re+r' OR ', r'', expr)
1024
    while True:
1025
        expr, n = re.subn(r'\((\([^()]*\))\)', r'\1', expr)
1026
        if n == 0: break
1027
    return expr
1028

    
1029
name_re = r'(?:\w+|(?:"[^"]*")+)'
1030

    
1031
def parse_expr_col(str_):
1032
    match = re.match(r'^\('+name_re+r'\(('+name_re+r').*\)\)$', str_)
1033
    if match: str_ = match.group(1)
1034
    return sql_gen.unesc_name(str_)
1035

    
1036
def map_expr(db, expr, mapping, in_cols_found=None):
1037
    '''Replaces output columns with input columns in an expression.
1038
    @param in_cols_found If set, will be filled in with the expr's (input) cols
1039
    '''
1040
    for out, in_ in mapping.iteritems():
1041
        orig_expr = expr
1042
        out = sql_gen.to_name_only_col(out)
1043
        in_str = sql_gen.to_name_only_col(sql_gen.remove_col_rename(in_)
1044
            ).to_str(db)
1045
        
1046
        # Replace out both with and without quotes
1047
        expr = expr.replace(out.to_str(db), in_str)
1048
        expr = re.sub(r'(?<!\.)\b'+out.name+r'\b(?!\.)', in_str, expr)
1049
        
1050
        if in_cols_found != None and expr != orig_expr: # replaced something
1051
            in_cols_found.append(in_)
1052
    
1053
    return simplify_expr(expr)
1054

    
1055
#### Tables
1056

    
1057
def tables(db, schema_like='public', table_like='%', exact=False,
1058
    cacheable=True):
1059
    if exact: compare = '='
1060
    else: compare = 'LIKE'
1061
    
1062
    module = util.root_module(db.db)
1063
    if module == 'psycopg2':
1064
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1065
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1066
        return values(select(db, 'pg_tables', ['tablename'], conds,
1067
            order_by='tablename', cacheable=cacheable, log_level=4))
1068
    elif module == 'MySQLdb':
1069
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1070
            , cacheable=True, log_level=4))
1071
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1072

    
1073
def table_exists(db, table, cacheable=True):
1074
    table = sql_gen.as_Table(table)
1075
    return list(tables(db, table.schema, table.name, True, cacheable)) != []
1076

    
1077
def table_row_count(db, table, recover=None):
1078
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
1079
        order_by=None), recover=recover, log_level=3))
1080

    
1081
def table_cols(db, table, recover=None):
1082
    return list(col_names(select(db, table, limit=0, order_by=None,
1083
        recover=recover, log_level=4)))
1084

    
1085
pkey_col = 'row_num'
1086

    
1087
def pkey(db, table, recover=None):
1088
    '''Uses pkey_col, or if not found, the first column in the table.'''
1089
    cols = table_cols(db, table, recover)
1090
    if pkey_col in cols: return pkey_col
1091
    else: return cols[0]
1092

    
1093
not_null_col = 'not_null_col'
1094

    
1095
def table_not_null_col(db, table, recover=None):
1096
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
1097
    if not_null_col in table_cols(db, table, recover): return not_null_col
1098
    else: return pkey(db, table, recover)
1099

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

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

    
1133
#### Functions
1134

    
1135
def function_exists(db, function):
1136
    qual_function = sql_gen.Literal(function.to_str(db))
1137
    try:
1138
        select(db, fields=[sql_gen.Cast('regproc', qual_function)],
1139
            recover=True, cacheable=True, log_level=4)
1140
    except DoesNotExistException: return False
1141
    except DuplicateException: return True # overloaded function
1142
    else: return True
1143

    
1144
##### Structural changes
1145

    
1146
#### Columns
1147

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

    
1169
def add_not_null(db, col):
1170
    table = col.table
1171
    col = sql_gen.to_name_only_col(col)
1172
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1173
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1174

    
1175
def drop_not_null(db, col):
1176
    table = col.table
1177
    col = sql_gen.to_name_only_col(col)
1178
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1179
        +col.to_str(db)+' DROP NOT NULL', cacheable=True, log_level=3)
1180

    
1181
row_num_col = '_row_num'
1182

    
1183
row_num_col_def = sql_gen.TypedCol('', 'serial', nullable=False,
1184
    constraints='PRIMARY KEY')
1185

    
1186
def add_row_num(db, table, name=row_num_col):
1187
    '''Adds a row number column to a table. Its definition is in
1188
    row_num_col_def. It will be the primary key.'''
1189
    col_def = copy.copy(row_num_col_def)
1190
    col_def.name = name
1191
    add_col(db, table, col_def, comment='', log_level=3)
1192

    
1193
#### Indexes
1194

    
1195
def add_pkey(db, table, cols=None, recover=None):
1196
    '''Adds a primary key.
1197
    @param cols [sql_gen.Col,...] The columns in the primary key.
1198
        Defaults to the first column in the table.
1199
    @pre The table must not already have a primary key.
1200
    '''
1201
    table = sql_gen.as_Table(table)
1202
    if cols == None: cols = [pkey(db, table, recover)]
1203
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1204
    
1205
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1206
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1207
        log_ignore_excs=(DuplicateException,))
1208

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

    
1257
already_indexed = object() # tells add_indexes() the pkey has already been added
1258

    
1259
def add_indexes(db, table, has_pkey=True):
1260
    '''Adds an index on all columns in a table.
1261
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1262
        index should be added on the first column.
1263
        * If already_indexed, the pkey is assumed to have already been added
1264
    '''
1265
    cols = table_cols(db, table)
1266
    if has_pkey:
1267
        if has_pkey is not already_indexed: add_pkey(db, table)
1268
        cols = cols[1:]
1269
    for col in cols: add_index(db, col, table)
1270

    
1271
#### Tables
1272

    
1273
### Maintenance
1274

    
1275
def analyze(db, table):
1276
    table = sql_gen.as_Table(table)
1277
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1278

    
1279
def autoanalyze(db, table):
1280
    if db.autoanalyze: analyze(db, table)
1281

    
1282
def vacuum(db, table):
1283
    table = sql_gen.as_Table(table)
1284
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1285
        log_level=3))
1286

    
1287
### Lifecycle
1288

    
1289
def drop(db, type_, name):
1290
    name = sql_gen.as_Name(name)
1291
    run_query(db, 'DROP '+type_+' IF EXISTS '+name.to_str(db)+' CASCADE')
1292

    
1293
def drop_table(db, table): drop(db, 'TABLE', table)
1294

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

    
1343
def copy_table_struct(db, src, dest):
1344
    '''Creates a structure-only copy of a table. (Does not copy data.)'''
1345
    create_table(db, dest, has_pkey=False, col_indexes=False, like=src)
1346

    
1347
### Data
1348

    
1349
def truncate(db, table, schema='public', **kw_args):
1350
    '''For params, see run_query()'''
1351
    table = sql_gen.as_Table(table, schema)
1352
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1353

    
1354
def empty_temp(db, tables):
1355
    tables = lists.mk_seq(tables)
1356
    for table in tables: truncate(db, table, log_level=3)
1357

    
1358
def empty_db(db, schema='public', **kw_args):
1359
    '''For kw_args, see tables()'''
1360
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1361

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