Project

General

Profile

1 11 aaronmk
# Database access
2
3 1869 aaronmk
import copy
4 2127 aaronmk
import operator
5 11 aaronmk
import re
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 1889 aaronmk
from Proxy import Proxy
13 1872 aaronmk
import rand
14 2217 aaronmk
import sql_gen
15 862 aaronmk
import strings
16 131 aaronmk
import util
17 11 aaronmk
18 832 aaronmk
##### Exceptions
19
20 2170 aaronmk
def get_cur_query(cur, input_query=None, input_params=None):
21 2168 aaronmk
    raw_query = None
22
    if hasattr(cur, 'query'): raw_query = cur.query
23
    elif hasattr(cur, '_last_executed'): raw_query = cur._last_executed
24 2170 aaronmk
25
    if raw_query != None: return raw_query
26 2371 aaronmk
    else: return '[input] '+strings.ustr(input_query)+' % '+repr(input_params)
27 14 aaronmk
28 2170 aaronmk
def _add_cursor_info(e, *args, **kw_args):
29
    '''For params, see get_cur_query()'''
30 2771 aaronmk
    exc.add_msg(e, 'query: '+strings.ustr(get_cur_query(*args, **kw_args)))
31 135 aaronmk
32 300 aaronmk
class DbException(exc.ExceptionWithCause):
33 14 aaronmk
    def __init__(self, msg, cause=None, cur=None):
34 2145 aaronmk
        exc.ExceptionWithCause.__init__(self, msg, cause, cause_newline=True)
35 14 aaronmk
        if cur != None: _add_cursor_info(self, cur)
36
37 2143 aaronmk
class ExceptionWithName(DbException):
38
    def __init__(self, name, cause=None):
39 2484 aaronmk
        DbException.__init__(self, 'for name: '+strings.as_tt(str(name)), cause)
40 2143 aaronmk
        self.name = name
41 360 aaronmk
42 2240 aaronmk
class ExceptionWithNameValue(DbException):
43
    def __init__(self, name, value, cause=None):
44 2484 aaronmk
        DbException.__init__(self, 'for name: '+strings.as_tt(str(name))
45
            +'; value: '+strings.as_tt(repr(value)), cause)
46 2240 aaronmk
        self.name = name
47
        self.value = value
48
49 2306 aaronmk
class ConstraintException(DbException):
50
    def __init__(self, name, cols, cause=None):
51 2484 aaronmk
        DbException.__init__(self, 'Violated '+strings.as_tt(name)
52
            +' constraint on columns: '+strings.as_tt(', '.join(cols)), cause)
53 2306 aaronmk
        self.name = name
54 468 aaronmk
        self.cols = cols
55 11 aaronmk
56 2523 aaronmk
class MissingCastException(DbException):
57
    def __init__(self, type_, col, cause=None):
58
        DbException.__init__(self, 'Missing cast to type '+strings.as_tt(type_)
59
            +' on column: '+strings.as_tt(col), cause)
60
        self.type = type_
61
        self.col = col
62
63 2143 aaronmk
class NameException(DbException): pass
64
65 2306 aaronmk
class DuplicateKeyException(ConstraintException): pass
66 13 aaronmk
67 2306 aaronmk
class NullValueException(ConstraintException): pass
68 13 aaronmk
69 2240 aaronmk
class FunctionValueException(ExceptionWithNameValue): pass
70 2239 aaronmk
71 2143 aaronmk
class DuplicateTableException(ExceptionWithName): pass
72
73 2188 aaronmk
class DuplicateFunctionException(ExceptionWithName): pass
74
75 89 aaronmk
class EmptyRowException(DbException): pass
76
77 865 aaronmk
##### Warnings
78
79
class DbWarning(UserWarning): pass
80
81 1930 aaronmk
##### Result retrieval
82
83
def col_names(cur): return (col[0] for col in cur.description)
84
85
def rows(cur): return iter(lambda: cur.fetchone(), None)
86
87
def consume_rows(cur):
88
    '''Used to fetch all rows so result will be cached'''
89
    iters.consume_iter(rows(cur))
90
91
def next_row(cur): return rows(cur).next()
92
93
def row(cur):
94
    row_ = next_row(cur)
95
    consume_rows(cur)
96
    return row_
97
98
def next_value(cur): return next_row(cur)[0]
99
100
def value(cur): return row(cur)[0]
101
102
def values(cur): return iters.func_iter(lambda: next_value(cur))
103
104
def value_or_none(cur):
105
    try: return value(cur)
106
    except StopIteration: return None
107
108 2762 aaronmk
##### Escaping
109 2101 aaronmk
110 2573 aaronmk
def esc_name_by_module(module, name):
111
    if module == 'psycopg2' or module == None: quote = '"'
112 2101 aaronmk
    elif module == 'MySQLdb': quote = '`'
113
    else: raise NotImplementedError("Can't escape name for "+module+' database')
114 2500 aaronmk
    return sql_gen.esc_name(name, quote)
115 2101 aaronmk
116
def esc_name_by_engine(engine, name, **kw_args):
117
    return esc_name_by_module(db_engines[engine][0], name, **kw_args)
118
119
def esc_name(db, name, **kw_args):
120
    return esc_name_by_module(util.root_module(db.db), name, **kw_args)
121
122
def qual_name(db, schema, table):
123
    def esc_name_(name): return esc_name(db, name)
124
    table = esc_name_(table)
125
    if schema != None: return esc_name_(schema)+'.'+table
126
    else: return table
127
128 1869 aaronmk
##### Database connections
129 1849 aaronmk
130 2097 aaronmk
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
131 1926 aaronmk
132 1869 aaronmk
db_engines = {
133
    'MySQL': ('MySQLdb', {'password': 'passwd', 'database': 'db'}),
134
    'PostgreSQL': ('psycopg2', {}),
135
}
136
137
DatabaseErrors_set = set([DbException])
138
DatabaseErrors = tuple(DatabaseErrors_set)
139
140
def _add_module(module):
141
    DatabaseErrors_set.add(module.DatabaseError)
142
    global DatabaseErrors
143
    DatabaseErrors = tuple(DatabaseErrors_set)
144
145
def db_config_str(db_config):
146
    return db_config['engine']+' database '+db_config['database']
147
148 1909 aaronmk
def _query_lookup(query, params): return (query, dicts.make_hashable(params))
149 1894 aaronmk
150 2448 aaronmk
log_debug_none = lambda msg, level=2: None
151 1901 aaronmk
152 1849 aaronmk
class DbConn:
153 2190 aaronmk
    def __init__(self, db_config, serializable=True, autocommit=False,
154
        caching=True, log_debug=log_debug_none):
155 1869 aaronmk
        self.db_config = db_config
156
        self.serializable = serializable
157 2190 aaronmk
        self.autocommit = autocommit
158
        self.caching = caching
159 1901 aaronmk
        self.log_debug = log_debug
160 2193 aaronmk
        self.debug = log_debug != log_debug_none
161 1869 aaronmk
162
        self.__db = None
163 1889 aaronmk
        self.query_results = {}
164 2139 aaronmk
        self._savepoint = 0
165 2671 aaronmk
        self._notices_seen = set()
166 1869 aaronmk
167
    def __getattr__(self, name):
168
        if name == '__dict__': raise Exception('getting __dict__')
169
        if name == 'db': return self._db()
170
        else: raise AttributeError()
171
172
    def __getstate__(self):
173
        state = copy.copy(self.__dict__) # shallow copy
174 1915 aaronmk
        state['log_debug'] = None # don't pickle the debug callback
175 1869 aaronmk
        state['_DbConn__db'] = None # don't pickle the connection
176
        return state
177
178 2165 aaronmk
    def connected(self): return self.__db != None
179
180 1869 aaronmk
    def _db(self):
181
        if self.__db == None:
182
            # Process db_config
183
            db_config = self.db_config.copy() # don't modify input!
184 2097 aaronmk
            schemas = db_config.pop('schemas', None)
185 1869 aaronmk
            module_name, mappings = db_engines[db_config.pop('engine')]
186
            module = __import__(module_name)
187
            _add_module(module)
188
            for orig, new in mappings.iteritems():
189
                try: util.rename_key(db_config, orig, new)
190
                except KeyError: pass
191
192
            # Connect
193
            self.__db = module.connect(**db_config)
194
195
            # Configure connection
196 2676 aaronmk
            if self.serializable and not self.autocommit: self.run_query(
197 2678 aaronmk
                'SET TRANSACTION ISOLATION LEVEL SERIALIZABLE', log_level=4)
198 2101 aaronmk
            if schemas != None:
