Project

General

Profile

1
# Database access
2

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

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

    
19
##### Exceptions
20

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

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

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

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

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

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

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

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

    
74
class NameException(DbException): pass
75

    
76
class DuplicateKeyException(ConstraintException): pass
77

    
78
class NullValueException(ConstraintException): pass
79

    
80
class CheckException(ConstraintException): pass
81

    
82
class InvalidValueException(ExceptionWithValue): pass
83

    
84
class DuplicateException(ExceptionWithNameType): pass
85

    
86
class DoesNotExistException(ExceptionWithNameType): pass
87

    
88
class EmptyRowException(DbException): pass
89

    
90
##### Warnings
91

    
92
class DbWarning(UserWarning): pass
93

    
94
##### Result retrieval
95

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

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

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

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

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

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

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

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

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

    
121
##### Escaping
122

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

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

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

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

    
141
##### Database connections
142

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

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

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

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

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

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

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

    
491
connect = DbConn
492

    
493
##### Recoverable querying
494

    
495
def with_savepoint(db, func): return db.with_savepoint(func)
496

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

    
580
##### Basic queries
581

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

    
587
def explain(db, query, **kw_args):
588
    '''
589
    For params, see run_query().
590
    '''
591
    kw_args.setdefault('log_level', 4)
592
    
593
    return strings.ustr(strings.join_lines(values(run_query(db,
594
        'EXPLAIN '+query, recover=True, cacheable=True, **kw_args))))
595
        # not a higher log_level because it's useful to see what query is being
596
        # run before it's executed, which EXPLAIN effectively provides
597

    
598
def has_comment(query): return query.endswith('*/')
599

    
600
def with_explain_comment(db, query, **kw_args):
601
    if db.autoexplain and not has_comment(query) and is_explainable(query):
602
        query += '\n'+sql_gen.esc_comment(' EXPLAIN:\n'
603
            +explain(db, query, **kw_args))
604
    return query
605

    
606
def next_version(name):
607
    version = 1 # first existing name was version 0
608
    match = re.match(r'^(.*)#(\d+)$', name)
609
    if match:
610
        name, version = match.groups()
611
        version = int(version)+1
612
    return sql_gen.concat(name, '#'+str(version))
613

    
614
def lock_table(db, table, mode):
615
    table = sql_gen.as_Table(table)
616
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
617

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

    
661
order_by_pkey = object() # tells mk_select() to order by the pkey
662

    
663
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
664

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

    
749
def select(db, *args, **kw_args):
750
    '''For params, see mk_select() and run_query()'''
751
    recover = kw_args.pop('recover', None)
752
    cacheable = kw_args.pop('cacheable', True)
753
    log_level = kw_args.pop('log_level', 2)
754
    
755
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
756
        log_level=log_level)
757

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

    
832
def insert_select(db, table, *args, **kw_args):
833
    '''For params, see mk_insert_select() and run_query_into()
834
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
835
        values in
836
    '''
837
    returning = kw_args.get('returning', None)
838
    ignore = kw_args.get('ignore', False)
839
    
840
    into = kw_args.pop('into', None)
841
    if into != None: kw_args['embeddable'] = True
842
    recover = kw_args.pop('recover', None)
843
    if ignore: recover = True
844
    cacheable = kw_args.pop('cacheable', True)
845
    log_level = kw_args.pop('log_level', 2)
846
    
847
    rowcount_only = ignore and returning == None # keep NULL rows on server
848
    if rowcount_only: into = sql_gen.Table('rowcount')
849
    
850
    cur = run_query_into(db, mk_insert_select(db, table, *args, **kw_args),
851
        into, recover=recover, cacheable=cacheable, log_level=log_level)
852
    if rowcount_only: empty_temp(db, into)
853
    autoanalyze(db, table)
854
    return cur
855

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

    
858
def insert(db, table, row, *args, **kw_args):
859
    '''For params, see insert_select()'''
860
    if lists.is_seq(row): cols = None
861
    else:
862
        cols = row.keys()
863
        row = row.values()
864
    row = list(row) # ensure that "== []" works
