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 DuplicateKeyException(ConstraintException): pass
76

    
77
class NullValueException(ConstraintException): pass
78

    
79
class CheckException(ConstraintException): pass
80

    
81
class InvalidValueException(ExceptionWithValue): pass
82

    
83
class DuplicateException(ExceptionWithNameType): pass
84

    
85
class DoesNotExistException(ExceptionWithNameType): pass
86

    
87
class EmptyRowException(DbException): pass
88

    
89
##### Warnings
90

    
91
class DbWarning(UserWarning): pass
92

    
93
##### Result retrieval
94

    
95
def col_names(cur): return (col[0] for col in cur.description)
96

    
97
def rows(cur): return iter(lambda: cur.fetchone(), None)
98

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

    
103
def next_row(cur): return rows(cur).next()
104

    
105
def row(cur):
106
    row_ = next_row(cur)
107
    consume_rows(cur)
108
    return row_
109

    
110
def next_value(cur): return next_row(cur)[0]
111

    
112
def value(cur): return row(cur)[0]
113

    
114
def values(cur): return iters.func_iter(lambda: next_value(cur))
115

    
116
def value_or_none(cur):
117
    try: return value(cur)
118
    except StopIteration: return None
119

    
120
##### Escaping
121

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

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

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

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

    
140
##### Database connections
141

    
142
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
143

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

    
149
DatabaseErrors_set = set([DbException])
150
DatabaseErrors = tuple(DatabaseErrors_set)
151

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

    
157
def db_config_str(db_config):
158
    return db_config['engine']+' database '+db_config['database']
159

    
160
log_debug_none = lambda msg, level=2: None
161

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

    
493
connect = DbConn
494

    
495
##### Recoverable querying
496

    
497
def with_savepoint(db, func): return db.with_savepoint(func)
498

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

    
593
##### Basic queries
594

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

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

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

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

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

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

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

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

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

    
678
def mk_select(db, tables=None, fields=None, conds=None, distinct_on=[],
679
    limit=None, start=None, order_by=order_by_pkey, default_table=None,
680
    explain=True):
681
    '''
682
    @param tables The single table to select from, or a list of tables to join
683
        together, with tables after the first being sql_gen.Join objects
684
    @param fields Use None to select all fields in the table
685
    @param conds WHERE conditions: [(compare_left_side, compare_right_side),...]
686
        * container can be any iterable type
687
        * compare_left_side: sql_gen.Code|str (for col name)
688
        * compare_right_side: sql_gen.ValueCond|literal value
689
    @param distinct_on The columns to SELECT DISTINCT ON, or distinct_on_all to
690
        use all columns
691
    @return query
692
    '''
693
    # Parse tables param
694
    tables = lists.mk_seq(tables)
695
    tables = list(tables) # don't modify input! (list() copies input)
696
    table0 = sql_gen.as_Table(tables.pop(0)) # first table is separate
697
    
698
    # Parse other params
699
    if conds == None: conds = []
700
    elif dicts.is_dict(conds): conds = conds.items()
701
    conds = list(conds) # don't modify input! (list() copies input)
702
    assert limit == None or isinstance(limit, (int, long))
703
    assert start == None or isinstance(start, (int, long))
704
    if limit == 0: order_by = None
705
    if order_by is order_by_pkey:
706
        order_by = None
707
        if table0 != None and distinct_on == []:
708
            order_by = table_order_by(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, limit=limit, start=start),
1021
        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, recover=recover,
1055
        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_index(db, table, recover=None):
1062
    table_str = sql_gen.Literal(table.to_str(db))
1063
    try:
1064
        return sql_gen.Table(value(run_query(db, '''\
1065
SELECT relname
1066
FROM pg_index
1067
JOIN pg_class index ON index.oid = indexrelid
1068
WHERE
1069
indrelid = '''+table_str.to_str(db)+'''::regclass
1070
AND indisprimary
1071
'''
1072
            , recover, cacheable=True, log_level=4)), table.schema)