199
                schemas_ = ''.join((esc_name(self, s)+', '
200
                    for s in schemas.split(',')))
201 2792 aaronmk
                self.run_query("SELECT set_config('search_path', "
202
                    +self.esc_value(schemas_)
203
                    +" || current_setting('search_path'), false)", log_level=3)
204 1869 aaronmk
205
        return self.__db
206 1889 aaronmk
207 1891 aaronmk
    class DbCursor(Proxy):
208 1927 aaronmk
        def __init__(self, outer):
209 1891 aaronmk
            Proxy.__init__(self, outer.db.cursor())
210 2191 aaronmk
            self.outer = outer
211 1927 aaronmk
            self.query_results = outer.query_results
212 1894 aaronmk
            self.query_lookup = None
213 1891 aaronmk
            self.result = []
214 1889 aaronmk
215 1894 aaronmk
        def execute(self, query, params=None):
216 2784 aaronmk
            assert params == None or params == [] or params == ()
217 2763 aaronmk
            if params == [] or params == (): params = None
218
                # None turns off the mogrifier
219 2762 aaronmk
220 2764 aaronmk
            self._is_insert = query.startswith('INSERT')
221 1894 aaronmk
            self.query_lookup = _query_lookup(query, params)
222 2148 aaronmk
            try:
223 2191 aaronmk
                try:
224 2763 aaronmk
                    cur = self.inner.execute(query, params)
225 2191 aaronmk
                    self.outer.do_autocommit()
226 2648 aaronmk
                finally: self.query = get_cur_query(self.inner, query, params)
227 1904 aaronmk
            except Exception, e:
228 2170 aaronmk
                _add_cursor_info(e, self, query, params)
229 1904 aaronmk
                self.result = e # cache the exception as the result
230
                self._cache_result()
231
                raise
232 1930 aaronmk
            # Fetch all rows so result will be cached
233
            if self.rowcount == 0 and not self._is_insert: consume_rows(self)
234 2762 aaronmk
            return cur
235 1894 aaronmk
236 1891 aaronmk
        def fetchone(self):
237
            row = self.inner.fetchone()
238 1899 aaronmk
            if row != None: self.result.append(row)
239
            # otherwise, fetched all rows
240 1904 aaronmk
            else: self._cache_result()
241
            return row
242
243
        def _cache_result(self):
244 1906 aaronmk
            # For inserts, only cache exceptions since inserts are not
245
            # idempotent, but an invalid insert will always be invalid
246 1930 aaronmk
            if self.query_results != None and (not self._is_insert
247 1906 aaronmk
                or isinstance(self.result, Exception)):
248
249 1894 aaronmk
                assert self.query_lookup != None
250 1916 aaronmk
                self.query_results[self.query_lookup] = self.CacheCursor(
251
                    util.dict_subset(dicts.AttrsDictView(self),
252
                    ['query', 'result', 'rowcount', 'description']))
253 1906 aaronmk
254 1916 aaronmk
        class CacheCursor:
255
            def __init__(self, cached_result): self.__dict__ = cached_result
256
257 1927 aaronmk
            def execute(self, *args, **kw_args):
258 1916 aaronmk
                if isinstance(self.result, Exception): raise self.result
259
                # otherwise, result is a rows list
260
                self.iter = iter(self.result)
261
262
            def fetchone(self):
263
                try: return self.iter.next()
264
                except StopIteration: return None
265 1891 aaronmk
266 2212 aaronmk
    def esc_value(self, value):
267 2663 aaronmk
        try: str_ = self.mogrify('%s', [value])
268
        except NotImplementedError, e:
269
            module = util.root_module(self.db)
270
            if module == 'MySQLdb':
271
                import _mysql
272
                str_ = _mysql.escape_string(value)
273
            else: raise e
274 2374 aaronmk
        return strings.to_unicode(str_)
275 2212 aaronmk
276 2347 aaronmk
    def esc_name(self, name): return esc_name(self, name) # calls global func
277
278 2665 aaronmk
    def can_mogrify(self):
279 2663 aaronmk
        module = util.root_module(self.db)
280 2665 aaronmk
        return module == 'psycopg2'
281 2663 aaronmk
282 2665 aaronmk
    def mogrify(self, query, params=None):
283
        if self.can_mogrify(): return self.db.cursor().mogrify(query, params)
284
        else: raise NotImplementedError("Can't mogrify query")
285
286 2671 aaronmk
    def print_notices(self):
287 2725 aaronmk
        if hasattr(self.db, 'notices'):
288
            for msg in self.db.notices:
289
                if msg not in self._notices_seen:
290
                    self._notices_seen.add(msg)
291
                    self.log_debug(msg, level=2)
292 2671 aaronmk
293 2445 aaronmk
    def run_query(self, query, params=None, cacheable=False, log_level=2,
294 2464 aaronmk
        debug_msg_ref=None):
295 2445 aaronmk
        '''
296 2784 aaronmk
        @param params Not supported. Use self.esc_value() instead.
297 2464 aaronmk
        @param log_ignore_excs The log_level will be increased by 2 if the query
298
            throws one of these exceptions.
299 2664 aaronmk
        @param debug_msg_ref If specified, the log message will be returned in
300
            this instead of being output. This allows you to filter log messages
301
            depending on the result of the query.
302 2445 aaronmk
        '''
303 2167 aaronmk
        assert query != None
304
305 2047 aaronmk
        if not self.caching: cacheable = False
306 1903 aaronmk
        used_cache = False
307 2664 aaronmk
308
        def log_msg(query):
309
            if used_cache: cache_status = 'cache hit'
310
            elif cacheable: cache_status = 'cache miss'
311
            else: cache_status = 'non-cacheable'
312
            return 'DB query: '+cache_status+':\n'+strings.as_code(query, 'SQL')
313
314 1903 aaronmk
        try:
315 1927 aaronmk
            # Get cursor
316
            if cacheable:
317
                query_lookup = _query_lookup(query, params)
318
                try:
319
                    cur = self.query_results[query_lookup]
320
                    used_cache = True
321
                except KeyError: cur = self.DbCursor(self)
322
            else: cur = self.db.cursor()
323
324 2664 aaronmk
            # Log query
325
            if self.debug and debug_msg_ref == None: # log before running
326
                self.log_debug(log_msg(query), log_level)
327
328 1927 aaronmk
            # Run query
329 2148 aaronmk
            cur.execute(query, params)
330 1903 aaronmk
        finally:
331 2671 aaronmk
            self.print_notices()
332 2664 aaronmk
            if self.debug and debug_msg_ref != None: # return after running
333
                debug_msg_ref[0] = log_msg(str(get_cur_query(cur, query,
334
                    params)))
335 1903 aaronmk
336
        return cur
337 1914 aaronmk
338
    def is_cached(self, query, params=None):
339
        return _query_lookup(query, params) in self.query_results
340 2139 aaronmk
341 2683 aaronmk
    def with_autocommit(self, func, autocommit=True):
342
        prev_autocommit = self.db.autocommit
343
        self.db.autocommit = autocommit
344
        try: return func()
345
        finally: self.db.autocommit = prev_autocommit
346
347 2139 aaronmk
    def with_savepoint(self, func):
348 2171 aaronmk
        savepoint = 'level_'+str(self._savepoint)
349 2443 aaronmk
        self.run_query('SAVEPOINT '+savepoint, log_level=4)
350 2139 aaronmk
        self._savepoint += 1
351 2683 aaronmk
        try:
352 2139 aaronmk
            try: return_val = func()
353
            finally:
354
                self._savepoint -= 1
355
                assert self._savepoint >= 0
356
        except:
357 2443 aaronmk
            self.run_query('ROLLBACK TO SAVEPOINT '+savepoint, log_level=4)
358 2139 aaronmk
            raise
359
        else:
360 2443 aaronmk
            self.run_query('RELEASE SAVEPOINT '+savepoint, log_level=4)
361 2191 aaronmk
            self.do_autocommit()
362 2139 aaronmk
            return return_val
363 2191 aaronmk
364
    def do_autocommit(self):
365
        '''Autocommits if outside savepoint'''
366
        assert self._savepoint >= 0
367
        if self.autocommit and self._savepoint == 0:
368 2668 aaronmk
            self.log_debug('Autocommitting')
369 2191 aaronmk
            self.db.commit()
370 2643 aaronmk
371
    def col_default(self, col):
372
        table = sql_gen.Table('columns', 'information_schema')
373
374
        conds = [('table_name', col.table.name), ('column_name', col.name)]
375
        schema = col.table.schema
376
        if schema != None: conds.append(('table_schema', schema))
