Project

General

Profile

1 11 aaronmk
# Database access
2
3 1869 aaronmk
import copy
4 11 aaronmk
import re
5 3238 aaronmk
import time
6 865 aaronmk
import warnings
7 11 aaronmk
8 300 aaronmk
import exc
9 1909 aaronmk
import dicts
10 1893 aaronmk
import iters
11 1960 aaronmk
import lists
12 3241 aaronmk
import profiling
13 1889 aaronmk
from Proxy import Proxy
14 1872 aaronmk
import rand
15 2217 aaronmk
import sql_gen
16 862 aaronmk
import strings
17 131 aaronmk
import util
18 11 aaronmk
19 832 aaronmk
##### Exceptions
20
21 2804 aaronmk
def get_cur_query(cur, input_query=None):
22 2168 aaronmk
    raw_query = None
23
    if hasattr(cur, 'query'): raw_query = cur.query
24
    elif hasattr(cur, '_last_executed'): raw_query = cur._last_executed
25 2170 aaronmk
26
    if raw_query != None: return raw_query
27 2804 aaronmk
    else: return '[input] '+strings.ustr(input_query)
28 14 aaronmk
29 2170 aaronmk
def _add_cursor_info(e, *args, **kw_args):
30
    '''For params, see get_cur_query()'''
31 2771 aaronmk
    exc.add_msg(e, 'query: '+strings.ustr(get_cur_query(*args, **kw_args)))
32 135 aaronmk
33 300 aaronmk
class DbException(exc.ExceptionWithCause):
34 14 aaronmk
    def __init__(self, msg, cause=None, cur=None):
35 2145 aaronmk
        exc.ExceptionWithCause.__init__(self, msg, cause, cause_newline=True)
36 14 aaronmk
        if cur != None: _add_cursor_info(self, cur)
37
38 2143 aaronmk
class ExceptionWithName(DbException):
39
    def __init__(self, name, cause=None):
40 2484 aaronmk
        DbException.__init__(self, 'for name: '+strings.as_tt(str(name)), cause)
41 2143 aaronmk
        self.name = name
42 360 aaronmk
43 3109 aaronmk
class ExceptionWithValue(DbException):
44
    def __init__(self, value, cause=None):
45
        DbException.__init__(self, 'for value: '+strings.as_tt(repr(value)),
46
            cause)
47 2240 aaronmk
        self.value = value
48
49 2945 aaronmk
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 2306 aaronmk
class ConstraintException(DbException):
57
    def __init__(self, name, cols, cause=None):
58 2484 aaronmk
        DbException.__init__(self, 'Violated '+strings.as_tt(name)
59
            +' constraint on columns: '+strings.as_tt(', '.join(cols)), cause)
60 2306 aaronmk
        self.name = name
61 468 aaronmk
        self.cols = cols
62 11 aaronmk
63 2523 aaronmk
class MissingCastException(DbException):
64
    def __init__(self, type_, col, cause=None):
65
        DbException.__init__(self, 'Missing cast to type '+strings.as_tt(type_)
66
            +' on column: '+strings.as_tt(col), cause)
67
        self.type = type_
68
        self.col = col
69
70 2143 aaronmk
class NameException(DbException): pass
71
72 2306 aaronmk
class DuplicateKeyException(ConstraintException): pass
73 13 aaronmk
74 2306 aaronmk
class NullValueException(ConstraintException): pass
75 13 aaronmk
76 3109 aaronmk
class InvalidValueException(ExceptionWithValue): pass
77 2239 aaronmk
78 2945 aaronmk
class DuplicateException(ExceptionWithNameType): pass
79 2143 aaronmk
80 89 aaronmk
class EmptyRowException(DbException): pass
81
82 865 aaronmk
##### Warnings
83
84
class DbWarning(UserWarning): pass
85
86 1930 aaronmk
##### Result retrieval
87
88
def col_names(cur): return (col[0] for col in cur.description)
89
90
def rows(cur): return iter(lambda: cur.fetchone(), None)
91
92
def consume_rows(cur):
93
    '''Used to fetch all rows so result will be cached'''
94
    iters.consume_iter(rows(cur))
95
96
def next_row(cur): return rows(cur).next()
97
98
def row(cur):
99
    row_ = next_row(cur)
100
    consume_rows(cur)
101
    return row_
102
103
def next_value(cur): return next_row(cur)[0]
104
105
def value(cur): return row(cur)[0]
106
107
def values(cur): return iters.func_iter(lambda: next_value(cur))
108
109
def value_or_none(cur):
110
    try: return value(cur)
111
    except StopIteration: return None
112
113 2762 aaronmk
##### Escaping
114 2101 aaronmk
115 2573 aaronmk
def esc_name_by_module(module, name):
116
    if module == 'psycopg2' or module == None: quote = '"'
117 2101 aaronmk
    elif module == 'MySQLdb': quote = '`'
118
    else: raise NotImplementedError("Can't escape name for "+module+' database')
119 2500 aaronmk
    return sql_gen.esc_name(name, quote)
120 2101 aaronmk
121
def esc_name_by_engine(engine, name, **kw_args):
122
    return esc_name_by_module(db_engines[engine][0], name, **kw_args)
123
124
def esc_name(db, name, **kw_args):
125
    return esc_name_by_module(util.root_module(db.db), name, **kw_args)
126
127
def qual_name(db, schema, table):
128
    def esc_name_(name): return esc_name(db, name)
129
    table = esc_name_(table)
130
    if schema != None: return esc_name_(schema)+'.'+table
131
    else: return table
132
133 1869 aaronmk
##### Database connections
134 1849 aaronmk
135 2097 aaronmk
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
136 1926 aaronmk
137 1869 aaronmk
db_engines = {
138
    'MySQL': ('MySQLdb', {'password': 'passwd', 'database': 'db'}),
139
    'PostgreSQL': ('psycopg2', {}),
140
}
141
142
DatabaseErrors_set = set([DbException])
143
DatabaseErrors = tuple(DatabaseErrors_set)
144
145
def _add_module(module):
146
    DatabaseErrors_set.add(module.DatabaseError)
147
    global DatabaseErrors
148
    DatabaseErrors = tuple(DatabaseErrors_set)
149
150
def db_config_str(db_config):
151
    return db_config['engine']+' database '+db_config['database']
152
153 2448 aaronmk
log_debug_none = lambda msg, level=2: None
154 1901 aaronmk
155 1849 aaronmk
class DbConn:
156 2923 aaronmk
    def __init__(self, db_config, autocommit=True, caching=True,
157 3183 aaronmk
        log_debug=log_debug_none, debug_temp=False, src=None):
158 2915 aaronmk
        '''
159
        @param debug_temp Whether temporary objects should instead be permanent.
160
            This assists in debugging the internal objects used by the program.
161 3183 aaronmk
        @param src In autocommit mode, will be included in a comment in every
162
            query, to help identify the data source in pg_stat_activity.
163 2915 aaronmk
        '''
164 1869 aaronmk
        self.db_config = db_config
165 2190 aaronmk
        self.autocommit = autocommit
166
        self.caching = caching
167 1901 aaronmk
        self.log_debug = log_debug
168 2193 aaronmk
        self.debug = log_debug != log_debug_none
169 2915 aaronmk
        self.debug_temp = debug_temp
170 3244 aaronmk
        self.profile_row_ct = None
171 3183 aaronmk
        self.src = src
172 3074 aaronmk
        self.autoanalyze = False
173 1869 aaronmk
174 3124 aaronmk
        self._savepoint = 0
175 3120 aaronmk
        self._reset()
176 1869 aaronmk
177
    def __getattr__(self, name):
178
        if name == '__dict__': raise Exception('getting __dict__')
179
        if name == 'db': return self._db()
180
        else: raise AttributeError()
181
182
    def __getstate__(self):
183
        state = copy.copy(self.__dict__) # shallow copy