865
    
866
    if row == []: query = None
867
    else: query = sql_gen.Values(row).to_str(db)
868
    
869
    return insert_select(db, table, cols, query, *args, **kw_args)
870

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

    
907
def update(db, table, *args, **kw_args):
908
    '''For params, see mk_update() and run_query()'''
909
    recover = kw_args.pop('recover', None)
910
    cacheable = kw_args.pop('cacheable', False)
911
    log_level = kw_args.pop('log_level', 2)
912
    
913
    cur = run_query(db, mk_update(db, table, *args, **kw_args), recover,
914
        cacheable, log_level=log_level)
915
    autoanalyze(db, table)
916
    return cur
917

    
918
def mk_delete(db, table, cond=None):
919
    '''
920
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
921
    @return str query
922
    '''
923
    query = 'DELETE FROM '+table.to_str(db)
924
    if cond != None: query += '\nWHERE '+cond.to_str(db)
925
    
926
    query = with_explain_comment(db, query)
927
    
928
    return query
929

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

    
941
def last_insert_id(db):
942
    module = util.root_module(db.db)
943
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
944
    elif module == 'MySQLdb': return db.insert_id()
945
    else: return None
946

    
947
def define_func(db, def_):
948
    func = def_.function
949
    while True:
950
        try:
951
            run_query(db, def_.to_str(db), recover=True, cacheable=True,
952
                log_ignore_excs=(DuplicateException,))
953
            break # successful
954
        except DuplicateException:
955
            func.name = next_version(func.name)
956
            # try again with next version of name
957

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

    
990
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
991
    '''For params, see mk_flatten_mapping()
992
    @return See return value of mk_flatten_mapping()
993
    '''
994
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
995
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
996
    run_query_into(db, mk_select(db, joins, cols, order_by=None, limit=limit,
997
        start=start), into=into, add_pkey_=True)
998
        # don't cache because the temp table will usually be truncated after use
999
    return dict(items)
1000

    
1001
##### Database structure introspection
1002

    
1003
#### Expressions
1004

    
1005
bool_re = r'(?:true|false)'
1006

    
1007
def simplify_expr(expr):
1008
    expr = expr.replace('(NULL IS NULL)', 'true')
1009
    expr = expr.replace('(NULL IS NOT NULL)', 'false')
1010
    expr = re.sub(r' OR '+bool_re, r'', expr)
1011
    expr = re.sub(bool_re+r' OR ', r'', expr)
1012
    while True:
1013
        expr, n = re.subn(r'\((\([^()]*\))\)', r'\1', expr)
1014
        if n == 0: break
1015
    return expr
1016

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

    
1019
def parse_expr_col(str_):
1020
    match = re.match(r'^\('+name_re+r'\(('+name_re+r').*\)\)$', str_)
1021
    if match: str_ = match.group(1)
1022
    return sql_gen.unesc_name(str_)
1023

    
1024
def map_expr(db, expr, mapping, in_cols_found=None):
1025
    '''Replaces output columns with input columns in an expression.
1026
    @param in_cols_found If set, will be filled in with the expr's (input) cols
1027
    '''
1028
    for out, in_ in mapping.iteritems():
1029
        orig_expr = expr
1030
        out = sql_gen.to_name_only_col(out)
1031
        in_str = sql_gen.to_name_only_col(sql_gen.remove_col_rename(in_)
1032
            ).to_str(db)
1033
        
1034
        # Replace out both with and without quotes
1035
        expr = expr.replace(out.to_str(db), in_str)
1036
        expr = re.sub(r'\b'+out.name+r'\b', in_str, expr)
1037
        
1038
        if in_cols_found != None and expr != orig_expr: # replaced something
1039
            in_cols_found.append(in_)
1040
    
1041
    return simplify_expr(expr)
1042

    
1043
#### Tables
1044

    
1045
def tables(db, schema_like='public', table_like='%', exact=False):
1046
    if exact: compare = '='
1047
    else: compare = 'LIKE'
1048
    
1049
    module = util.root_module(db.db)
1050
    if module == 'psycopg2':