377
378 2660 aaronmk
        return sql_gen.as_Code(value(select(self, table, ['column_default'],
379
            conds, order_by='table_schema', limit=1, log_level=3)))
380 2643 aaronmk
            # TODO: order_by search_path schema order
381 1849 aaronmk
382 1869 aaronmk
connect = DbConn
383
384 832 aaronmk
##### Querying
385
386 1894 aaronmk
def run_raw_query(db, *args, **kw_args):
387 2085 aaronmk
    '''For params, see DbConn.run_query()'''
388 1894 aaronmk
    return db.run_query(*args, **kw_args)
389 11 aaronmk
390 2068 aaronmk
def mogrify(db, query, params):
391
    module = util.root_module(db.db)
392
    if module == 'psycopg2': return db.db.cursor().mogrify(query, params)
393
    else: raise NotImplementedError("Can't mogrify query for "+module+
394
        ' database')
395
396 832 aaronmk
##### Recoverable querying
397 15 aaronmk
398 2139 aaronmk
def with_savepoint(db, func): return db.with_savepoint(func)
399 11 aaronmk
400 2791 aaronmk
def run_query(db, query, recover=None, cacheable=False, log_level=2,
401
    log_ignore_excs=None, **kw_args):
402 2441 aaronmk
    '''For params, see run_raw_query()'''
403 830 aaronmk
    if recover == None: recover = False
404 2464 aaronmk
    if log_ignore_excs == None: log_ignore_excs = ()
405
    log_ignore_excs = tuple(log_ignore_excs)
406 830 aaronmk
407 2666 aaronmk
    debug_msg_ref = None # usually, db.run_query() logs query before running it
408
    # But if filtering with log_ignore_excs, wait until after exception parsing
409
    if log_ignore_excs != () or not db.can_mogrify(): debug_msg_ref = [None]
410
411 2148 aaronmk
    try:
412 2464 aaronmk
        try:
413 2791 aaronmk
            def run(): return run_raw_query(db, query, [], cacheable,
414 2464 aaronmk
                log_level, debug_msg_ref, **kw_args)
415 2791 aaronmk
            if recover and not db.is_cached(query, []):
416 2464 aaronmk
                return with_savepoint(db, run)
417
            else: return run() # don't need savepoint if cached
418
        except Exception, e:
419
            if not recover: raise # need savepoint to run index_cols()
420
            msg = exc.str_(e)
421
422
            match = re.search(r'duplicate key value violates unique constraint '
423 2493 aaronmk
                r'"((_?[^\W_]+)_.+?)"', msg)
424 2464 aaronmk
            if match:
425
                constraint, table = match.groups()
426
                try: cols = index_cols(db, table, constraint)
427
                except NotImplementedError: raise e
428
                else: raise DuplicateKeyException(constraint, cols, e)
429
430 2493 aaronmk
            match = re.search(r'null value in column "(.+?)" violates not-null'
431 2464 aaronmk
                r' constraint', msg)
432
            if match: raise NullValueException('NOT NULL', [match.group(1)], e)
433
434
            match = re.search(r'\b(?:invalid input (?:syntax|value)\b.*?'
435
                r'|date/time field value out of range): "(.+?)"\n'
436 2535 aaronmk
                r'(?:(?s).*?)\bfunction "(.+?)"', msg)
437 2464 aaronmk
            if match:
438
                value, name = match.groups()
439
                raise FunctionValueException(name, strings.to_unicode(value), e)
440
441 2526 aaronmk
            match = re.search(r'column "(.+?)" is of type (.+?) but expression '
442 2523 aaronmk
                r'is of type', msg)
443
            if match:
444
                col, type_ = match.groups()
445
                raise MissingCastException(type_, col, e)
446
447 2493 aaronmk
            match = re.search(r'relation "(.+?)" already exists', msg)
448 2464 aaronmk
            if match: raise DuplicateTableException(match.group(1), e)
449
450 2493 aaronmk
            match = re.search(r'function "(.+?)" already exists', msg)
451 2464 aaronmk
            if match: raise DuplicateFunctionException(match.group(1), e)
452
453
            raise # no specific exception raised
454
    except log_ignore_excs:
455
        log_level += 2
456
        raise
457
    finally:
458 2666 aaronmk
        if debug_msg_ref != None and debug_msg_ref[0] != None:
459
            db.log_debug(debug_msg_ref[0], log_level)
460 830 aaronmk
461 832 aaronmk
##### Basic queries
462
463 2153 aaronmk
def next_version(name):
464 2163 aaronmk
    version = 1 # first existing name was version 0
465 2586 aaronmk
    match = re.match(r'^(.*)#(\d+)$', name)
466 2153 aaronmk
    if match:
467 2586 aaronmk
        name, version = match.groups()
468
        version = int(version)+1
469 2588 aaronmk
    return sql_gen.add_suffix(name, '#'+str(version))
470 2153 aaronmk
471 2789 aaronmk
def run_query_into(db, query, into=None, add_indexes_=False, **kw_args):
472 2085 aaronmk
    '''Outputs a query to a temp table.
473
    For params, see run_query().
474
    '''
475 2789 aaronmk
    if into == None: return run_query(db, query, **kw_args)
476 2790 aaronmk
477
    assert isinstance(into, sql_gen.Table)
478
479
    kw_args['recover'] = True
480
    kw_args.setdefault('log_ignore_excs', (DuplicateTableException,))
481
482
    temp = not db.autocommit # tables are permanent in autocommit mode
483
    # "temporary tables cannot specify a schema name", so remove schema
484
    if temp: into.schema = None
485
486
    # Create table
487
    while True:
488
        create_query = 'CREATE'
489
        if temp: create_query += ' TEMP'
490
        create_query += ' TABLE '+into.to_str(db)+' AS\n'+query
491 2385 aaronmk
492 2790 aaronmk
        try:
493
            cur = run_query(db, create_query, **kw_args)
494
                # CREATE TABLE AS sets rowcount to # rows in query
495
            break
496
        except DuplicateTableException, e:
497
            into.name = next_version(into.name)
498
            # try again with next version of name
499
500
    if add_indexes_: add_indexes(db, into)
501
502
    return cur
503 2085 aaronmk
504 2120 aaronmk
order_by_pkey = object() # tells mk_select() to order by the pkey
505
506 2199 aaronmk
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
507
508 2233 aaronmk
def mk_select(db, tables, fields=None, conds=None, distinct_on=[], limit=None,
509 2293 aaronmk
    start=None, order_by=order_by_pkey, default_table=None):
510 1981 aaronmk
    '''
511 2121 aaronmk
    @param tables The single table to select from, or a list of tables to join
512 2280 aaronmk
        together, with tables after the first being sql_gen.Join objects
513 1981 aaronmk
    @param fields Use None to select all fields in the table
514 2377 aaronmk
    @param conds WHERE conditions: [(compare_left_side, compare_right_side),...]
515 2379 aaronmk
        * container can be any iterable type
516 2399 aaronmk
        * compare_left_side: sql_gen.Code|str (for col name)
517
        * compare_right_side: sql_gen.ValueCond|literal value
518 2199 aaronmk
    @param distinct_on The columns to SELECT DISTINCT ON, or distinct_on_all to
519
        use all columns
520 2786 aaronmk
    @return query
521 1981 aaronmk
    '''
522 2315 aaronmk
    # Parse tables param
523 2121 aaronmk
    if not lists.is_seq(tables): tables = [tables]
524 2141 aaronmk
    tables = list(tables) # don't modify input! (list() copies input)
525 2315 aaronmk
    table0 = sql_gen.as_Table(tables.pop(0)) # first table is separate
526 2121 aaronmk
527 2315 aaronmk
    # Parse other params
528 2376 aaronmk
    if conds == None: conds = []
529 2650 aaronmk
    elif dicts.is_dict(conds): conds = conds.items()
530 2379 aaronmk
    conds = list(conds) # don't modify input! (list() copies input)
531 135 aaronmk
    assert limit == None or type(limit) == int
532 865 aaronmk
    assert start == None or type(start) == int
533 2315 aaronmk
    if order_by is order_by_pkey:
534
        if distinct_on != []: order_by = None
535
        else: order_by = pkey(db, table0, recover=True)
536 865 aaronmk
537 2315 aaronmk
    query = 'SELECT'
538 2056 aaronmk
539 2315 aaronmk
    def parse_col(col): return sql_gen.as_Col(col, default_table).to_str(db)
540 2056 aaronmk
541 2200 aaronmk
    # DISTINCT ON columns
542 2233 aaronmk
    if distinct_on != []:
543 2467 aaronmk
        query += '\nDISTINCT'
544 2254 aaronmk
        if distinct_on is not distinct_on_all:
545 2200 aaronmk
            query += ' ON ('+(', '.join(map(parse_col, distinct_on)))+')'
546
547
    # Columns
548 2467 aaronmk
    query += '\n'
549 1135 aaronmk
    if fields == None: query += '*'
550 2765 aaronmk
    else:
551
        assert fields != []
552
        query += '\n, '.join(map(parse_col, fields))
553 2200 aaronmk
554
    # Main table
555 2467 aaronmk
    query += '\nFROM '+table0.to_str(db)
556 865 aaronmk
557 2122 aaronmk
    # Add joins
558 2271 aaronmk
    left_table = table0
559 2263 aaronmk
    for join_ in tables:
560
        table = join_.table
561 2238 aaronmk
562 2343 aaronmk
        # Parse special values
563
        if join_.type_ is sql_gen.filter_out: # filter no match
564 2376 aaronmk
            conds.append((sql_gen.Col(table_not_null_col(db, table), table),
565
                None))
566 2343 aaronmk
567 2467 aaronmk
        query += '\n'+join_.to_str(db, left_table)
568 2122 aaronmk
569
        left_table = table
570
571 865 aaronmk
    missing = True
572 2376 aaronmk
    if conds != []:
573 2576 aaronmk
        if len(conds) == 1: whitespace = ' '
574
        else: whitespace = '\n'
575 2578 aaronmk
        query += '\n'+sql_gen.combine_conds([sql_gen.ColValueCond(l, r)
576
            .to_str(db) for l, r in conds], 'WHERE')
577 865 aaronmk
        missing = False
578 2227 aaronmk
    if order_by != None:
579 2467 aaronmk
        query += '\nORDER BY '+sql_gen.as_Col(order_by, table0).to_str(db)
580
    if limit != None: query += '\nLIMIT '+str(limit); missing = False
581 865 aaronmk
    if start != None:
582 2467 aaronmk
        if start != 0: query += '\nOFFSET '+str(start)
583 865 aaronmk
        missing = False
584
    if missing: warnings.warn(DbWarning(
585
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
586
587 2786 aaronmk
    return query
588 11 aaronmk
589 2054 aaronmk
def select(db, *args, **kw_args):
590
    '''For params, see mk_select() and run_query()'''
591
    recover = kw_args.pop('recover', None)
592
    cacheable = kw_args.pop('cacheable', True)
593 2442 aaronmk
    log_level = kw_args.pop('log_level', 2)
594 2054 aaronmk
595 2791 aaronmk
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
596
        log_level=log_level)
597 2054 aaronmk
598 2788 aaronmk
def mk_insert_select(db, table, cols=None, select_query=None, returning=None,
599
    embeddable=False):
600 1960 aaronmk
    '''
601
    @param returning str|None An inserted column (such as pkey) to return
602 2070 aaronmk
    @param embeddable Whether the query should be embeddable as a nested SELECT.
603 2073 aaronmk
        Warning: If you set this and cacheable=True when the query is run, the
604
        query will be fully cached, not just if it raises an exception.
605 1960 aaronmk
    '''
606 2754 aaronmk
    table = sql_gen.remove_table_rename(sql_gen.as_Table(table))
607 2318 aaronmk
    if cols == []: cols = None # no cols (all defaults) = unknown col names
608 2646 aaronmk
    if cols != None:
609
        cols = [sql_gen.to_name_only_col(v, table).to_str(db) for v in cols]
610 2063 aaronmk
    if select_query == None: select_query = 'DEFAULT VALUES'
611 2327 aaronmk
    if returning != None: returning = sql_gen.as_Col(returning, table)
612 2063 aaronmk
613
    # Build query
614 2497 aaronmk
    first_line = 'INSERT INTO '+table.to_str(db)
615
    query = first_line
616 2467 aaronmk
    if cols != None: query += '\n('+', '.join(cols)+')'
617
    query += '\n'+select_query
618 2063 aaronmk
619
    if returning != None:
620 2743 aaronmk
        query += '\nRETURNING '+sql_gen.to_name_only_col(returning).to_str(db)
621 2063 aaronmk
622 2070 aaronmk
    if embeddable:
623 2327 aaronmk
        assert returning != None
624
625 2070 aaronmk
        # Create function
626 2513 aaronmk
        function_name = sql_gen.clean_name(first_line)
627 2327 aaronmk
        return_type = 'SETOF '+returning.to_str(db)+'%TYPE'
628 2189 aaronmk
        while True:
629
            try:
630 2698 aaronmk
                function = sql_gen.TempFunction(function_name, db.autocommit)
631 2194 aaronmk
632 2189 aaronmk
                function_query = '''\
633 2698 aaronmk
CREATE FUNCTION '''+function.to_str(db)+'''()
634 2467 aaronmk
RETURNS '''+return_type+'''
635
LANGUAGE sql
636
AS $$
637 2788 aaronmk
'''+query+''';
638 2467 aaronmk
$$;
639 2070 aaronmk
'''
640 2446 aaronmk
                run_query(db, function_query, recover=True, cacheable=True,
641 2464 aaronmk
                    log_ignore_excs=(DuplicateFunctionException,))
642 2189 aaronmk
                break # this version was successful
643
            except DuplicateFunctionException, e:
644
                function_name = next_version(function_name)
645
                # try again with next version of name
646 2070 aaronmk
647 2337 aaronmk
        # Return query that uses function
648 2698 aaronmk
        func_table = sql_gen.NamedTable('f', sql_gen.FunctionCall(function),
649 2742 aaronmk
            [returning]) # AS clause requires function alias
650 2787 aaronmk
        return mk_select(db, func_table, start=0, order_by=None)
651 2070 aaronmk
652 2787 aaronmk
    return query
653 2066 aaronmk
654
def insert_select(db, *args, **kw_args):
655 2085 aaronmk
    '''For params, see mk_insert_select() and run_query_into()
656 2386 aaronmk
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
657
        values in
658 2072 aaronmk
    '''
659 2386 aaronmk
    into = kw_args.pop('into', None)
660
    if into != None: kw_args['embeddable'] = True
661 2066 aaronmk
    recover = kw_args.pop('recover', None)
662
    cacheable = kw_args.pop('cacheable', True)
663 2673 aaronmk
    log_level = kw_args.pop('log_level', 2)
664 2066 aaronmk
665 2789 aaronmk
    return run_query_into(db, mk_insert_select(db, *args, **kw_args), into,
666 2787 aaronmk
        recover=recover, cacheable=cacheable, log_level=log_level)
667 2063 aaronmk
668 2738 aaronmk
default = sql_gen.default # tells insert() to use the default value for a column
669 2066 aaronmk
670 2063 aaronmk
def insert(db, table, row, *args, **kw_args):
671 2085 aaronmk
    '''For params, see insert_select()'''
672 1960 aaronmk
    if lists.is_seq(row): cols = None
673
    else:
674
        cols = row.keys()
675
        row = row.values()
676 2738 aaronmk
    row = list(row) # ensure that "== []" works
677 1960 aaronmk
678 2738 aaronmk
    if row == []: query = None
679
    else: query = sql_gen.Values(row).to_str(db)
680 1961 aaronmk
681 2788 aaronmk
    return insert_select(db, table, cols, query, *args, **kw_args)
682 11 aaronmk
683 2402 aaronmk
def mk_update(db, table, changes=None, cond=None):
684
    '''
685
    @param changes [(col, new_value),...]
686
        * container can be any iterable type
687
        * col: sql_gen.Code|str (for col name)
688
        * new_value: sql_gen.Code|literal value
689
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
690
    @return str query
691
    '''
692
    query = 'UPDATE '+sql_gen.as_Table(table).to_str(db)+'\nSET\n'
693 2405 aaronmk
    query += ',\n'.join((sql_gen.to_name_only_col(col, table).to_str(db)+' = '
694 2402 aaronmk
        +sql_gen.as_Value(new_value).to_str(db) for col, new_value in changes))
695 2467 aaronmk
    if cond != None: query += '\nWHERE\n'+cond.to_str(db)
696 2402 aaronmk
697
    return query
698
699
def update(db, *args, **kw_args):
700
    '''For params, see mk_update() and run_query()'''
701
    recover = kw_args.pop('recover', None)
702
703 2791 aaronmk
    return run_query(db, mk_update(db, *args, **kw_args), recover)
704 2402 aaronmk
705 135 aaronmk
def last_insert_id(db):
706 1849 aaronmk
    module = util.root_module(db.db)
707 135 aaronmk
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
708
    elif module == 'MySQLdb': return db.insert_id()
709
    else: return None
710 13 aaronmk
711 2394 aaronmk
def mk_flatten_mapping(db, into, cols, preserve=[], as_items=False):
712 2383 aaronmk
    '''Creates a mapping from original column names (which may have collisions)
713 2415 aaronmk
    to names that will be distinct among the columns' tables.
714 2383 aaronmk
    This is meant to be used for several tables that are being joined together.
715 2415 aaronmk
    @param cols The columns to combine. Duplicates will be removed.
716
    @param into The table for the new columns.
717 2394 aaronmk
    @param preserve [sql_gen.Col...] Columns not to rename. Note that these
718
        columns will be included in the mapping even if they are not in cols.
719
        The tables of the provided Col objects will be changed to into, so make
720
        copies of them if you want to keep the original tables.
721
    @param as_items Whether to return a list of dict items instead of a dict
722 2383 aaronmk
    @return dict(orig_col=new_col, ...)
723
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
724 2392 aaronmk
        * new_col: sql_gen.Col(orig_col_name, into)
725
        * All mappings use the into table so its name can easily be
726 2383 aaronmk
          changed for all columns at once
727
    '''
728 2415 aaronmk
    cols = lists.uniqify(cols)
729
730 2394 aaronmk
    items = []
731 2389 aaronmk
    for col in preserve:
732 2390 aaronmk
        orig_col = copy.copy(col)
733 2392 aaronmk
        col.table = into
734 2394 aaronmk
        items.append((orig_col, col))
735
    preserve = set(preserve)
736
    for col in cols:
737 2716 aaronmk
        if col not in preserve:
738
            items.append((col, sql_gen.Col(str(col), into, col.srcs)))
739 2394 aaronmk
740
    if not as_items: items = dict(items)
741
    return items
742 2383 aaronmk
743 2393 aaronmk
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
744 2391 aaronmk
    '''For params, see mk_flatten_mapping()
745
    @return See return value of mk_flatten_mapping()
746
    '''
747 2394 aaronmk
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
748
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
749 2786 aaronmk
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
750 2392 aaronmk
        into=into)