1073
    except StopIteration: raise DoesNotExistException('primary key', '')
1074

    
1075
def table_pkey_col(db, table, recover=None):
1076
    table = sql_gen.as_Table(table)
1077
    
1078
    join_cols = ['table_schema', 'table_name', 'constraint_schema',
1079
        'constraint_name']
1080
    tables = [sql_gen.Table('key_column_usage', 'information_schema'),
1081
        sql_gen.Join(sql_gen.Table('table_constraints', 'information_schema'),
1082
            dict(((c, sql_gen.join_same_not_null) for c in join_cols)))]
1083
    cols = [sql_gen.Col('column_name')]
1084
    
1085
    conds = [('constraint_type', 'PRIMARY KEY'), ('table_name', table.name)]
1086
    schema = table.schema
1087
    if schema != None: conds.append(('table_schema', schema))
1088
    order_by = 'position_in_unique_constraint'
1089
    
1090
    try: return sql_gen.Col(value(select(db, tables, cols, conds,
1091
        order_by=order_by, limit=1, log_level=4)), table)
1092
    except StopIteration: raise DoesNotExistException('primary key', '')
1093

    
1094
def pkey_name(db, table, recover=None):
1095
    '''If no pkey, returns the first column in the table.'''
1096
    return pkey_col(db, table, recover).name
1097

    
1098
def pkey_col(db, table, recover=None):
1099
    '''If no pkey, returns the first column in the table.'''
1100
    try: return table_pkey_col(db, table, recover)
1101
    except DoesNotExistException: return table_cols(db, table, recover)[0]
1102

    
1103
not_null_col = 'not_null_col'
1104

    
1105
def table_not_null_col(db, table, recover=None):
1106
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
1107
    if not_null_col in table_col_names(db, table, recover): return not_null_col
1108
    else: return pkey_name(db, table, recover)
1109

    
1110
def constraint_cond(db, constraint):
1111
    module = util.root_module(db.db)
1112
    if module == 'psycopg2':
1113
        table_str = sql_gen.Literal(constraint.table.to_str(db))
1114
        name_str = sql_gen.Literal(constraint.name)
1115
        return value(run_query(db, '''\
1116
SELECT consrc
1117
FROM pg_constraint
1118
WHERE
1119
conrelid = '''+table_str.to_str(db)+'''::regclass
1120
AND conname = '''+name_str.to_str(db)+'''
1121
'''
1122
            , cacheable=True, log_level=4))
1123
    else: raise NotImplementedError("Can't get constraint condition for "
1124
        +module+' database')
1125

    
1126
def index_exprs(db, index):
1127
    index = sql_gen.as_Table(index)
1128
    module = util.root_module(db.db)
1129
    if module == 'psycopg2':
1130
        qual_index = sql_gen.Literal(index.to_str(db))
1131
        return list(values(run_query(db, '''\
1132
SELECT pg_get_indexdef(indexrelid, generate_series(1, indnatts), true)
1133
FROM pg_index
1134
WHERE indexrelid = '''+qual_index.to_str(db)+'''::regclass
1135
'''
1136
            , cacheable=True, log_level=4)))
1137
    else: raise NotImplementedError()
1138

    
1139
def index_cols(db, index):
1140
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
1141
    automatically created. When you don't know whether something is a UNIQUE
1142
    constraint or a UNIQUE index, use this function.'''
1143
    return map(sql_gen.parse_expr_col, index_exprs(db, index))
1144

    
1145
def index_cond(db, index):
1146
    index = sql_gen.as_Table(index)
1147
    module = util.root_module(db.db)
1148
    if module == 'psycopg2':
1149
        qual_index = sql_gen.Literal(index.to_str(db))
1150
        return value(run_query(db, '''\