1051
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1052
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1053
        return values(select(db, 'pg_tables', ['tablename'], conds,
1054
            order_by='tablename', log_level=4))
1055
    elif module == 'MySQLdb':
1056
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1057
            , cacheable=True, log_level=4))
1058
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1059

    
1060
def table_exists(db, table):
1061
    table = sql_gen.as_Table(table)
1062
    return list(tables(db, table.schema, table.name, exact=True)) != []
1063

    
1064
def table_row_count(db, table, recover=None):
1065
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
1066
        order_by=None), recover=recover, log_level=3))
1067

    
1068
def table_cols(db, table, recover=None):
1069
    return list(col_names(select(db, table, limit=0, order_by=None,
1070
        recover=recover, log_level=4)))
1071

    
1072
def pkey(db, table, recover=None):
1073
    '''Assumed to be first column in table'''
1074
    return table_cols(db, table, recover)[0]
1075

    
1076
not_null_col = 'not_null_col'
1077

    
1078
def table_not_null_col(db, table, recover=None):
1079
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
1080
    if not_null_col in table_cols(db, table, recover): return not_null_col
1081
    else: return pkey(db, table, recover)
1082

    
1083
def constraint_cond(db, constraint):
1084
    module = util.root_module(db.db)
1085
    if module == 'psycopg2':
1086
        table_str = sql_gen.Literal(constraint.table.to_str(db))
1087
        name_str = sql_gen.Literal(constraint.name)
1088
        return value(run_query(db, '''\
1089
SELECT consrc
1090
FROM pg_constraint
1091
WHERE
1092
conrelid = '''+table_str.to_str(db)+'''::regclass
1093
AND conname = '''+name_str.to_str(db)+'''
1094
'''
1095
            , cacheable=True, log_level=4))
1096
    else: raise NotImplementedError("Can't list index columns for "+module+
1097
        ' database')
1098

    
1099
def index_cols(db, index):
1100
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
1101
    automatically created. When you don't know whether something is a UNIQUE
1102
    constraint or a UNIQUE index, use this function.'''
1103
    index = sql_gen.as_Table(index)
1104
    module = util.root_module(db.db)
1105
    if module == 'psycopg2':
1106
        qual_index = sql_gen.Literal(index.to_str(db))
1107
        return map(parse_expr_col, values(run_query(db, '''\
1108
SELECT pg_get_indexdef(indexrelid, generate_series(1, indnatts), true)
1109
FROM pg_index
1110
WHERE indexrelid = '''+qual_index.to_str(db)+'''::regclass
1111
'''
1112
            , cacheable=True, log_level=4)))
1113
    else: raise NotImplementedError("Can't list index columns for "+module+
1114
        ' database')
1115

    
1116
#### Functions
1117

    
1118
def function_exists(db, function):
1119
    qual_function = sql_gen.Literal(function.to_str(db))
1120
    try:
1121
        select(db, fields=[sql_gen.Cast('regproc', qual_function)],
1122
            recover=True, cacheable=True, log_level=4)
1123
    except DoesNotExistException: return False
1124
    else: return True
1125

    
1126
##### Structural changes
1127

    
1128
#### Columns
1129

    
1130
def add_col(db, table, col, comment=None, **kw_args):
1131
    '''
1132
    @param col TypedCol Name may be versioned, so be sure to propagate any
1133
        renaming back to any source column for the TypedCol.
1134
    @param comment None|str SQL comment used to distinguish columns of the same
1135
        name from each other when they contain different data, to allow the
1136
        ADD COLUMN query to be cached. If not set, query will not be cached.
1137
    '''
1138
    assert isinstance(col, sql_gen.TypedCol)
1139
    
1140
    while True:
1141
        str_ = 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '+col.to_str(db)
1142
        if comment != None: str_ += ' '+sql_gen.esc_comment(comment)
1143
        
1144
        try:
1145
            run_query(db, str_, recover=True, cacheable=True, **kw_args)
1146
            break
1147
        except DuplicateException:
1148
            col.name = next_version(col.name)
1149
            # try again with next version of name
1150

    
1151
def add_not_null(db, col):
1152
    table = col.table
1153
    col = sql_gen.to_name_only_col(col)
1154
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1155
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1156

    
1157
row_num_col = '_row_num'
1158

    
1159
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1160
    constraints='PRIMARY KEY')
1161

    
1162
def add_row_num(db, table):
1163
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1164
    be the primary key.'''