751 2394 aaronmk
    return dict(items)
752 2391 aaronmk
753 2751 aaronmk
def mk_track_data_error(db, errors_table, cols, value, error_code, error):
754
    cols = map(sql_gen.to_name_only_col, cols)
755
756
    columns_cols = ['column']
757
    columns = sql_gen.NamedValues('columns', columns_cols,
758
        [[c.name] for c in cols])
759
    values_cols = ['value', 'error_code', 'error']
760
    values = sql_gen.NamedValues('values', values_cols,
761
        [value, error_code, error])
762
763
    select_cols = columns_cols+values_cols
764
    name_only_cols = map(sql_gen.to_name_only_col, select_cols)
765 2755 aaronmk
    errors_table = sql_gen.NamedTable('errors', errors_table)
766 2751 aaronmk
    joins = [columns, sql_gen.Join(values, type_='CROSS'),
767
        sql_gen.Join(errors_table, dict(zip(name_only_cols, select_cols)),
768
        sql_gen.filter_out)]
769
770
    return mk_insert_select(db, errors_table, name_only_cols,
771 2787 aaronmk
        mk_select(db, joins, select_cols, order_by=None))
772 2751 aaronmk
773 2758 aaronmk
def track_data_error(db, errors_table, *args, **kw_args):
774
    '''
775
    @param errors_table If None, does nothing.
776
    '''
777
    if errors_table == None: return
778
    run_query(db, mk_track_data_error(db, errors_table, *args, **kw_args),
779
        cacheable=True, log_level=4)
780
781 2704 aaronmk
def cast(db, type_, col, errors_table=None):
782
    '''Casts an (unrenamed) column or value.
783 2769 aaronmk
    If errors_table set and col has srcs, saves errors in errors_table (using
784
    col's srcs attr as the source columns) and converts errors to warnings.
785 2704 aaronmk
    @param col sql_gen.Col|sql_gen.Literal
786
    @param errors_table None|sql_gen.Table|str
787
    '''
788 2769 aaronmk
    save_errors = (errors_table != None and isinstance(col, sql_gen.Col)
789
        and col.srcs != ())
790
    if not save_errors: # can't save errors
791
        return sql_gen.CustomCode(col.to_str(db)+'::'+type_) # just cast
792 2704 aaronmk
793
    assert not isinstance(col, sql_gen.NamedCol)
794
795 2770 aaronmk
    errors_table = sql_gen.as_Table(errors_table)
796
    srcs = map(sql_gen.to_name_only_col, col.srcs)
797
    function_name = str(sql_gen.FunctionCall(type_, *srcs))
798 2704 aaronmk
    function = sql_gen.TempFunction(function_name, db.autocommit)
799
800 2718 aaronmk
    while True:
801
        # Create function definition
802
        query = '''\
803 2704 aaronmk
CREATE FUNCTION '''+function.to_str(db)+'''(value text)
804
RETURNS '''+type_+'''
805
LANGUAGE plpgsql
806
STRICT
807
AS $$
808
BEGIN
809
    /* The explicit cast to the return type is needed to make the cast happen
810
    inside the try block. (Implicit casts to the return type happen at the end
811
    of the function, outside any block.) */
812
    RETURN value::'''+type_+''';
813
EXCEPTION
814
    WHEN data_exception THEN
815
        -- Save error in errors table.
816 2751 aaronmk
        -- Insert the value and error for *each* source column.
817
'''+mk_track_data_error(db, errors_table, srcs,
818
    *map(sql_gen.CustomCode, ['value', 'SQLSTATE', 'SQLERRM']))+''';
819 2704 aaronmk
820
        RAISE WARNING '%', SQLERRM;
821
        RETURN NULL;
822
END;
823
$$;
824
'''
825 2718 aaronmk
826
        # Create function
827
        try:
828
            run_query(db, query, recover=True, cacheable=True,
829
                log_ignore_excs=(DuplicateFunctionException,))
830
            break # successful
831
        except DuplicateFunctionException:
832 2770 aaronmk
            function.name = next_version(function.name)
833
            # try again with next version of name
834 2704 aaronmk
835
    return sql_gen.FunctionCall(function, col)
836
837 2414 aaronmk
##### Database structure queries
838
839 2426 aaronmk
def table_row_count(db, table, recover=None):
840 2786 aaronmk
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
841 2443 aaronmk
        order_by=None, start=0), recover=recover, log_level=3))
842 2426 aaronmk
843 2414 aaronmk
def table_cols(db, table, recover=None):
844
    return list(col_names(select(db, table, limit=0, order_by=None,
845 2443 aaronmk
        recover=recover, log_level=4)))
846 2414 aaronmk
847 2291 aaronmk
def pkey(db, table, recover=None):
848 832 aaronmk
    '''Assumed to be first column in table'''
849 2339 aaronmk
    return table_cols(db, table, recover)[0]
850 832 aaronmk
851 2559 aaronmk
not_null_col = 'not_null_col'
852 2340 aaronmk
853
def table_not_null_col(db, table, recover=None):
854
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
855
    if not_null_col in table_cols(db, table, recover): return not_null_col
856
    else: return pkey(db, table, recover)
857
858 853 aaronmk
def index_cols(db, table, index):
859
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
860
    automatically created. When you don't know whether something is a UNIQUE
861
    constraint or a UNIQUE index, use this function.'''
862 1909 aaronmk
    module = util.root_module(db.db)
863
    if module == 'psycopg2':
864
        return list(values(run_query(db, '''\
865 853 aaronmk
SELECT attname
866 866 aaronmk
FROM
867
(
868
        SELECT attnum, attname
869
        FROM pg_index
870
        JOIN pg_class index ON index.oid = indexrelid
871
        JOIN pg_class table_ ON table_.oid = indrelid
872
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
873
        WHERE
874 2782 aaronmk
            table_.relname = '''+db.esc_value(table)+'''
875
            AND index.relname = '''+db.esc_value(index)+'''
876 866 aaronmk
    UNION
877
        SELECT attnum, attname
878
        FROM
879
        (
880
            SELECT
881
                indrelid
882
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
883
                    AS indkey
884
            FROM pg_index
885
            JOIN pg_class index ON index.oid = indexrelid
886
            JOIN pg_class table_ ON table_.oid = indrelid
887
            WHERE
888 2782 aaronmk
                table_.relname = '''+db.esc_value(table)+'''
889
                AND index.relname = '''+db.esc_value(index)+'''
890 866 aaronmk
        ) s
891
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
892
) s
893 853 aaronmk
ORDER BY attnum
894 2782 aaronmk
'''
895
            , cacheable=True, log_level=4)))
896 1909 aaronmk
    else: raise NotImplementedError("Can't list index columns for "+module+
897
        ' database')
898 853 aaronmk
899 464 aaronmk
def constraint_cols(db, table, constraint):
900 1849 aaronmk
    module = util.root_module(db.db)
901 464 aaronmk
    if module == 'psycopg2':
902
        return list(values(run_query(db, '''\