184 1915 aaronmk
        state['log_debug'] = None # don't pickle the debug callback
185 1869 aaronmk
        state['_DbConn__db'] = None # don't pickle the connection
186
        return state
187
188 3118 aaronmk
    def clear_cache(self): self.query_results = {}
189
190 3120 aaronmk
    def _reset(self):
191 3118 aaronmk
        self.clear_cache()
192 3124 aaronmk
        assert self._savepoint == 0
193 3118 aaronmk
        self._notices_seen = set()
194
        self.__db = None
195
196 2165 aaronmk
    def connected(self): return self.__db != None
197
198 3116 aaronmk
    def close(self):
199 3119 aaronmk
        if not self.connected(): return
200
201 3135 aaronmk
        # Record that the automatic transaction is now closed
202 3136 aaronmk
        self._savepoint -= 1
203 3135 aaronmk
204 3119 aaronmk
        self.db.close()
205 3120 aaronmk
        self._reset()
206 3116 aaronmk
207 3125 aaronmk
    def reconnect(self):
208
        # Do not do this in test mode as it would roll back everything
209
        if self.autocommit: self.close()
210
        # Connection will be reopened automatically on first query
211
212 1869 aaronmk
    def _db(self):
213
        if self.__db == None:
214
            # Process db_config
215
            db_config = self.db_config.copy() # don't modify input!
216 2097 aaronmk
            schemas = db_config.pop('schemas', None)
217 1869 aaronmk
            module_name, mappings = db_engines[db_config.pop('engine')]
218
            module = __import__(module_name)
219
            _add_module(module)
220
            for orig, new in mappings.iteritems():
221
                try: util.rename_key(db_config, orig, new)
222
                except KeyError: pass
223
224
            # Connect
225
            self.__db = module.connect(**db_config)
226
227 3161 aaronmk
            # Record that a transaction is already open
228
            self._savepoint += 1
229
230 1869 aaronmk
            # Configure connection
231 2906 aaronmk
            if hasattr(self.db, 'set_isolation_level'):
232
                import psycopg2.extensions
233
                self.db.set_isolation_level(
234
                    psycopg2.extensions.ISOLATION_LEVEL_READ_COMMITTED)
235 2101 aaronmk
            if schemas != None:
236 2893 aaronmk
                search_path = [self.esc_name(s) for s in schemas.split(',')]
237
                search_path.append(value(run_query(self, 'SHOW search_path',
238
                    log_level=4)))
239
                run_query(self, 'SET search_path TO '+(','.join(search_path)),
240
                    log_level=3)
241 1869 aaronmk
242
        return self.__db
243 1889 aaronmk
244 1891 aaronmk
    class DbCursor(Proxy):
245 1927 aaronmk
        def __init__(self, outer):
246 1891 aaronmk
            Proxy.__init__(self, outer.db.cursor())
247 2191 aaronmk
            self.outer = outer
248 1927 aaronmk
            self.query_results = outer.query_results
249 1894 aaronmk
            self.query_lookup = None
250 1891 aaronmk
            self.result = []
251 1889 aaronmk
252 2802 aaronmk
        def execute(self, query):
253 2764 aaronmk
            self._is_insert = query.startswith('INSERT')
254 2797 aaronmk
            self.query_lookup = query
255 2148 aaronmk
            try:
256 3162 aaronmk
                try: cur = self.inner.execute(query)
257 2802 aaronmk
                finally: self.query = get_cur_query(self.inner, query)
258 1904 aaronmk
            except Exception, e:
259
                self.result = e # cache the exception as the result
260
                self._cache_result()
261
                raise
262 3004 aaronmk
263
            # Always cache certain queries
264 3183 aaronmk
            query = sql_gen.lstrip(query)
265 3004 aaronmk
            if query.startswith('CREATE') or query.startswith('ALTER'):
266 3007 aaronmk
                # structural changes
267 3040 aaronmk
                # Rest of query must be unique in the face of name collisions,
268
                # so don't cache ADD COLUMN unless it has distinguishing comment
269
                if query.find('ADD COLUMN') < 0 or query.endswith('*/'):
270 3007 aaronmk
                    self._cache_result()
271 3004 aaronmk
            elif self.rowcount == 0 and query.startswith('SELECT'): # empty
272 2800 aaronmk
                consume_rows(self) # fetch all rows so result will be cached
273 3004 aaronmk
274 2762 aaronmk
            return cur
275 1894 aaronmk
276 1891 aaronmk
        def fetchone(self):
277
            row = self.inner.fetchone()
278 1899 aaronmk
            if row != None: self.result.append(row)
279
            # otherwise, fetched all rows
280 1904 aaronmk
            else: self._cache_result()
281
            return row
282
283
        def _cache_result(self):
284 2948 aaronmk
            # For inserts that return a result set, don't cache result set since
285
            # inserts are not idempotent. Other non-SELECT queries don't have
286
            # their result set read, so only exceptions will be cached (an
287
            # invalid query will always be invalid).
288 1930 aaronmk
            if self.query_results != None and (not self._is_insert
289 1906 aaronmk
                or isinstance(self.result, Exception)):
290
291 1894 aaronmk
                assert self.query_lookup != None
292 1916 aaronmk
                self.query_results[self.query_lookup] = self.CacheCursor(
293
                    util.dict_subset(dicts.AttrsDictView(self),
294
                    ['query', 'result', 'rowcount', 'description']))
295 1906 aaronmk
296 1916 aaronmk
        class CacheCursor:
297
            def __init__(self, cached_result): self.__dict__ = cached_result
298
299 1927 aaronmk
            def execute(self, *args, **kw_args):
300 1916 aaronmk
                if isinstance(self.result, Exception): raise self.result
301
                # otherwise, result is a rows list
302
                self.iter = iter(self.result)
303
304
            def fetchone(self):
305
                try: return self.iter.next()
306
                except StopIteration: return None
307 1891 aaronmk
308 2212 aaronmk
    def esc_value(self, value):
309 2663 aaronmk
        try: str_ = self.mogrify('%s', [value])
310
        except NotImplementedError, e:
311
            module = util.root_module(self.db)
312
            if module == 'MySQLdb':
313
                import _mysql
314
                str_ = _mysql.escape_string(value)
315
            else: raise e
316 2374 aaronmk
        return strings.to_unicode(str_)
317 2212 aaronmk
318 2347 aaronmk
    def esc_name(self, name): return esc_name(self, name) # calls global func
319
320 2814 aaronmk
    def std_code(self, str_):
321
        '''Standardizes SQL code.
322
        * Ensures that string literals are prefixed by `E`
323
        '''
324
        if str_.startswith("'"): str_ = 'E'+str_
325
        return str_
326
327 2665 aaronmk
    def can_mogrify(self):
328 2663 aaronmk
        module = util.root_module(self.db)
329 2665 aaronmk
        return module == 'psycopg2'
330 2663 aaronmk
331 2665 aaronmk
    def mogrify(self, query, params=None):
332
        if self.can_mogrify(): return self.db.cursor().mogrify(query, params)
333
        else: raise NotImplementedError("Can't mogrify query")
334
335 2671 aaronmk
    def print_notices(self):
336 2725 aaronmk
        if hasattr(self.db, 'notices'):
337
            for msg in self.db.notices:
338
                if msg not in self._notices_seen:
339
                    self._notices_seen.add(msg)
340
                    self.log_debug(msg, level=2)
341 2671 aaronmk
342 2793 aaronmk
    def run_query(self, query, cacheable=False, log_level=2,
343 2464 aaronmk
        debug_msg_ref=None):
344 2445 aaronmk
        '''
345 2464 aaronmk
        @param log_ignore_excs The log_level will be increased by 2 if the query
346
            throws one of these exceptions.
347 2664 aaronmk
        @param debug_msg_ref If specified, the log message will be returned in
348
            this instead of being output. This allows you to filter log messages
349
            depending on the result of the query.
350 2445 aaronmk
        '''