1151
SELECT pg_get_expr(indpred, indrelid, true)
1152
FROM pg_index
1153
WHERE indexrelid = '''+qual_index.to_str(db)+'''::regclass
1154
'''
1155
            , cacheable=True, log_level=4))
1156
    else: raise NotImplementedError()
1157

    
1158
def index_order_by(db, index):
1159
    return sql_gen.CustomCode(', '.join(index_exprs(db, index)))
1160

    
1161
def table_cluster_on(db, table, recover=None):
1162
    '''
1163
    @return The table's cluster index, or its pkey if none is set
1164
    '''
1165
    table_str = sql_gen.Literal(table.to_str(db))
1166
    try:
1167
        return sql_gen.Table(value(run_query(db, '''\
1168
SELECT relname
1169
FROM pg_index
1170
JOIN pg_class index ON index.oid = indexrelid
1171
WHERE
1172
indrelid = '''+table_str.to_str(db)+'''::regclass
1173
AND indisclustered
1174
'''
1175
            , recover, cacheable=True, log_level=4)), table.schema)
1176
    except StopIteration: return table_pkey_index(db, table, recover)
1177

    
1178
def table_order_by(db, table, recover=None):
1179
    if table.order_by == None:
1180
        try: table.order_by = index_order_by(db, table_cluster_on(db, table,
1181
            recover))
1182
        except DoesNotExistException: pass
1183
    return table.order_by
1184

    
1185
#### Functions
1186

    
1187
def function_exists(db, function):
1188
    qual_function = sql_gen.Literal(function.to_str(db))
1189
    try:
1190
        select(db, fields=[sql_gen.Cast('regproc', qual_function)],
1191
            recover=True, cacheable=True, log_level=4)
1192
    except DoesNotExistException: return False
1193
    except DuplicateException: return True # overloaded function
1194
    else: return True
1195

    
1196
##### Structural changes
1197

    
1198
#### Columns
1199

    
1200
def add_col(db, table, col, comment=None, if_not_exists=False, **kw_args):
1201
    '''
1202
    @param col TypedCol Name may be versioned, so be sure to propagate any
1203
        renaming back to any source column for the TypedCol.
1204
    @param comment None|str SQL comment used to distinguish columns of the same
1205
        name from each other when they contain different data, to allow the
1206
        ADD COLUMN query to be cached. If not set, query will not be cached.
1207
    '''
1208
    assert isinstance(col, sql_gen.TypedCol)
1209
    
1210
    while True:
1211
        str_ = 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '+col.to_str(db)
1212
        if comment != None: str_ += ' '+sql_gen.esc_comment(comment)
1213
        
1214
        try:
1215
            run_query(db, str_, recover=True, cacheable=True, **kw_args)
1216
            break
1217
        except DuplicateException:
1218
            if if_not_exists: raise
1219
            col.name = next_version(col.name)
1220
            # try again with next version of name
1221

    
1222
def add_not_null(db, col):
1223
    table = col.table
1224
    col = sql_gen.to_name_only_col(col)
1225
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1226
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1227

    
1228
def drop_not_null(db, col):
1229
    table = col.table
1230
    col = sql_gen.to_name_only_col(col)
1231
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1232
        +col.to_str(db)+' DROP NOT NULL', cacheable=True, log_level=3)
1233

    
1234
row_num_col = '_row_num'
1235

    
1236
row_num_col_def = sql_gen.TypedCol('', 'serial', nullable=False,
1237
    constraints='PRIMARY KEY')
1238

    
1239
def add_row_num(db, table, name=row_num_col):
1240
    '''Adds a row number column to a table. Its definition is in
1241
    row_num_col_def. It will be the primary key.'''
1242
    col_def = copy.copy(row_num_col_def)
1243
    col_def.name = name
1244
    add_col(db, table, col_def, comment='', if_not_exists=True, log_level=3)
1245

    
1246
#### Indexes
1247

    
1248
def add_pkey(db, table, cols=None, recover=None):
1249
    '''Adds a primary key.