903
SELECT attname
904
FROM pg_constraint
905
JOIN pg_class ON pg_class.oid = conrelid
906
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
907
WHERE
908 2783 aaronmk
    relname = '''+db.esc_value(table)+'''
909
    AND conname = '''+db.esc_value(constraint)+'''
910 464 aaronmk
ORDER BY attnum
911 2783 aaronmk
'''
912
            )))
913 464 aaronmk
    else: raise NotImplementedError("Can't list constraint columns for "+module+
914
        ' database')
915
916 2096 aaronmk
row_num_col = '_row_num'
917
918 2688 aaronmk
def add_index(db, exprs, table=None, unique=False):
919
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
920 2538 aaronmk
    Currently, only function calls are supported as expressions.
921
    '''
922 2688 aaronmk
    if not lists.is_seq(exprs): exprs = [exprs]
923 2538 aaronmk
924 2688 aaronmk
    # Parse exprs
925
    old_exprs = exprs[:]
926
    exprs = []
927
    cols = []
928
    for i, expr in enumerate(old_exprs):
929
        expr = copy.deepcopy(expr) # don't modify input!
930
        expr = sql_gen.as_Col(expr)
931
932
        # Extract col
933
        if isinstance(expr, sql_gen.FunctionCall):
934
            col = expr.args[0]
935
            expr = sql_gen.Expr(expr)
936
        else: col = expr
937
938
        # Extract table
939
        if table == None:
940
            assert sql_gen.is_table_col(col)
941
            table = col.table
942
943
        col.table = None
944
945
        exprs.append(expr)
946
        cols.append(col)
947 2408 aaronmk
948 2688 aaronmk
    table = sql_gen.as_Table(table)
949
    index = sql_gen.Table(str(sql_gen.Col(','.join(map(str, cols)), table)))
950
951
    str_ = 'CREATE'
952
    if unique: str_ += ' UNIQUE'
953
    str_ += ' INDEX '+index.to_str(db)+' ON '+table.to_str(db)+' ('+(
954
        ', '.join((v.to_str(db) for v in exprs)))+')'
955
956
    try: run_query(db, str_, recover=True, cacheable=True, log_level=3)
957 2408 aaronmk
    except DuplicateTableException: pass # index already existed
958
959 2686 aaronmk
def add_pkey(db, table, cols=None, recover=None):
960
    '''Adds a primary key.
961
    @param cols [sql_gen.Col,...] The columns in the primary key.
962
        Defaults to the first column in the table.
963 2406 aaronmk
    @pre The table must not already have a primary key.
964
    '''
965
    table = sql_gen.as_Table(table)
966 2686 aaronmk
    if cols == None: cols = [pkey(db, table, recover)]
967
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
968 2406 aaronmk
969 2781 aaronmk
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
970
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
971
        log_ignore_excs=(DuplicateTableException,))
972 2406 aaronmk
973 2772 aaronmk
already_indexed = object() # tells add_indexes() the pkey has already been added
974
975
def add_indexes(db, table, has_pkey=True):
976
    '''Adds an index on all columns in a table.
977
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
978
        index should be added on the first column.
979
        * If already_indexed, the pkey is assumed to have already been added
980
    '''
981
    cols = table_cols(db, table)
982
    if has_pkey:
983
        if has_pkey is not already_indexed: add_pkey(db, table)
984
        cols = cols[1:]
985
    for col in cols: add_index(db, col, table)
986
987 2086 aaronmk
def add_row_num(db, table):
988 2117 aaronmk
    '''Adds a row number column to a table. Its name is in row_num_col. It will
989
    be the primary key.'''
990 2320 aaronmk
    table = sql_gen.as_Table(table).to_str(db)
991 2096 aaronmk
    run_query(db, 'ALTER TABLE '+table+' ADD COLUMN '+row_num_col
992 2443 aaronmk
        +' serial NOT NULL PRIMARY KEY', log_level=3)
993 2086 aaronmk
994 2760 aaronmk
def create_table(db, table, cols, has_pkey=True, col_indexes=True):
995 2675 aaronmk
    '''Creates a table.
996 2681 aaronmk
    @param cols [sql_gen.TypedCol,...] The column names and types
997
    @param has_pkey If set, the first column becomes the primary key.
998 2760 aaronmk
    @param col_indexes bool|[ref]
999
        * If True, indexes will be added on all non-pkey columns.
1000
        * If a list reference, [0] will be set to a function to do this.
1001
          This can be used to delay index creation until the table is populated.
1002 2675 aaronmk
    '''
1003
    table = sql_gen.as_Table(table)
1004
1005 2681 aaronmk
    if has_pkey:
1006
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1007
        pkey.type += ' NOT NULL PRIMARY KEY'
1008
1009 2675 aaronmk
    str_ = 'CREATE TABLE '+table.to_str(db)+' (\n'
1010 2681 aaronmk
    str_ += '\n, '.join(v.to_str(db) for v in cols)
1011
    str_ += '\n);\n'
1012 2675 aaronmk
    run_query(db, str_, cacheable=True, log_level=2)
1013 2760 aaronmk
1014
    # Add indexes
1015 2773 aaronmk
    if has_pkey: has_pkey = already_indexed
1016
    def add_indexes_(): add_indexes(db, table, has_pkey)
1017
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1018
    elif col_indexes: add_indexes_() # add now
1019 2675 aaronmk
1020 2684 aaronmk
def vacuum(db, table):
1021
    table = sql_gen.as_Table(table)
1022
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1023
        log_level=3))
1024
1025 2732 aaronmk
def truncate(db, table, schema='public'):
1026 2777 aaronmk
    table = sql_gen.as_Table(table, schema)
1027 2733 aaronmk
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE')
1028 2732 aaronmk
1029 2729 aaronmk
def tables(db, schema_like='public', table_like='%', exact=False):
1030
    if exact: compare = '='
1031
    else: compare = 'LIKE'
1032
1033 1849 aaronmk
    module = util.root_module(db.db)
1034 832 aaronmk
    if module == 'psycopg2':
1035 2779 aaronmk
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1036
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1037
        return values(select(db, 'pg_tables', ['tablename'], conds,
1038
            order_by='tablename', log_level=4))
1039 1968 aaronmk
    elif module == 'MySQLdb':
1040 2779 aaronmk
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1041
            , cacheable=True, log_level=4))
1042 832 aaronmk
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1043 830 aaronmk
1044 2726 aaronmk
def table_exists(db, table):
1045
    table = sql_gen.as_Table(table)
1046 2730 aaronmk
    return list(tables(db, table.schema, table.name, exact=True)) != []
1047 2726 aaronmk
1048
def errors_table(db, table, if_exists=True):
1049
    '''
1050
    @param if_exists If set, returns None if the errors table doesn't exist
1051
    @return None|sql_gen.Table
1052
    '''
1053
    table = sql_gen.as_Table(table)
1054
    if table.srcs != (): table = table.srcs[0]
1055
1056
    errors_table = sql_gen.suffixed_table(table, '.errors')
1057
    if if_exists and not table_exists(db, errors_table): return None
1058
    return errors_table
1059
1060 833 aaronmk
##### Database management
1061
1062 1968 aaronmk
def empty_db(db, schema='public', **kw_args):
1063
    '''For kw_args, see tables()'''
1064
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1065 833 aaronmk
1066 832 aaronmk
##### Heuristic queries
1067
1068 2104 aaronmk
def put(db, table, row, pkey_=None, row_ct_ref=None):
1069 1554 aaronmk
    '''Recovers from errors.
1070 2077 aaronmk
    Only works under PostgreSQL (uses INSERT RETURNING).
1071
    '''
1072 2642 aaronmk
    row = sql_gen.ColDict(db, table, row)
1073 2104 aaronmk
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
1074
1075 471 aaronmk
    try:
1076 2149 aaronmk
        cur = insert(db, table, row, pkey_, recover=True)
1077 1554 aaronmk
        if row_ct_ref != None and cur.rowcount >= 0:
1078
            row_ct_ref[0] += cur.rowcount
1079
        return value(cur)
1080 471 aaronmk
    except DuplicateKeyException, e:
1081 2653 aaronmk
        row = sql_gen.ColDict(db, table,
1082
            util.dict_subset_right_join(row, e.cols))
1083
        return value(select(db, table, [pkey_], row, recover=True))