351 2167 aaronmk
        assert query != None
352
353 3183 aaronmk
        if self.autocommit and self.src != None:
354 3206 aaronmk
            query = sql_gen.esc_comment(self.src)+'\t'+query
355 3183 aaronmk
356 2047 aaronmk
        if not self.caching: cacheable = False
357 1903 aaronmk
        used_cache = False
358 2664 aaronmk
359 3242 aaronmk
        if self.debug:
360
            profiler = profiling.ItersProfiler(start_now=True, iter_text='row')
361 1903 aaronmk
        try:
362 1927 aaronmk
            # Get cursor
363
            if cacheable:
364 3238 aaronmk
                try: cur = self.query_results[query]
365 1927 aaronmk
                except KeyError: cur = self.DbCursor(self)
366 3238 aaronmk
                else: used_cache = True
367 1927 aaronmk
            else: cur = self.db.cursor()
368
369
            # Run query
370 3238 aaronmk
            try: cur.execute(query)
371 3162 aaronmk
            except Exception, e:
372
                _add_cursor_info(e, self, query)
373
                raise
374 3238 aaronmk
            else: self.do_autocommit()
375 1903 aaronmk
        finally:
376 3242 aaronmk
            if self.debug:
377 3244 aaronmk
                profiler.stop(self.profile_row_ct)
378 3242 aaronmk
379
                ## Log or return query
380
381 3239 aaronmk
                query = str(get_cur_query(cur, query))
382
                # So that the src comment is hidden when cating the file, and
383
                # put on a separate line when viewed in a text editor.
384
                query = query.replace('\t', '\r', 1)
385
386 3240 aaronmk
                msg = 'DB query: '
387 3239 aaronmk
388 3240 aaronmk
                if used_cache: msg += 'cache hit'
389
                elif cacheable: msg += 'cache miss'
390
                else: msg += 'non-cacheable'
391 3239 aaronmk
392 3241 aaronmk
                msg += ':\n'+profiler.msg()+'\n'+strings.as_code(query, 'SQL')
393 3240 aaronmk
394 3237 aaronmk
                if debug_msg_ref != None: debug_msg_ref[0] = msg
395
                else: self.log_debug(msg, log_level)
396 3245 aaronmk
397
                self.print_notices()
398 1903 aaronmk
399
        return cur
400 1914 aaronmk
401 2797 aaronmk
    def is_cached(self, query): return query in self.query_results
402 2139 aaronmk
403 2907 aaronmk
    def with_autocommit(self, func):
404 2801 aaronmk
        import psycopg2.extensions
405
406
        prev_isolation_level = self.db.isolation_level
407 2907 aaronmk
        self.db.set_isolation_level(
408
            psycopg2.extensions.ISOLATION_LEVEL_AUTOCOMMIT)
409 2683 aaronmk
        try: return func()
410 2801 aaronmk
        finally: self.db.set_isolation_level(prev_isolation_level)
411 2683 aaronmk
412 2139 aaronmk
    def with_savepoint(self, func):
413 3137 aaronmk
        top = self._savepoint == 0
414 2171 aaronmk
        savepoint = 'level_'+str(self._savepoint)
415 3137 aaronmk
416 3160 aaronmk
        # Must happen before running queries so they don't get autocommitted
417
        self._savepoint += 1
418
419 3137 aaronmk
        if top: query = 'START TRANSACTION ISOLATION LEVEL READ COMMITTED'
420
        else: query = 'SAVEPOINT '+savepoint
421
        self.run_query(query, log_level=4)
422
        try:
423
            return func()
424
            if top: self.run_query('COMMIT', log_level=4)
425 2139 aaronmk
        except:
426 3137 aaronmk
            if top: query = 'ROLLBACK'
427
            else: query = 'ROLLBACK TO SAVEPOINT '+savepoint
428
            self.run_query(query, log_level=4)
429
430 2139 aaronmk
            raise
431 2930 aaronmk
        finally:
432
            # Always release savepoint, because after ROLLBACK TO SAVEPOINT,
433
            # "The savepoint remains valid and can be rolled back to again"
434
            # (http://www.postgresql.org/docs/8.3/static/sql-rollback-to.html).
435 3137 aaronmk
            if not top:
436
                self.run_query('RELEASE SAVEPOINT '+savepoint, log_level=4)
437 2930 aaronmk
438
            self._savepoint -= 1
439
            assert self._savepoint >= 0
440
441
            self.do_autocommit() # OK to do this after ROLLBACK TO SAVEPOINT
442 2191 aaronmk
443
    def do_autocommit(self):
444
        '''Autocommits if outside savepoint'''
445 3135 aaronmk
        assert self._savepoint >= 1
446
        if self.autocommit and self._savepoint == 1:
447 2924 aaronmk
            self.log_debug('Autocommitting', level=4)
448 2191 aaronmk
            self.db.commit()
449 2643 aaronmk
450 3155 aaronmk
    def col_info(self, col, cacheable=True):
451 2643 aaronmk
        table = sql_gen.Table('columns', 'information_schema')
452 3063 aaronmk
        type_ = sql_gen.Coalesce(sql_gen.Nullif(sql_gen.Col('data_type'),
453
            'USER-DEFINED'), sql_gen.Col('udt_name'))
454 3078 aaronmk
        cols = [type_, 'column_default',
455
            sql_gen.Cast('boolean', sql_gen.Col('is_nullable'))]
456 2643 aaronmk
457
        conds = [('table_name', col.table.name), ('column_name', col.name)]
458
        schema = col.table.schema
459
        if schema != None: conds.append(('table_schema', schema))
460
461 2819 aaronmk
        type_, default, nullable = row(select(self, table, cols, conds,
462 3150 aaronmk
            order_by='table_schema', limit=1, cacheable=cacheable, log_level=4))
463 2643 aaronmk
            # TODO: order_by search_path schema order
464 2819 aaronmk
        default = sql_gen.as_Code(default, self)
465
466
        return sql_gen.TypedCol(col.name, type_, default, nullable)
467 2917 aaronmk
468
    def TempFunction(self, name):
469
        if self.debug_temp: schema = None
470
        else: schema = 'pg_temp'
471
        return sql_gen.Function(name, schema)
472 1849 aaronmk
473 1869 aaronmk
connect = DbConn
474
475 832 aaronmk
##### Recoverable querying
476 15 aaronmk
477 2139 aaronmk
def with_savepoint(db, func): return db.with_savepoint(func)
478 11 aaronmk
479 2791 aaronmk
def run_query(db, query, recover=None, cacheable=False, log_level=2,
480
    log_ignore_excs=None, **kw_args):
481 2794 aaronmk
    '''For params, see DbConn.run_query()'''
482 830 aaronmk
    if recover == None: recover = False
483 2464 aaronmk
    if log_ignore_excs == None: log_ignore_excs = ()
484
    log_ignore_excs = tuple(log_ignore_excs)
485 3236 aaronmk
    debug_msg_ref = [None]
486 830 aaronmk
487 3265 aaronmk
    query = with_explain_comment(db, query, log_level=log_level+1)
488 3258 aaronmk
489 2148 aaronmk
    try:
490 2464 aaronmk
        try:
491 2794 aaronmk
            def run(): return db.run_query(query, cacheable, log_level,
492 2793 aaronmk
                debug_msg_ref, **kw_args)
493 2796 aaronmk
            if recover and not db.is_cached(query):
494 2464 aaronmk
                return with_savepoint(db, run)
495
            else: return run() # don't need savepoint if cached
496
        except Exception, e:
497 3095 aaronmk
            msg = strings.ustr(e.args[0])
498 2464 aaronmk
499 3095 aaronmk
            match = re.match(r'^duplicate key value violates unique constraint '
500 3096 aaronmk
                r'"((_?[^\W_]+(?=[._]))?.+?)"', msg)
501 2464 aaronmk
            if match:
502
                constraint, table = match.groups()