1250
    @param cols [sql_gen.Col,...] The columns in the primary key.
1251
        Defaults to the first column in the table.
1252
    @pre The table must not already have a primary key.
1253
    '''
1254
    table = sql_gen.as_Table(table)
1255
    if cols == None: cols = [pkey_name(db, table, recover)]
1256
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1257
    
1258
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1259
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1260
        log_ignore_excs=(DuplicateException,))
1261

    
1262
def add_index(db, exprs, table=None, unique=False, ensure_not_null_=True):
1263
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
1264
    Currently, only function calls and literal values are supported expressions.
1265
    @param ensure_not_null_ If set, translates NULL values to sentinel values.
1266
        This allows indexes to be used for comparisons where NULLs are equal.
1267
    '''
1268
    exprs = lists.mk_seq(exprs)
1269
    
1270
    # Parse exprs
1271
    old_exprs = exprs[:]
1272
    exprs = []
1273
    cols = []
1274
    for i, expr in enumerate(old_exprs):
1275
        expr = sql_gen.as_Col(expr, table)
1276
        
1277
        # Handle nullable columns
1278
        if ensure_not_null_:
1279
            try: expr = sql_gen.ensure_not_null(db, expr)
1280
            except KeyError: pass # unknown type, so just create plain index
1281
        
1282
        # Extract col
1283
        expr = copy.deepcopy(expr) # don't modify input!
1284
        col = expr
1285
        if isinstance(expr, sql_gen.FunctionCall): col = expr.args[0]
1286
        expr = sql_gen.cast_literal(expr)
1287
        if not isinstance(expr, (sql_gen.Expr, sql_gen.Col)):
1288
            expr = sql_gen.Expr(expr)
1289
            
1290
        
1291
        # Extract table
1292
        if table == None:
1293
            assert sql_gen.is_table_col(col)
1294
            table = col.table
1295
        
1296
        if isinstance(col, sql_gen.Col): col.table = None
1297
        
1298
        exprs.append(expr)
1299
        cols.append(col)
1300
    
1301
    table = sql_gen.as_Table(table)
1302
    
1303
    # Add index
1304
    str_ = 'CREATE'
1305
    if unique: str_ += ' UNIQUE'
1306
    str_ += ' INDEX ON '+table.to_str(db)+' ('+(
1307
        ', '.join((v.to_str(db) for v in exprs)))+')'
1308
    run_query(db, str_, recover=True, cacheable=True, log_level=3)
1309

    
1310
already_indexed = object() # tells add_indexes() the pkey has already been added
1311

    
1312
def add_indexes(db, table, has_pkey=True):
1313
    '''Adds an index on all columns in a table.
1314
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1315
        index should be added on the first column.
1316
        * If already_indexed, the pkey is assumed to have already been added
1317
    '''
1318
    cols = table_col_names(db, table)
1319
    if has_pkey:
1320
        if has_pkey is not already_indexed: add_pkey(db, table)
1321
        cols = cols[1:]
1322
    for col in cols: add_index(db, col, table)
1323

    
1324
#### Tables
1325

    
1326
### Maintenance
1327

    
1328
def analyze(db, table):
1329
    table = sql_gen.as_Table(table)
1330
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1331

    
1332
def autoanalyze(db, table):
1333
    if db.autoanalyze: analyze(db, table)
1334

    
1335
def vacuum(db, table):
1336
    table = sql_gen.as_Table(table)
1337
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1338
        log_level=3))
1339

    
1340
### Lifecycle
1341

    
1342
def drop(db, type_, name):
1343
    name = sql_gen.as_Name(name)
1344
    run_query(db, 'DROP '+type_+' IF EXISTS '+name.to_str(db)+' CASCADE')
1345

    
1346
def drop_table(db, table): drop(db, 'TABLE', table)
1347

    
1348
def create_table(db, table, cols=[], has_pkey=True, col_indexes=True,
1349
    like=None):