1084 471 aaronmk
1085 473 aaronmk
def get(db, table, row, pkey, row_ct_ref=None, create=False):
1086 830 aaronmk
    '''Recovers from errors'''
1087 2209 aaronmk
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
1088 14 aaronmk
    except StopIteration:
1089 40 aaronmk
        if not create: raise
1090 471 aaronmk
        return put(db, table, row, pkey, row_ct_ref) # insert new row
1091 2078 aaronmk
1092 2593 aaronmk
def is_func_result(col):
1093
    return col.table.name.find('(') >= 0 and col.name == 'result'
1094
1095 2592 aaronmk
def into_table_name(out_table, in_tables0, mapping, is_func):
1096 2615 aaronmk
    def in_col_str(in_col):
1097
        in_col = sql_gen.remove_col_rename(in_col)
1098
        if isinstance(in_col, sql_gen.Col):
1099
            table = in_col.table
1100
            if table == in_tables0:
1101
                in_col = sql_gen.to_name_only_col(in_col)
1102
            elif is_func_result(in_col): in_col = table # omit col name
1103
        return str(in_col)
1104
1105 2580 aaronmk
    str_ = str(out_table)
1106
    if is_func:
1107 2615 aaronmk
        str_ += '('
1108 2580 aaronmk
1109 2615 aaronmk
        try: value_in_col = mapping['value']
1110
        except KeyError:
1111 2654 aaronmk
            str_ += ', '.join((str(k)+'='+in_col_str(v)
1112 2615 aaronmk
                for k, v in mapping.iteritems()))
1113
        else: str_ += in_col_str(value_in_col)
1114
1115
        str_ += ')'
1116 2580 aaronmk
    else: str_ += '_pkeys'
1117
    return str_
1118
1119 2508 aaronmk
def put_table(db, out_table, in_tables, mapping, row_ct_ref=None, into=None,
1120 2552 aaronmk
    default=None, is_func=False):
1121 2078 aaronmk
    '''Recovers from errors.
1122
    Only works under PostgreSQL (uses INSERT RETURNING).
1123 2131 aaronmk
    @param in_tables The main input table to select from, followed by a list of
1124
        tables to join with it using the main input table's pkey
1125 2312 aaronmk
    @param mapping dict(out_table_col=in_table_col, ...)
1126 2612 aaronmk
        * out_table_col: str (*not* sql_gen.Col)
1127
        * in_table_col: sql_gen.Col|literal-value
1128 2489 aaronmk
    @param into The table to contain the output and input pkeys.
1129 2574 aaronmk
        Defaults to `out_table.name+'_pkeys'`.
1130 2509 aaronmk
    @param default The *output* column to use as the pkey for missing rows.
1131
        If this output column does not exist in the mapping, uses None.
1132 2552 aaronmk
    @param is_func Whether out_table is the name of a SQL function, not a table
1133 2312 aaronmk
    @return sql_gen.Col Where the output pkeys are made available
1134 2078 aaronmk
    '''
1135 2329 aaronmk
    out_table = sql_gen.as_Table(out_table)
1136 2312 aaronmk
1137 2450 aaronmk
    def log_debug(msg): db.log_debug(msg, level=1.5)
1138 2505 aaronmk
    def col_ustr(str_):
1139 2567 aaronmk
        return strings.repr_no_u(sql_gen.remove_col_rename(str_))
1140 2450 aaronmk
1141 2768 aaronmk
    out_pkey = pkey(db, out_table, recover=True)
1142
    out_pkey_col = sql_gen.as_Col(out_pkey, out_table)
1143
1144
    if mapping == {}: # need at least one column for INSERT SELECT
1145
        mapping = {out_pkey: None} # ColDict will replace with default value
1146
1147 2486 aaronmk
    log_debug('********** New iteration **********')
1148 2505 aaronmk
    log_debug('Inserting these input columns into '+strings.as_tt(
1149
        out_table.to_str(db))+':\n'+strings.as_table(mapping, ustr=col_ustr))
1150 2463 aaronmk
1151 2382 aaronmk
    # Create input joins from list of input tables
1152
    in_tables_ = in_tables[:] # don't modify input!
1153
    in_tables0 = in_tables_.pop(0) # first table is separate
1154 2735 aaronmk
    errors_table_ = errors_table(db, in_tables0)
1155 2279 aaronmk
    in_pkey = pkey(db, in_tables0, recover=True)
1156 2285 aaronmk
    in_pkey_col = sql_gen.as_Col(in_pkey, in_tables0)
1157 2460 aaronmk
    input_joins = [in_tables0]+[sql_gen.Join(v,
1158
        {in_pkey: sql_gen.join_same_not_null}) for v in in_tables_]
1159 2131 aaronmk
1160 2592 aaronmk
    if into == None:
1161
        into = into_table_name(out_table, in_tables0, mapping, is_func)
1162
    into = sql_gen.as_Table(into)
1163
1164 2702 aaronmk
    # Set column sources
1165
    in_cols = filter(sql_gen.is_table_col, mapping.values())
1166
    for col in in_cols:
1167
        if col.table == in_tables0: col.set_srcs(sql_gen.src_self)
1168
1169 2486 aaronmk
    log_debug('Joining together input tables into temp table')
1170 2395 aaronmk
    # Place in new table for speed and so don't modify input if values edited
1171 2584 aaronmk
    in_table = sql_gen.Table('in')
1172 2702 aaronmk
    mapping = dicts.join(mapping, flatten(db, in_table, input_joins, in_cols,
1173
        preserve=[in_pkey_col], start=0))
1174 2395 aaronmk
    input_joins = [in_table]
1175 2486 aaronmk
    db.log_debug('Temp table: '+strings.as_tt(in_table.to_str(db)), level=2)
1176 2395 aaronmk
1177 2656 aaronmk
    mapping = sql_gen.ColDict(db, out_table, mapping)
1178
        # after applying dicts.join() because that returns a plain dict
1179
1180 2509 aaronmk
    # Resolve default value column
1181
    try: default = mapping[default]
1182
    except KeyError:
1183
        if default != None:
1184
            db.log_debug('Default value column '
1185
                +strings.as_tt(strings.repr_no_u(default))
1186 2511 aaronmk
                +' does not exist in mapping, falling back to None', level=2.1)
1187 2509 aaronmk
            default = None
1188
1189 2387 aaronmk
    pkeys_names = [in_pkey, out_pkey]
1190 2236 aaronmk
    pkeys_cols = [in_pkey_col, out_pkey_col]
1191
1192 2201 aaronmk
    pkeys_table_exists_ref = [False]
1193 2420 aaronmk
    def insert_into_pkeys(joins, cols):
1194 2786 aaronmk
        query = mk_select(db, joins, cols, order_by=None, start=0)
1195 2201 aaronmk
        if pkeys_table_exists_ref[0]:
1196 2786 aaronmk
            insert_select(db, into, pkeys_names, query)
1197 2201 aaronmk
        else:
1198 2786 aaronmk
            run_query_into(db, query, into=into)
1199 2201 aaronmk
            pkeys_table_exists_ref[0] = True
1200
1201 2429 aaronmk
    limit_ref = [None]
1202 2380 aaronmk
    conds = set()
1203 2233 aaronmk
    distinct_on = []
1204 2325 aaronmk
    def mk_main_select(joins, cols):
1205 2429 aaronmk
        return mk_select(db, joins, cols, conds, distinct_on,
1206
            limit=limit_ref[0], start=0)
1207 2132 aaronmk
1208 2519 aaronmk
    exc_strs = set()
1209 2309 aaronmk
    def log_exc(e):
1210 2519 aaronmk
        e_str = exc.str_(e, first_line_only=True)
1211
        log_debug('Caught exception: '+e_str)
1212
        assert e_str not in exc_strs # avoid infinite loops
1213
        exc_strs.add(e_str)
1214 2735 aaronmk
1215 2451 aaronmk
    def remove_all_rows():
1216 2450 aaronmk
        log_debug('Returning NULL for all rows')
1217 2429 aaronmk
        limit_ref[0] = 0 # just create an empty pkeys table
1218 2735 aaronmk
1219 2758 aaronmk
    def ignore(in_col, value, e):
1220
        track_data_error(db, errors_table_, in_col.srcs, value, e.cause.pgcode,
1221
            e.cause.pgerror)
1222
1223 2545 aaronmk
        in_col_str = strings.as_tt(repr(in_col))
1224 2544 aaronmk
        db.log_debug('Adding index on '+in_col_str+' to enable fast filtering',
1225
            level=2.5)
1226 2537 aaronmk
        add_index(db, in_col)