503 3025 aaronmk
                cols = []
504
                if recover: # need auto-rollback to run index_cols()
505
                    try: cols = index_cols(db, table, constraint)
506
                    except NotImplementedError: pass
507
                raise DuplicateKeyException(constraint, cols, e)
508 2464 aaronmk
509 3095 aaronmk
            match = re.match(r'^null value in column "(.+?)" violates not-null'
510 2464 aaronmk
                r' constraint', msg)
511
            if match: raise NullValueException('NOT NULL', [match.group(1)], e)
512
513 3095 aaronmk
            match = re.match(r'^(?:invalid input (?:syntax|value)\b.*?'
514 3109 aaronmk
                r'|.+? field value out of range): "(.+?)"', msg)
515 2464 aaronmk
            if match:
516 3109 aaronmk
                value, = match.groups()
517
                raise InvalidValueException(strings.to_unicode(value), e)
518 2464 aaronmk
519 3095 aaronmk
            match = re.match(r'^column "(.+?)" is of type (.+?) but expression '
520 2523 aaronmk
                r'is of type', msg)
521
            if match:
522
                col, type_ = match.groups()
523
                raise MissingCastException(type_, col, e)
524
525 3095 aaronmk
            match = re.match(r'^(\S+) "(.+?)".*? already exists', msg)
526 2945 aaronmk
            if match:
527
                type_, name = match.groups()
528
                raise DuplicateException(type_, name, e)
529 2464 aaronmk
530
            raise # no specific exception raised
531
    except log_ignore_excs:
532
        log_level += 2
533
        raise
534
    finally:
535 3236 aaronmk
        if debug_msg_ref[0] != None: db.log_debug(debug_msg_ref[0], log_level)
536 830 aaronmk
537 832 aaronmk
##### Basic queries
538
539 3256 aaronmk
def is_explainable(query):
540
    # See <http://www.postgresql.org/docs/8.3/static/sql-explain.html#AEN57749>
541 3257 aaronmk
    return re.match(r'^(?:SELECT|INSERT|UPDATE|DELETE|VALUES|EXECUTE|DECLARE)\b'
542
        , query)
543 3256 aaronmk
544 3263 aaronmk
def explain(db, query, **kw_args):
545
    '''
546
    For params, see run_query().
547
    '''
548
    kw_args.setdefault('log_level', 3)
549
550 3256 aaronmk
    return strings.join_lines(values(run_query(db, 'EXPLAIN '+query,
551 3263 aaronmk
        recover=True, cacheable=True, **kw_args)))
552 3256 aaronmk
        # not a higher log_level because it's useful to see what query is being
553
        # run before it's executed, which EXPLAIN effectively provides
554
555 3265 aaronmk
def has_comment(query): return query.endswith('*/')
556
557
def with_explain_comment(db, query, **kw_args):
558
    if db.debug and not has_comment(query) and is_explainable(query):
559
        query += '\n'+sql_gen.esc_comment(' EXPLAIN:\n'
560
            +explain(db, query, **kw_args))
561
    return query
562
563 2153 aaronmk
def next_version(name):
564 2163 aaronmk
    version = 1 # first existing name was version 0
565 2586 aaronmk
    match = re.match(r'^(.*)#(\d+)$', name)
566 2153 aaronmk
    if match:
567 2586 aaronmk
        name, version = match.groups()
568
        version = int(version)+1
569 2932 aaronmk
    return sql_gen.concat(name, '#'+str(version))
570 2153 aaronmk
571 2899 aaronmk
def lock_table(db, table, mode):
572
    table = sql_gen.as_Table(table)
573
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
574
575 2789 aaronmk
def run_query_into(db, query, into=None, add_indexes_=False, **kw_args):
576 2085 aaronmk
    '''Outputs a query to a temp table.
577
    For params, see run_query().
578
    '''
579 2789 aaronmk
    if into == None: return run_query(db, query, **kw_args)
580 2790 aaronmk
581
    assert isinstance(into, sql_gen.Table)
582
583 2992 aaronmk
    into.is_temp = True
584 3008 aaronmk
    # "temporary tables cannot specify a schema name", so remove schema
585
    into.schema = None
586 2992 aaronmk
587 2790 aaronmk
    kw_args['recover'] = True
588 2945 aaronmk
    kw_args.setdefault('log_ignore_excs', (DuplicateException,))
589 2790 aaronmk
590 2916 aaronmk
    temp = not db.debug_temp # tables are permanent in debug_temp mode
591 2790 aaronmk
592
    # Create table
593
    while True:
594
        create_query = 'CREATE'
595
        if temp: create_query += ' TEMP'
596
        create_query += ' TABLE '+into.to_str(db)+' AS\n'+query
597 2385 aaronmk
598 2790 aaronmk
        try:
599
            cur = run_query(db, create_query, **kw_args)
600
                # CREATE TABLE AS sets rowcount to # rows in query
601
            break
602 2945 aaronmk
        except DuplicateException, e:
603 2790 aaronmk
            into.name = next_version(into.name)
604
            # try again with next version of name
605
606
    if add_indexes_: add_indexes(db, into)
607 3075 aaronmk
608
    # According to the PostgreSQL doc, "The autovacuum daemon cannot access and
609
    # therefore cannot vacuum or analyze temporary tables. [...] if a temporary
610
    # table is going to be used in complex queries, it is wise to run ANALYZE on
611
    # the temporary table after it is populated."
612
    # (http://www.postgresql.org/docs/9.1/static/sql-createtable.html)
613
    # If into is not a temp table, ANALYZE is useful but not required.
614 3073 aaronmk
    analyze(db, into)
615 2790 aaronmk
616
    return cur
617 2085 aaronmk
618 2120 aaronmk
order_by_pkey = object() # tells mk_select() to order by the pkey
619
620 2199 aaronmk
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
621
622 2233 aaronmk
def mk_select(db, tables, fields=None, conds=None, distinct_on=[], limit=None,
623 2293 aaronmk
    start=None, order_by=order_by_pkey, default_table=None):
624 1981 aaronmk
    '''
625 2121 aaronmk
    @param tables The single table to select from, or a list of tables to join
626 2280 aaronmk
        together, with tables after the first being sql_gen.Join objects
627 1981 aaronmk
    @param fields Use None to select all fields in the table
628 2377 aaronmk
    @param conds WHERE conditions: [(compare_left_side, compare_right_side),...]
629 2379 aaronmk
        * container can be any iterable type
630 2399 aaronmk
        * compare_left_side: sql_gen.Code|str (for col name)
631
        * compare_right_side: sql_gen.ValueCond|literal value
632 2199 aaronmk
    @param distinct_on The columns to SELECT DISTINCT ON, or distinct_on_all to
633
        use all columns
634 2786 aaronmk
    @return query
635 1981 aaronmk
    '''
636 2315 aaronmk
    # Parse tables param
637 2964 aaronmk
    tables = lists.mk_seq(tables)
638 2141 aaronmk
    tables = list(tables) # don't modify input! (list() copies input)
639 2315 aaronmk
    table0 = sql_gen.as_Table(tables.pop(0)) # first table is separate
640 2121 aaronmk
641 2315 aaronmk
    # Parse other params
642 2376 aaronmk
    if conds == None: conds = []
643 2650 aaronmk
    elif dicts.is_dict(conds): conds = conds.items()
644 2379 aaronmk
    conds = list(conds) # don't modify input! (list() copies input)
645 3129 aaronmk
    assert limit == None or isinstance(limit, (int, long))
646
    assert start == None or isinstance(start, (int, long))
647 2315 aaronmk
    if order_by is order_by_pkey:
648
        if distinct_on != []: order_by = None
649
        else: order_by = pkey(db, table0, recover=True)
650 865 aaronmk
651 2315 aaronmk
    query = 'SELECT'
652 2056 aaronmk
653 2315 aaronmk
    def parse_col(col): return sql_gen.as_Col(col, default_table).to_str(db)