1350
    '''Creates a table.
1351
    @param cols [sql_gen.TypedCol,...] The column names and types
1352
    @param has_pkey If set, the first column becomes the primary key.
1353
    @param col_indexes bool|[ref]
1354
        * If True, indexes will be added on all non-pkey columns.
1355
        * If a list reference, [0] will be set to a function to do this.
1356
          This can be used to delay index creation until the table is populated.
1357
    '''
1358
    table = sql_gen.as_Table(table)
1359
    
1360
    if like != None:
1361
        cols = [sql_gen.CustomCode('LIKE '+like.to_str(db)+' INCLUDING ALL')
1362
            ]+cols
1363
        table.order_by = like.order_by
1364
    if has_pkey:
1365
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1366
        pkey.constraints = 'PRIMARY KEY'
1367
    
1368
    temp = table.is_temp and not db.debug_temp
1369
        # temp tables permanent in debug_temp mode
1370
    
1371
    # Create table
1372
    def create():
1373
        str_ = 'CREATE'
1374
        if temp: str_ += ' TEMP'
1375
        str_ += ' TABLE '+table.to_str(db)+' (\n'
1376
        str_ += '\n, '.join(c.to_str(db) for c in cols)
1377
        str_ += '\n);'
1378
        
1379
        run_query(db, str_, recover=True, cacheable=True, log_level=2,
1380
            log_ignore_excs=(DuplicateException,))
1381
    if table.is_temp:
1382
        while True:
1383
            try:
1384
                create()
1385
                break
1386
            except DuplicateException:
1387
                table.name = next_version(table.name)
1388
                # try again with next version of name
1389
    else: create()
1390
    
1391
    # Add indexes
1392
    if has_pkey: has_pkey = already_indexed
1393
    def add_indexes_(): add_indexes(db, table, has_pkey)
1394
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1395
    elif col_indexes: add_indexes_() # add now
1396

    
1397
def copy_table_struct(db, src, dest):
1398
    '''Creates a structure-only copy of a table. (Does not copy data.)'''
1399
    create_table(db, dest, has_pkey=False, col_indexes=False, like=src)
1400

    
1401
def copy_table(db, src, dest):
1402
    '''Creates a copy of a table, including data'''
1403
    copy_table_struct(db, src, dest)
1404
    insert_select(db, dest, None, mk_select(db, src))
1405

    
1406
### Data
1407

    
1408
def truncate(db, table, schema='public', **kw_args):
1409
    '''For params, see run_query()'''
1410
    table = sql_gen.as_Table(table, schema)
1411
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1412

    
1413
def empty_temp(db, tables):
1414
    tables = lists.mk_seq(tables)
1415
    for table in tables: truncate(db, table, log_level=3)
1416

    
1417
def empty_db(db, schema='public', **kw_args):
1418
    '''For kw_args, see tables()'''
1419
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1420

    
1421
def distinct_table(db, table, distinct_on):
1422
    '''Creates a copy of a temp table which is distinct on the given columns.
1423
    The old and new tables will both get an index on these columns, to
1424
    facilitate merge joins.
1425
    @param distinct_on If empty, creates a table with one row. This is useful if
1426
        your distinct_on columns are all literal values.
1427
    @return The new table.
1428
    '''
1429
    new_table = sql_gen.suffixed_table(table, '_distinct')
1430
    distinct_on = filter(sql_gen.is_table_col, distinct_on)
1431
    
1432
    copy_table_struct(db, table, new_table)
1433
    
1434
    limit = None
1435
    if distinct_on == []: limit = 1 # one sample row
1436
    else:
1437
        add_index(db, distinct_on, new_table, unique=True)
1438
        add_index(db, distinct_on, table) # for join optimization
1439
    
1440
    insert_select(db, new_table, None, mk_select(db, table, order_by=None,
1441
        limit=limit), ignore=True)
1442
    analyze(db, new_table)
1443
    
1444
    return new_table
(28-28/42)