1227 2735 aaronmk
1228 2545 aaronmk
        log_debug('Ignoring rows with '+in_col_str+' = '
1229
            +strings.as_tt(repr(value)))
1230 2758 aaronmk
    def remove_rows(in_col, value, e):
1231
        ignore(in_col, value, e)
1232 2378 aaronmk
        cond = (in_col, sql_gen.CompareCond(value, '!='))
1233
        assert cond not in conds # avoid infinite loops
1234 2380 aaronmk
        conds.add(cond)
1235 2758 aaronmk
    def invalid2null(in_col, value, e):
1236
        ignore(in_col, value, e)
1237 2403 aaronmk
        update(db, in_table, [(in_col, None)],
1238
            sql_gen.ColValueCond(in_col, value))
1239 2245 aaronmk
1240 2589 aaronmk
    def insert_pkeys_table(which):
1241
        return sql_gen.Table(sql_gen.add_suffix(in_table.name,
1242
            '_insert_'+which+'_pkeys'))
1243
    insert_out_pkeys = insert_pkeys_table('out')
1244
    insert_in_pkeys = insert_pkeys_table('in')
1245
1246 2206 aaronmk
    # Do inserts and selects
1247 2642 aaronmk
    join_cols = sql_gen.ColDict(db, out_table)
1248 2206 aaronmk
    while True:
1249 2521 aaronmk
        if limit_ref[0] == 0: # special case
1250
            log_debug('Creating an empty pkeys table')
1251 2786 aaronmk
            cur = run_query_into(db, mk_select(db, out_table, [out_pkey],
1252 2521 aaronmk
                limit=limit_ref[0]), into=insert_out_pkeys)
1253
            break # don't do main case
1254
1255 2303 aaronmk
        has_joins = join_cols != {}
1256
1257 2305 aaronmk
        # Prepare to insert new rows
1258 2325 aaronmk
        insert_joins = input_joins[:] # don't modify original!
1259 2403 aaronmk
        insert_args = dict(recover=True, cacheable=False)
1260 2303 aaronmk
        if has_joins:
1261 2317 aaronmk
            distinct_on = [v.to_Col() for v in join_cols.values()]
1262 2325 aaronmk
            insert_joins.append(sql_gen.Join(out_table, join_cols,
1263
                sql_gen.filter_out))
1264
        else:
1265 2404 aaronmk
            insert_args.update(dict(returning=out_pkey, into=insert_out_pkeys))
1266 2786 aaronmk
        main_select = mk_main_select(insert_joins, mapping.values())
1267 2303 aaronmk
1268 2486 aaronmk
        log_debug('Trying to insert new rows')
1269 2206 aaronmk
        try:
1270 2518 aaronmk
            cur = insert_select(db, out_table, mapping.keys(), main_select,
1271
                **insert_args)
1272 2357 aaronmk
            break # insert successful
1273 2206 aaronmk
        except DuplicateKeyException, e:
1274 2309 aaronmk
            log_exc(e)
1275
1276 2258 aaronmk
            old_join_cols = join_cols.copy()
1277 2565 aaronmk
            join_cols.update(util.dict_subset_right_join(mapping, e.cols))
1278 2486 aaronmk
            log_debug('Ignoring existing rows, comparing on these columns:\n'
1279 2505 aaronmk
                +strings.as_inline_table(join_cols, ustr=col_ustr))
1280 2258 aaronmk
            assert join_cols != old_join_cols # avoid infinite loops
1281 2230 aaronmk
        except NullValueException, e:
1282 2309 aaronmk
            log_exc(e)
1283
1284 2230 aaronmk
            out_col, = e.cols
1285
            try: in_col = mapping[out_col]
1286 2356 aaronmk
            except KeyError:
1287 2486 aaronmk
                log_debug('Missing mapping for NOT NULL column '+out_col)
1288 2451 aaronmk
                remove_all_rows()
1289 2758 aaronmk
            else: remove_rows(in_col, None, e)
1290 2542 aaronmk
        except FunctionValueException, e:
1291
            log_exc(e)
1292
1293
            func_name = e.name
1294
            value = e.value
1295
            for out_col, in_col in mapping.iteritems():
1296 2758 aaronmk
                in_col = sql_gen.unwrap_func_call(in_col, func_name)
1297
                invalid2null(in_col, value, e)
1298 2525 aaronmk
        except MissingCastException, e:
1299
            log_exc(e)
1300
1301
            out_col = e.col
1302 2706 aaronmk
            type_ = e.type
1303
1304 2724 aaronmk
            log_debug('Casting '+strings.as_tt(out_col)+' input to '
1305
                +strings.as_tt(type_))
1306 2735 aaronmk
            def wrap_func(col): return cast(db, type_, col, errors_table_)
1307 2705 aaronmk
            mapping[out_col] = sql_gen.wrap(wrap_func, mapping[out_col])
1308 2429 aaronmk
        except DatabaseErrors, e:
1309
            log_exc(e)
1310
1311 2531 aaronmk
            msg = 'No handler for exception: '+exc.str_(e)
1312 2451 aaronmk
            warnings.warn(DbWarning(msg))
1313
            log_debug(msg)
1314
            remove_all_rows()
1315 2358 aaronmk
        # after exception handled, rerun loop with additional constraints
1316 2132 aaronmk
1317 2357 aaronmk
    if row_ct_ref != None and cur.rowcount >= 0:
1318
        row_ct_ref[0] += cur.rowcount
1319
1320
    if has_joins:
1321
        select_joins = input_joins+[sql_gen.Join(out_table, join_cols)]
1322 2486 aaronmk
        log_debug('Getting output table pkeys of existing/inserted rows')
1323 2420 aaronmk
        insert_into_pkeys(select_joins, pkeys_cols)
1324 2357 aaronmk
    else:
1325 2404 aaronmk
        add_row_num(db, insert_out_pkeys) # for joining with input pkeys
1326 2357 aaronmk
1327 2486 aaronmk
        log_debug('Getting input table pkeys of inserted rows')
1328 2786 aaronmk
        run_query_into(db, mk_main_select(input_joins, [in_pkey]),
1329 2404 aaronmk
            into=insert_in_pkeys)
1330
        add_row_num(db, insert_in_pkeys) # for joining with output pkeys
1331 2357 aaronmk
1332 2428 aaronmk
        assert table_row_count(db, insert_out_pkeys) == table_row_count(db,
1333
            insert_in_pkeys)
1334
1335 2486 aaronmk
        log_debug('Combining output and input pkeys in inserted order')
1336 2404 aaronmk
        pkey_joins = [insert_in_pkeys, sql_gen.Join(insert_out_pkeys,
1337 2357 aaronmk
            {row_num_col: sql_gen.join_same_not_null})]
1338 2420 aaronmk
        insert_into_pkeys(pkey_joins, pkeys_names)
1339 2357 aaronmk
1340 2486 aaronmk
    db.log_debug('Adding pkey on pkeys table to enable fast joins', level=2.5)
1341 2594 aaronmk
    add_pkey(db, into)
1342 2407 aaronmk
1343 2508 aaronmk
    log_debug('Setting pkeys of missing rows to '+strings.as_tt(repr(default)))
1344 2489 aaronmk
    missing_rows_joins = input_joins+[sql_gen.Join(into,
1345 2357 aaronmk
        {in_pkey: sql_gen.join_same_not_null}, sql_gen.filter_out)]
1346
        # must use join_same_not_null or query will take forever
1347 2420 aaronmk
    insert_into_pkeys(missing_rows_joins,
1348 2508 aaronmk
        [in_pkey_col, sql_gen.NamedCol(out_pkey, default)])
1349 2357 aaronmk
1350 2489 aaronmk
    assert table_row_count(db, into) == table_row_count(db, in_table)
1351 2428 aaronmk
1352 2702 aaronmk
    srcs = []
1353
    if is_func: srcs = sql_gen.cols_srcs(in_cols)
1354
    return sql_gen.Col(out_pkey, into, srcs)
1355 2115 aaronmk
1356
##### Data cleanup
1357
1358 2290 aaronmk
def cleanup_table(db, table, cols):
1359 2677 aaronmk
    table = sql_gen.as_Table(table)
1360
    cols = map(sql_gen.as_Col, cols)
1361 2115 aaronmk
1362 2677 aaronmk
    expr = ('nullif(nullif(trim(both from %s), '+db.esc_value('')+'), '
1363
        +db.esc_value(r'\N')+')')
1364
    changes = [(v, sql_gen.CustomCode(expr % v.to_str(db)))
1365
        for v in cols]
1366 2115 aaronmk
1367 2677 aaronmk
    update(db, table, changes)