654 2056 aaronmk
655 2200 aaronmk
    # DISTINCT ON columns
656 2233 aaronmk
    if distinct_on != []:
657 2467 aaronmk
        query += '\nDISTINCT'
658 2254 aaronmk
        if distinct_on is not distinct_on_all:
659 2200 aaronmk
            query += ' ON ('+(', '.join(map(parse_col, distinct_on)))+')'
660
661
    # Columns
662 3185 aaronmk
    if query.find('\n') >= 0: whitespace = '\n'
663
    else: whitespace = ' '
664
    if fields == None: query += whitespace+'*'
665 2765 aaronmk
    else:
666
        assert fields != []
667 3185 aaronmk
        if len(fields) > 1: whitespace = '\n'
668
        query += whitespace+('\n, '.join(map(parse_col, fields)))
669 2200 aaronmk
670
    # Main table
671 3185 aaronmk
    if query.find('\n') >= 0 or len(tables) > 0: whitespace = '\n'
672
    else: whitespace = ' '
673
    query += whitespace+'FROM '+table0.to_str(db)
674 865 aaronmk
675 2122 aaronmk
    # Add joins
676 2271 aaronmk
    left_table = table0
677 2263 aaronmk
    for join_ in tables:
678
        table = join_.table
679 2238 aaronmk
680 2343 aaronmk
        # Parse special values
681
        if join_.type_ is sql_gen.filter_out: # filter no match
682 2376 aaronmk
            conds.append((sql_gen.Col(table_not_null_col(db, table), table),
683 2853 aaronmk
                sql_gen.CompareCond(None, '~=')))
684 2343 aaronmk
685 2467 aaronmk
        query += '\n'+join_.to_str(db, left_table)
686 2122 aaronmk
687
        left_table = table
688
689 865 aaronmk
    missing = True
690 2376 aaronmk
    if conds != []:
691 2576 aaronmk
        if len(conds) == 1: whitespace = ' '
692
        else: whitespace = '\n'
693 2578 aaronmk
        query += '\n'+sql_gen.combine_conds([sql_gen.ColValueCond(l, r)
694
            .to_str(db) for l, r in conds], 'WHERE')
695 865 aaronmk
        missing = False
696 2227 aaronmk
    if order_by != None:
697 2467 aaronmk
        query += '\nORDER BY '+sql_gen.as_Col(order_by, table0).to_str(db)
698
    if limit != None: query += '\nLIMIT '+str(limit); missing = False
699 865 aaronmk
    if start != None:
700 2467 aaronmk
        if start != 0: query += '\nOFFSET '+str(start)
701 865 aaronmk
        missing = False