1165
    add_col(db, table, row_num_typed_col, log_level=3)
1166

    
1167
#### Indexes
1168

    
1169
def add_pkey(db, table, cols=None, recover=None):
1170
    '''Adds a primary key.
1171
    @param cols [sql_gen.Col,...] The columns in the primary key.
1172
        Defaults to the first column in the table.
1173
    @pre The table must not already have a primary key.
1174
    '''
1175
    table = sql_gen.as_Table(table)
1176
    if cols == None: cols = [pkey(db, table, recover)]
1177
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1178
    
1179
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1180
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1181
        log_ignore_excs=(DuplicateException,))
1182

    
1183
def add_index(db, exprs, table=None, unique=False, ensure_not_null_=True):
1184
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
1185
    Currently, only function calls and literal values are supported expressions.
1186
    @param ensure_not_null_ If set, translates NULL values to sentinel values.
1187
        This allows indexes to be used for comparisons where NULLs are equal.
1188
    '''
1189
    exprs = lists.mk_seq(exprs)
1190
    
1191
    # Parse exprs
1192
    old_exprs = exprs[:]
1193
    exprs = []
1194
    cols = []
1195
    for i, expr in enumerate(old_exprs):
1196
        expr = sql_gen.as_Col(expr, table)
1197
        
1198
        # Handle nullable columns
1199
        if ensure_not_null_:
1200
            try: expr = sql_gen.ensure_not_null(db, expr)
1201
            except KeyError: pass # unknown type, so just create plain index
1202
        
1203
        # Extract col
1204
        expr = copy.deepcopy(expr) # don't modify input!
1205
        col = expr
1206
        if isinstance(expr, sql_gen.FunctionCall): col = expr.args[0]
1207
        expr = sql_gen.cast_literal(expr)
1208
        if not isinstance(expr, (sql_gen.Expr, sql_gen.Col)):
1209
            expr = sql_gen.Expr(expr)
1210
            
1211
        
1212
        # Extract table
1213
        if table == None:
1214
            assert sql_gen.is_table_col(col)
1215
            table = col.table
1216
        
1217
        if isinstance(col, sql_gen.Col): col.table = None
1218
        
1219
        exprs.append(expr)
1220
        cols.append(col)
1221
    
1222
    table = sql_gen.as_Table(table)
1223
    
1224
    # Add index
1225
    str_ = 'CREATE'
1226
    if unique: str_ += ' UNIQUE'
1227
    str_ += ' INDEX ON '+table.to_str(db)+' ('+(
1228
        ', '.join((v.to_str(db) for v in exprs)))+')'
1229
    run_query(db, str_, recover=True, cacheable=True, log_level=3)
1230

    
1231
already_indexed = object() # tells add_indexes() the pkey has already been added
1232

    
1233
def add_indexes(db, table, has_pkey=True):
1234
    '''Adds an index on all columns in a table.
1235
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1236
        index should be added on the first column.
1237
        * If already_indexed, the pkey is assumed to have already been added
1238
    '''
1239
    cols = table_cols(db, table)
1240
    if has_pkey:
1241
        if has_pkey is not already_indexed: add_pkey(db, table)
1242
        cols = cols[1:]
1243
    for col in cols: add_index(db, col, table)
1244

    
1245
#### Tables
1246

    
1247
### Maintenance
1248

    
1249
def analyze(db, table):
1250
    table = sql_gen.as_Table(table)
1251
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1252

    
1253
def autoanalyze(db, table):
1254
    if db.autoanalyze: analyze(db, table)
1255

    
1256
def vacuum(db, table):
1257
    table = sql_gen.as_Table(table)
1258
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1259
        log_level=3))
1260

    
1261
### Lifecycle
1262

    
1263
def drop(db, type_, name):
1264
    name = sql_gen.as_Name(name)
1265
    run_query(db, 'DROP '+type_+' IF EXISTS '+name.to_str(db)+' CASCADE')
1266

    
1267
def drop_table(db, table): drop(db, 'TABLE', table)
1268

    
1269
def create_table(db, table, cols=[], has_pkey=True, col_indexes=True,
1270
    like=None):
1271
    '''Creates a table.