702
    if missing: warnings.warn(DbWarning(
703
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
704
705 2786 aaronmk
    return query
706 11 aaronmk
707 2054 aaronmk
def select(db, *args, **kw_args):
708
    '''For params, see mk_select() and run_query()'''
709
    recover = kw_args.pop('recover', None)
710
    cacheable = kw_args.pop('cacheable', True)
711 2442 aaronmk
    log_level = kw_args.pop('log_level', 2)
712 2054 aaronmk
713 2791 aaronmk
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
714
        log_level=log_level)
715 2054 aaronmk
716 2788 aaronmk
def mk_insert_select(db, table, cols=None, select_query=None, returning=None,
717 3181 aaronmk
    embeddable=False, ignore=False, src=None):
718 1960 aaronmk
    '''
719
    @param returning str|None An inserted column (such as pkey) to return
720 2070 aaronmk
    @param embeddable Whether the query should be embeddable as a nested SELECT.
721 2073 aaronmk
        Warning: If you set this and cacheable=True when the query is run, the
722
        query will be fully cached, not just if it raises an exception.
723 3009 aaronmk
    @param ignore Whether to ignore duplicate keys.
724 3181 aaronmk
    @param src Will be included in the name of any created function, to help
725
        identify the data source in pg_stat_activity.
726 1960 aaronmk
    '''
727 2754 aaronmk
    table = sql_gen.remove_table_rename(sql_gen.as_Table(table))
728 2318 aaronmk
    if cols == []: cols = None # no cols (all defaults) = unknown col names
729 3010 aaronmk
    if cols != None: cols = [sql_gen.to_name_only_col(c, table) for c in cols]
730 2063 aaronmk
    if select_query == None: select_query = 'DEFAULT VALUES'
731 2327 aaronmk
    if returning != None: returning = sql_gen.as_Col(returning, table)
732 2063 aaronmk
733 2497 aaronmk
    first_line = 'INSERT INTO '+table.to_str(db)
734 2063 aaronmk
735 3009 aaronmk
    def mk_insert(select_query):
736
        query = first_line
737 3014 aaronmk
        if cols != None:
738
            query += '\n('+(', '.join((c.to_str(db) for c in cols)))+')'
739 3009 aaronmk
        query += '\n'+select_query
740
741
        if returning != None:
742
            returning_name_col = sql_gen.to_name_only_col(returning)
743
            query += '\nRETURNING '+returning_name_col.to_str(db)
744
745
        return query
746 2063 aaronmk
747 3017 aaronmk
    return_type = 'unknown'
748
    if returning != None: return_type = returning.to_str(db)+'%TYPE'
749
750 3009 aaronmk
    lang = 'sql'
751
    if ignore:
752 3017 aaronmk
        # Always return something to set the correct rowcount
753
        if returning == None: returning = sql_gen.NamedCol('NULL', None)
754
755 3009 aaronmk
        embeddable = True # must use function
756
        lang = 'plpgsql'
757 3010 aaronmk
758 3092 aaronmk
        if cols == None:
759
            row = [sql_gen.Col(sql_gen.all_cols, 'row')]
760
            row_vars = [sql_gen.Table('row')]
761
        else:
762
            row_vars = row = [sql_gen.Col(c.name, 'row') for c in cols]
763
764 3009 aaronmk
        query = '''\
765 3010 aaronmk
DECLARE
766 3014 aaronmk
    row '''+table.to_str(db)+'''%ROWTYPE;
767 3009 aaronmk
BEGIN
768 3019 aaronmk
    /* Need an EXCEPTION block for each individual row because "When an error is
769
    caught by an EXCEPTION clause, [...] all changes to persistent database
770
    state within the block are rolled back."
771
    This is unfortunate because "A block containing an EXCEPTION clause is
772
    significantly more expensive to enter and exit than a block without one."
773 3015 aaronmk
    (http://www.postgresql.org/docs/8.3/static/plpgsql-control-structures.html\
774
#PLPGSQL-ERROR-TRAPPING)
775
    */
776 3092 aaronmk
    FOR '''+(', '.join((v.to_str(db) for v in row_vars)))+''' IN
777 3034 aaronmk
'''+select_query+'''
778
    LOOP
779 3015 aaronmk
        BEGIN
780 3019 aaronmk
            RETURN QUERY
781 3014 aaronmk
'''+mk_insert(sql_gen.Values(row).to_str(db))+'''
782 3010 aaronmk
;
783 3015 aaronmk
        EXCEPTION
784 3019 aaronmk
            WHEN unique_violation THEN NULL; -- continue to next row
785 3015 aaronmk
        END;
786 3010 aaronmk
    END LOOP;
787
END;\
788 3009 aaronmk
'''
789
    else: query = mk_insert(select_query)
790
791 2070 aaronmk
    if embeddable:
792
        # Create function
793 2513 aaronmk
        function_name = sql_gen.clean_name(first_line)
794 3181 aaronmk
        if src != None: function_name = src+': '+function_name
795 2189 aaronmk
        while True:
796
            try:
797 2918 aaronmk
                function = db.TempFunction(function_name)
798 2194 aaronmk
799 2189 aaronmk
                function_query = '''\
800 2698 aaronmk
CREATE FUNCTION '''+function.to_str(db)+'''()
801 3017 aaronmk
RETURNS SETOF '''+return_type+'''
802 3009 aaronmk
LANGUAGE '''+lang+'''
803 2467 aaronmk
AS $$
804 3009 aaronmk
'''+query+'''
805 2467 aaronmk
$$;
806 2070 aaronmk
'''
807 2446 aaronmk
                run_query(db, function_query, recover=True, cacheable=True,
808 2945 aaronmk
                    log_ignore_excs=(DuplicateException,))
809 2189 aaronmk
                break # this version was successful
810 2945 aaronmk
            except DuplicateException, e:
811 2189 aaronmk
                function_name = next_version(function_name)
812
                # try again with next version of name
813 2070 aaronmk
814 2337 aaronmk
        # Return query that uses function
815 3009 aaronmk
        cols = None
816
        if returning != None: cols = [returning]
817 2698 aaronmk
        func_table = sql_gen.NamedTable('f', sql_gen.FunctionCall(function),
818 3009 aaronmk
            cols) # AS clause requires function alias
819 2787 aaronmk
        return mk_select(db, func_table, start=0, order_by=None)
820 2070 aaronmk
821 2787 aaronmk
    return query
822 2066 aaronmk
823 3074 aaronmk
def insert_select(db, table, *args, **kw_args):
824 2085 aaronmk
    '''For params, see mk_insert_select() and run_query_into()
825 2386 aaronmk
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
826
        values in
827 2072 aaronmk
    '''
828 3141 aaronmk
    returning = kw_args.get('returning', None)
829
    ignore = kw_args.get('ignore', False)
830
831 2386 aaronmk
    into = kw_args.pop('into', None)
832
    if into != None: kw_args['embeddable'] = True
833 2066 aaronmk
    recover = kw_args.pop('recover', None)
834 3141 aaronmk
    if ignore: recover = True
835 2066 aaronmk
    cacheable = kw_args.pop('cacheable', True)
836 2673 aaronmk
    log_level = kw_args.pop('log_level', 2)
837 2066 aaronmk
838 3141 aaronmk
    rowcount_only = ignore and returning == None # keep NULL rows on server
839
    if rowcount_only: into = sql_gen.Table('rowcount')
840
841 3074 aaronmk
    cur = run_query_into(db, mk_insert_select(db, table, *args, **kw_args),
842
        into, recover=recover, cacheable=cacheable, log_level=log_level)
843 3141 aaronmk
    if rowcount_only: empty_temp(db, into)
844 3074 aaronmk
    autoanalyze(db, table)
845
    return cur
846 2063 aaronmk
847 2738 aaronmk
default = sql_gen.default # tells insert() to use the default value for a column
848 2066 aaronmk
849 2063 aaronmk
def insert(db, table, row, *args, **kw_args):
850 2085 aaronmk
    '''For params, see insert_select()'''
851 1960 aaronmk
    if lists.is_seq(row): cols = None
852
    else:
853
        cols = row.keys()
854
        row = row.values()
855 2738 aaronmk
    row = list(row) # ensure that "== []" works
856 1960 aaronmk
857 2738 aaronmk
    if row == []: query = None
858
    else: query = sql_gen.Values(row).to_str(db)
859 1961 aaronmk
860 2788 aaronmk
    return insert_select(db, table, cols, query, *args, **kw_args)
861 11 aaronmk
862 3152 aaronmk
def mk_update(db, table, changes=None, cond=None, in_place=False,
863 3153 aaronmk
    cacheable_=True):
864 2402 aaronmk
    '''
865
    @param changes [(col, new_value),...]
866
        * container can be any iterable type
867
        * col: sql_gen.Code|str (for col name)
868
        * new_value: sql_gen.Code|literal value
869
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
870 3056 aaronmk
    @param in_place If set, locks the table and updates rows in place.
871
        This avoids creating dead rows in PostgreSQL.
872
        * cond must be None
873 3153 aaronmk
    @param cacheable_ Whether column structure information used to generate the
874 3152 aaronmk
        query can be cached
875 2402 aaronmk
    @return str query
876
    '''
877 3057 aaronmk
    table = sql_gen.as_Table(table)
878
    changes = [(sql_gen.to_name_only_col(c, table), sql_gen.as_Value(v))
879
        for c, v in changes]
880
881 3056 aaronmk
    if in_place:
882
        assert cond == None
883 3058 aaronmk
884 3065 aaronmk
        query = 'ALTER TABLE '+table.to_str(db)+'\n'
885
        query += ',\n'.join(('ALTER COLUMN '+c.to_str(db)+' TYPE '
886 3153 aaronmk
            +db.col_info(sql_gen.with_default_table(c, table), cacheable_).type
887 3065 aaronmk
            +'\nUSING '+v.to_str(db) for c, v in changes))
888 3058 aaronmk
    else:
889
        query = 'UPDATE '+table.to_str(db)+'\nSET\n'
890
        query += ',\n'.join((c.to_str(db)+' = '+v.to_str(db)
891
            for c, v in changes))
892
        if cond != None: query += '\nWHERE\n'+cond.to_str(db)
893 3056 aaronmk
894 2402 aaronmk
    return query
895
896 3074 aaronmk
def update(db, table, *args, **kw_args):
897 2402 aaronmk
    '''For params, see mk_update() and run_query()'''
898
    recover = kw_args.pop('recover', None)
899 3043 aaronmk
    cacheable = kw_args.pop('cacheable', False)
900 3030 aaronmk
    log_level = kw_args.pop('log_level', 2)
901 2402 aaronmk
902 3074 aaronmk
    cur = run_query(db, mk_update(db, table, *args, **kw_args), recover,
903
        cacheable, log_level=log_level)
904
    autoanalyze(db, table)
905
    return cur
906 2402 aaronmk
907 135 aaronmk
def last_insert_id(db):
908 1849 aaronmk
    module = util.root_module(db.db)
909 135 aaronmk
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
910
    elif module == 'MySQLdb': return db.insert_id()
911
    else: return None
912 13 aaronmk
913 2394 aaronmk
def mk_flatten_mapping(db, into, cols, preserve=[], as_items=False):
914 2383 aaronmk
    '''Creates a mapping from original column names (which may have collisions)
915 2415 aaronmk
    to names that will be distinct among the columns' tables.
916 2383 aaronmk
    This is meant to be used for several tables that are being joined together.
917 2415 aaronmk
    @param cols The columns to combine. Duplicates will be removed.
918
    @param into The table for the new columns.
919 2394 aaronmk
    @param preserve [sql_gen.Col...] Columns not to rename. Note that these
920
        columns will be included in the mapping even if they are not in cols.
921
        The tables of the provided Col objects will be changed to into, so make
922
        copies of them if you want to keep the original tables.
923
    @param as_items Whether to return a list of dict items instead of a dict
924 2383 aaronmk
    @return dict(orig_col=new_col, ...)
925
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
926 2392 aaronmk
        * new_col: sql_gen.Col(orig_col_name, into)
927
        * All mappings use the into table so its name can easily be
928 2383 aaronmk
          changed for all columns at once
929
    '''
930 2415 aaronmk
    cols = lists.uniqify(cols)
931
932 2394 aaronmk
    items = []
933 2389 aaronmk
    for col in preserve:
934 2390 aaronmk
        orig_col = copy.copy(col)
935 2392 aaronmk
        col.table = into
936 2394 aaronmk
        items.append((orig_col, col))
937
    preserve = set(preserve)
938
    for col in cols:
939 2716 aaronmk
        if col not in preserve:
940
            items.append((col, sql_gen.Col(str(col), into, col.srcs)))
941 2394 aaronmk
942
    if not as_items: items = dict(items)
943
    return items
944 2383 aaronmk
945 2393 aaronmk
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
946 2391 aaronmk
    '''For params, see mk_flatten_mapping()
947
    @return See return value of mk_flatten_mapping()
948
    '''
949 2394 aaronmk
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
950
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
951 2786 aaronmk
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
952 3166 aaronmk
        into=into)
953 2394 aaronmk
    return dict(items)
954 2391 aaronmk
955 3079 aaronmk
##### Database structure introspection
956 2414 aaronmk
957 3079 aaronmk
#### Tables
958
959
def tables(db, schema_like='public', table_like='%', exact=False):
960
    if exact: compare = '='
961
    else: compare = 'LIKE'
962
963
    module = util.root_module(db.db)
964
    if module == 'psycopg2':
965
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
966
            ('tablename', sql_gen.CompareCond(table_like, compare))]
967
        return values(select(db, 'pg_tables', ['tablename'], conds,
968
            order_by='tablename', log_level=4))
969
    elif module == 'MySQLdb':
970
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
971
            , cacheable=True, log_level=4))
972
    else: raise NotImplementedError("Can't list tables for "+module+' database')
973
974
def table_exists(db, table):
975
    table = sql_gen.as_Table(table)
976
    return list(tables(db, table.schema, table.name, exact=True)) != []
977
978 2426 aaronmk
def table_row_count(db, table, recover=None):
979 2786 aaronmk
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
980 2443 aaronmk
        order_by=None, start=0), recover=recover, log_level=3))
981 2426 aaronmk
982 2414 aaronmk
def table_cols(db, table, recover=None):
983
    return list(col_names(select(db, table, limit=0, order_by=None,
984 2443 aaronmk
        recover=recover, log_level=4)))
985 2414 aaronmk
986 2291 aaronmk
def pkey(db, table, recover=None):
987 832 aaronmk
    '''Assumed to be first column in table'''
988 2339 aaronmk
    return table_cols(db, table, recover)[0]
989 832 aaronmk
990 2559 aaronmk
not_null_col = 'not_null_col'
991 2340 aaronmk
992
def table_not_null_col(db, table, recover=None):
993
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
994
    if not_null_col in table_cols(db, table, recover): return not_null_col
995
    else: return pkey(db, table, recover)
996
997 853 aaronmk
def index_cols(db, table, index):
998
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
999
    automatically created. When you don't know whether something is a UNIQUE
1000
    constraint or a UNIQUE index, use this function.'''
1001 1909 aaronmk
    module = util.root_module(db.db)
1002
    if module == 'psycopg2':
1003
        return list(values(run_query(db, '''\
1004 853 aaronmk
SELECT attname
1005 866 aaronmk
FROM
1006
(
1007
        SELECT attnum, attname
1008
        FROM pg_index
1009
        JOIN pg_class index ON index.oid = indexrelid
1010
        JOIN pg_class table_ ON table_.oid = indrelid
1011
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
1012
        WHERE
1013 2782 aaronmk
            table_.relname = '''+db.esc_value(table)+'''
1014
            AND index.relname = '''+db.esc_value(index)+'''
1015 866 aaronmk
    UNION
1016
        SELECT attnum, attname
1017
        FROM
1018
        (
1019
            SELECT
1020
                indrelid
1021
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
1022
                    AS indkey
1023
            FROM pg_index
1024
            JOIN pg_class index ON index.oid = indexrelid
1025
            JOIN pg_class table_ ON table_.oid = indrelid
1026
            WHERE
1027 2782 aaronmk
                table_.relname = '''+db.esc_value(table)+'''
1028
                AND index.relname = '''+db.esc_value(index)+'''
1029 866 aaronmk
        ) s
1030
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
1031
) s
1032 853 aaronmk
ORDER BY attnum
1033 2782 aaronmk
'''
1034
            , cacheable=True, log_level=4)))
1035 1909 aaronmk
    else: raise NotImplementedError("Can't list index columns for "+module+
1036
        ' database')
1037 853 aaronmk
1038 464 aaronmk
def constraint_cols(db, table, constraint):
1039 1849 aaronmk
    module = util.root_module(db.db)
1040 464 aaronmk
    if module == 'psycopg2':
1041
        return list(values(run_query(db, '''\
1042
SELECT attname
1043
FROM pg_constraint
1044
JOIN pg_class ON pg_class.oid = conrelid
1045
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
1046
WHERE
1047 2783 aaronmk
    relname = '''+db.esc_value(table)+'''
1048
    AND conname = '''+db.esc_value(constraint)+'''
1049 464 aaronmk
ORDER BY attnum
1050 2783 aaronmk
'''
1051
            )))
1052 464 aaronmk
    else: raise NotImplementedError("Can't list constraint columns for "+module+
1053
        ' database')
1054
1055 3079 aaronmk
#### Functions
1056
1057
def function_exists(db, function):
1058
    function = sql_gen.as_Function(function)
1059
1060
    info_table = sql_gen.Table('routines', 'information_schema')
1061
    conds = [('routine_name', function.name)]
1062
    schema = function.schema
1063
    if schema != None: conds.append(('routine_schema', schema))
1064
    # Exclude trigger functions, since they cannot be called directly
1065
    conds.append(('data_type', sql_gen.CompareCond('trigger', '!=')))
1066
1067
    return list(values(select(db, info_table, ['routine_name'], conds,
1068
        order_by='routine_schema', limit=1, log_level=4))) != []
1069
        # TODO: order_by search_path schema order
1070
1071
##### Structural changes
1072
1073
#### Columns
1074
1075
def add_col(db, table, col, comment=None, **kw_args):
1076
    '''
1077
    @param col TypedCol Name may be versioned, so be sure to propagate any
1078
        renaming back to any source column for the TypedCol.
1079
    @param comment None|str SQL comment used to distinguish columns of the same
1080
        name from each other when they contain different data, to allow the
1081
        ADD COLUMN query to be cached. If not set, query will not be cached.
1082
    '''
1083
    assert isinstance(col, sql_gen.TypedCol)
1084
1085
    while True:
1086
        str_ = 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '+col.to_str(db)
1087
        if comment != None: str_ += ' '+sql_gen.esc_comment(comment)
1088
1089
        try:
1090
            run_query(db, str_, recover=True, cacheable=True, **kw_args)
1091
            break
1092
        except DuplicateException:
1093
            col.name = next_version(col.name)
1094
            # try again with next version of name
1095
1096
def add_not_null(db, col):
1097
    table = col.table
1098
    col = sql_gen.to_name_only_col(col)
1099
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1100
        +col.to_str(db)+' SET NOT NULL', cacheable=True, log_level=3)
1101
1102 2096 aaronmk
row_num_col = '_row_num'
1103
1104 3079 aaronmk
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1105
    constraints='PRIMARY KEY')
1106
1107
def add_row_num(db, table):
1108
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1109
    be the primary key.'''
1110
    add_col(db, table, row_num_typed_col, log_level=3)
1111
1112
#### Indexes
1113
1114
def add_pkey(db, table, cols=None, recover=None):
1115
    '''Adds a primary key.
1116
    @param cols [sql_gen.Col,...] The columns in the primary key.
1117
        Defaults to the first column in the table.
1118
    @pre The table must not already have a primary key.
1119
    '''
1120
    table = sql_gen.as_Table(table)
1121
    if cols == None: cols = [pkey(db, table, recover)]
1122
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1123
1124
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1125
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1126
        log_ignore_excs=(DuplicateException,))
1127
1128 2998 aaronmk
def add_index(db, exprs, table=None, unique=False, ensure_not_null_=True):
1129 2688 aaronmk
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
1130 2538 aaronmk
    Currently, only function calls are supported as expressions.
1131 2998 aaronmk
    @param ensure_not_null_ If set, translates NULL values to sentinel values.
1132 2847 aaronmk
        This allows indexes to be used for comparisons where NULLs are equal.