1272
    @param cols [sql_gen.TypedCol,...] The column names and types
1273
    @param has_pkey If set, the first column becomes the primary key.
1274
    @param col_indexes bool|[ref]
1275
        * If True, indexes will be added on all non-pkey columns.
1276
        * If a list reference, [0] will be set to a function to do this.
1277
          This can be used to delay index creation until the table is populated.
1278
    '''
1279
    table = sql_gen.as_Table(table)
1280
    
1281
    if like != None:
1282
        cols = [sql_gen.CustomCode('LIKE '+like.to_str(db)+' INCLUDING ALL')
1283
            ]+cols
1284
    if has_pkey:
1285
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1286
        pkey.constraints = 'PRIMARY KEY'
1287
    
1288
    temp = table.is_temp and not db.debug_temp
1289
        # temp tables permanent in debug_temp mode
1290
    
1291
    # Create table
1292
    def create():
1293
        str_ = 'CREATE'
1294
        if temp: str_ += ' TEMP'
1295
        str_ += ' TABLE '+table.to_str(db)+' (\n'
1296
        str_ += '\n, '.join(c.to_str(db) for c in cols)
1297
        str_ += '\n);'
1298
        
1299
        run_query(db, str_, recover=True, cacheable=True, log_level=2,
1300
            log_ignore_excs=(DuplicateException,))
1301
    if table.is_temp:
1302
        while True:
1303
            try:
1304
                create()
1305
                break
1306
            except DuplicateException:
1307
                table.name = next_version(table.name)
1308
                # try again with next version of name
1309
    else: create()
1310
    
1311
    # Add indexes
1312
    if has_pkey: has_pkey = already_indexed
1313
    def add_indexes_(): add_indexes(db, table, has_pkey)
1314
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1315
    elif col_indexes: add_indexes_() # add now
1316

    
1317
def copy_table_struct(db, src, dest):
1318
    '''Creates a structure-only copy of a table. (Does not copy data.)'''
1319
    create_table(db, dest, has_pkey=False, col_indexes=False, like=src)
1320

    
1321
### Data
1322

    
1323
def truncate(db, table, schema='public', **kw_args):
1324
    '''For params, see run_query()'''
1325
    table = sql_gen.as_Table(table, schema)
1326
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1327

    
1328
def empty_temp(db, tables):
1329
    tables = lists.mk_seq(tables)
1330
    for table in tables: truncate(db, table, log_level=3)
1331

    
1332
def empty_db(db, schema='public', **kw_args):
1333
    '''For kw_args, see tables()'''
1334
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1335

    
1336
def distinct_table(db, table, distinct_on):
1337
    '''Creates a copy of a temp table which is distinct on the given columns.
1338
    The old and new tables will both get an index on these columns, to
1339
    facilitate merge joins.
1340
    @param distinct_on If empty, creates a table with one row. This is useful if
1341
        your distinct_on columns are all literal values.
1342
    @return The new table.
1343
    '''
1344
    new_table = sql_gen.suffixed_table(table, '_distinct')
1345
    distinct_on = filter(sql_gen.is_table_col, distinct_on)
1346
    
1347
    copy_table_struct(db, table, new_table)
1348
    
1349
    limit = None
1350
    if distinct_on == []: limit = 1 # one sample row
1351
    else:
1352
        add_index(db, distinct_on, new_table, unique=True)
1353
        add_index(db, distinct_on, table) # for join optimization
1354
    
1355
    insert_select(db, new_table, None, mk_select(db, table, order_by=None,
1356
        limit=limit), ignore=True)
1357
    analyze(db, new_table)
1358
    
1359
    return new_table
(27-27/40)