1133 2538 aaronmk
    '''
1134 2964 aaronmk
    exprs = lists.mk_seq(exprs)
1135 2538 aaronmk
1136 2688 aaronmk
    # Parse exprs
1137
    old_exprs = exprs[:]
1138
    exprs = []
1139
    cols = []
1140
    for i, expr in enumerate(old_exprs):
1141 2823 aaronmk
        expr = sql_gen.as_Col(expr, table)
1142 2688 aaronmk
1143 2823 aaronmk
        # Handle nullable columns
1144 2998 aaronmk
        if ensure_not_null_:
1145 3164 aaronmk
            try: expr = sql_gen.ensure_not_null(db, expr)
1146 2860 aaronmk
            except KeyError: pass # unknown type, so just create plain index
1147 2823 aaronmk
1148 2688 aaronmk
        # Extract col
1149 3002 aaronmk
        expr = copy.deepcopy(expr) # don't modify input!
1150 2688 aaronmk
        if isinstance(expr, sql_gen.FunctionCall):
1151
            col = expr.args[0]
1152
            expr = sql_gen.Expr(expr)
1153
        else: col = expr
1154 2823 aaronmk
        assert isinstance(col, sql_gen.Col)
1155 2688 aaronmk
1156
        # Extract table
1157
        if table == None:
1158
            assert sql_gen.is_table_col(col)
1159
            table = col.table
1160
1161
        col.table = None
1162
1163
        exprs.append(expr)
1164
        cols.append(col)
1165 2408 aaronmk
1166 2688 aaronmk
    table = sql_gen.as_Table(table)
1167
1168 3005 aaronmk
    # Add index
1169 3148 aaronmk
    str_ = 'CREATE'
1170
    if unique: str_ += ' UNIQUE'
1171
    str_ += ' INDEX ON '+table.to_str(db)+' ('+(
1172
        ', '.join((v.to_str(db) for v in exprs)))+')'
1173
    run_query(db, str_, recover=True, cacheable=True, log_level=3)
1174 2408 aaronmk
1175 3083 aaronmk
already_indexed = object() # tells add_indexes() the pkey has already been added
1176
1177
def add_indexes(db, table, has_pkey=True):
1178
    '''Adds an index on all columns in a table.
1179
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1180
        index should be added on the first column.
1181
        * If already_indexed, the pkey is assumed to have already been added
1182
    '''
1183
    cols = table_cols(db, table)
1184
    if has_pkey:
1185
        if has_pkey is not already_indexed: add_pkey(db, table)
1186
        cols = cols[1:]
1187
    for col in cols: add_index(db, col, table)
1188
1189 3079 aaronmk
#### Tables
1190 2772 aaronmk
1191 3079 aaronmk
### Maintenance
1192 2772 aaronmk
1193 3079 aaronmk
def analyze(db, table):
1194
    table = sql_gen.as_Table(table)
1195
    run_query(db, 'ANALYZE '+table.to_str(db), log_level=3)
1196 2934 aaronmk
1197 3079 aaronmk
def autoanalyze(db, table):
1198
    if db.autoanalyze: analyze(db, table)
1199 2935 aaronmk
1200 3079 aaronmk
def vacuum(db, table):
1201
    table = sql_gen.as_Table(table)
1202
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1203
        log_level=3))
1204 2086 aaronmk
1205 3079 aaronmk
### Lifecycle
1206
1207 3247 aaronmk
def drop(db, type_, name):
1208
    name = sql_gen.as_Name(name)
1209
    run_query(db, 'DROP '+type_+' IF EXISTS '+name.to_str(db)+' CASCADE')
1210 2889 aaronmk
1211 3247 aaronmk
def drop_table(db, table): drop(db, 'TABLE', table)
1212
1213 3082 aaronmk
def create_table(db, table, cols=[], has_pkey=True, col_indexes=True,
1214
    like=None):
1215 2675 aaronmk
    '''Creates a table.
1216 2681 aaronmk
    @param cols [sql_gen.TypedCol,...] The column names and types
1217
    @param has_pkey If set, the first column becomes the primary key.
1218 2760 aaronmk
    @param col_indexes bool|[ref]
1219
        * If True, indexes will be added on all non-pkey columns.
1220
        * If a list reference, [0] will be set to a function to do this.
1221
          This can be used to delay index creation until the table is populated.
1222 2675 aaronmk
    '''
1223
    table = sql_gen.as_Table(table)
1224
1225 3082 aaronmk
    if like != None:
1226
        cols = [sql_gen.CustomCode('LIKE '+like.to_str(db)+' INCLUDING ALL')
1227
            ]+cols
1228 2681 aaronmk
    if has_pkey:
1229
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1230 2872 aaronmk
        pkey.constraints = 'PRIMARY KEY'
1231 2681 aaronmk
1232 3085 aaronmk
    temp = table.is_temp and not db.debug_temp
1233
        # temp tables permanent in debug_temp mode
1234 2760 aaronmk
1235 3085 aaronmk
    # Create table
1236
    while True:
1237
        str_ = 'CREATE'
1238
        if temp: str_ += ' TEMP'
1239
        str_ += ' TABLE '+table.to_str(db)+' (\n'
1240
        str_ += '\n, '.join(c.to_str(db) for c in cols)
1241 3126 aaronmk
        str_ += '\n);'
1242 3085 aaronmk
1243
        try:
1244 3127 aaronmk
            run_query(db, str_, recover=True, cacheable=True, log_level=2,
1245 3085 aaronmk
                log_ignore_excs=(DuplicateException,))
1246
            break
1247
        except DuplicateException:
1248
            table.name = next_version(table.name)
1249
            # try again with next version of name
1250
1251 2760 aaronmk
    # Add indexes
1252 2773 aaronmk
    if has_pkey: has_pkey = already_indexed
1253
    def add_indexes_(): add_indexes(db, table, has_pkey)
1254
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1255
    elif col_indexes: add_indexes_() # add now
1256 2675 aaronmk
1257 3084 aaronmk
def copy_table_struct(db, src, dest):
1258
    '''Creates a structure-only copy of a table. (Does not copy data.)'''
1259 3085 aaronmk
    create_table(db, dest, has_pkey=False, col_indexes=False, like=src)
1260 3084 aaronmk
1261 3079 aaronmk
### Data
1262 2684 aaronmk
1263 2970 aaronmk
def truncate(db, table, schema='public', **kw_args):
1264
    '''For params, see run_query()'''
1265 2777 aaronmk
    table = sql_gen.as_Table(table, schema)
1266 2970 aaronmk
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1267 2732 aaronmk
1268 2965 aaronmk
def empty_temp(db, tables):
1269
    tables = lists.mk_seq(tables)
1270 2971 aaronmk
    for table in tables: truncate(db, table, log_level=3)
1271 2965 aaronmk
1272 1968 aaronmk
def empty_db(db, schema='public', **kw_args):
1273
    '''For kw_args, see tables()'''
1274
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1275 3094 aaronmk
1276
def distinct_table(db, table, distinct_on):
1277
    '''Creates a copy of a temp table which is distinct on the given columns.
1278 3099 aaronmk
    The old and new tables will both get an index on these columns, to
1279
    facilitate merge joins.
1280 3097 aaronmk
    @param distinct_on If empty, creates a table with one row. This is useful if
1281
        your distinct_on columns are all literal values.
1282 3099 aaronmk
    @return The new table.
1283 3094 aaronmk
    '''
1284 3099 aaronmk
    new_table = sql_gen.suffixed_table(table, '_distinct')
1285 3094 aaronmk
1286 3099 aaronmk
    copy_table_struct(db, table, new_table)
1287 3097 aaronmk
1288
    limit = None
1289
    if distinct_on == []: limit = 1 # one sample row
1290 3099 aaronmk
    else:
1291
        add_index(db, distinct_on, new_table, unique=True)
1292
        add_index(db, distinct_on, table) # for join optimization
1293 3097 aaronmk
1294 3099 aaronmk
    insert_select(db, new_table, None, mk_select(db, table, start=0,
1295 3097 aaronmk
        limit=limit), ignore=True)
1296 3099 aaronmk
    analyze(db, new_table)
1297 3094 aaronmk
1298 3099 aaronmk
    return new_table