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 2804 aaronmk
def get_cur_query(cur, input_query=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 2804 aaronmk
    else: return '[input] '+strings.ustr(input_query)
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 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 2240 aaronmk
class FunctionValueException(ExceptionWithNameValue): 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 2915 aaronmk
        log_debug=log_debug_none, debug_temp=False):
158
        '''
159
        @param debug_temp Whether temporary objects should instead be permanent.
160
            This assists in debugging the internal objects used by the program.
161
        '''
162 1869 aaronmk
        self.db_config = db_config
163 2190 aaronmk
        self.autocommit = autocommit
164
        self.caching = caching
165 1901 aaronmk
        self.log_debug = log_debug
166 2193 aaronmk
        self.debug = log_debug != log_debug_none
167 2915 aaronmk
        self.debug_temp = debug_temp
168 1869 aaronmk
169
        self.__db = None
170 1889 aaronmk
        self.query_results = {}
171 2139 aaronmk
        self._savepoint = 0
172 2671 aaronmk
        self._notices_seen = set()
173 1869 aaronmk
174
    def __getattr__(self, name):
175
        if name == '__dict__': raise Exception('getting __dict__')
176
        if name == 'db': return self._db()
177
        else: raise AttributeError()
178
179
    def __getstate__(self):
180
        state = copy.copy(self.__dict__) # shallow copy
181 1915 aaronmk
        state['log_debug'] = None # don't pickle the debug callback
182 1869 aaronmk
        state['_DbConn__db'] = None # don't pickle the connection
183
        return state
184
185 2165 aaronmk
    def connected(self): return self.__db != None
186
187 1869 aaronmk
    def _db(self):
188
        if self.__db == None:
189
            # Process db_config
190
            db_config = self.db_config.copy() # don't modify input!
191 2097 aaronmk
            schemas = db_config.pop('schemas', None)
192 1869 aaronmk
            module_name, mappings = db_engines[db_config.pop('engine')]
193
            module = __import__(module_name)
194
            _add_module(module)
195
            for orig, new in mappings.iteritems():
196
                try: util.rename_key(db_config, orig, new)
197
                except KeyError: pass
198
199
            # Connect
200
            self.__db = module.connect(**db_config)
201
202
            # Configure connection
203 2906 aaronmk
            if hasattr(self.db, 'set_isolation_level'):
204
                import psycopg2.extensions
205
                self.db.set_isolation_level(
206
                    psycopg2.extensions.ISOLATION_LEVEL_READ_COMMITTED)
207 2101 aaronmk
            if schemas != None:
208 2893 aaronmk
                search_path = [self.esc_name(s) for s in schemas.split(',')]
209
                search_path.append(value(run_query(self, 'SHOW search_path',
210
                    log_level=4)))
211
                run_query(self, 'SET search_path TO '+(','.join(search_path)),
212
                    log_level=3)
213 1869 aaronmk
214
        return self.__db
215 1889 aaronmk
216 1891 aaronmk
    class DbCursor(Proxy):
217 1927 aaronmk
        def __init__(self, outer):
218 1891 aaronmk
            Proxy.__init__(self, outer.db.cursor())
219 2191 aaronmk
            self.outer = outer
220 1927 aaronmk
            self.query_results = outer.query_results
221 1894 aaronmk
            self.query_lookup = None
222 1891 aaronmk
            self.result = []
223 1889 aaronmk
224 2802 aaronmk
        def execute(self, query):
225 2764 aaronmk
            self._is_insert = query.startswith('INSERT')
226 2797 aaronmk
            self.query_lookup = query
227 2148 aaronmk
            try:
228 2191 aaronmk
                try:
229 2802 aaronmk
                    cur = self.inner.execute(query)
230 2191 aaronmk
                    self.outer.do_autocommit()
231 2802 aaronmk
                finally: self.query = get_cur_query(self.inner, query)
232 1904 aaronmk
            except Exception, e:
233 2802 aaronmk
                _add_cursor_info(e, self, query)
234 1904 aaronmk
                self.result = e # cache the exception as the result
235
                self._cache_result()
236
                raise
237 3004 aaronmk
238
            # Always cache certain queries
239
            if query.startswith('CREATE') or query.startswith('ALTER'):
240 3007 aaronmk
                # structural changes
241
                if query.find('ADD COLUMN') < 0: # rest of query must be unique
242
                    self._cache_result()
243 3004 aaronmk
            elif self.rowcount == 0 and query.startswith('SELECT'): # empty
244 2800 aaronmk
                consume_rows(self) # fetch all rows so result will be cached
245 3004 aaronmk
246 2762 aaronmk
            return cur
247 1894 aaronmk
248 1891 aaronmk
        def fetchone(self):
249
            row = self.inner.fetchone()
250 1899 aaronmk
            if row != None: self.result.append(row)
251
            # otherwise, fetched all rows
252 1904 aaronmk
            else: self._cache_result()
253
            return row
254
255
        def _cache_result(self):
256 2948 aaronmk
            # For inserts that return a result set, don't cache result set since
257
            # inserts are not idempotent. Other non-SELECT queries don't have
258
            # their result set read, so only exceptions will be cached (an
259
            # invalid query will always be invalid).
260 1930 aaronmk
            if self.query_results != None and (not self._is_insert
261 1906 aaronmk
                or isinstance(self.result, Exception)):
262
263 1894 aaronmk
                assert self.query_lookup != None
264 1916 aaronmk
                self.query_results[self.query_lookup] = self.CacheCursor(
265
                    util.dict_subset(dicts.AttrsDictView(self),
266
                    ['query', 'result', 'rowcount', 'description']))
267 1906 aaronmk
268 1916 aaronmk
        class CacheCursor:
269
            def __init__(self, cached_result): self.__dict__ = cached_result
270
271 1927 aaronmk
            def execute(self, *args, **kw_args):
272 1916 aaronmk
                if isinstance(self.result, Exception): raise self.result
273
                # otherwise, result is a rows list
274
                self.iter = iter(self.result)
275
276
            def fetchone(self):
277
                try: return self.iter.next()
278
                except StopIteration: return None
279 1891 aaronmk
280 2212 aaronmk
    def esc_value(self, value):
281 2663 aaronmk
        try: str_ = self.mogrify('%s', [value])
282
        except NotImplementedError, e:
283
            module = util.root_module(self.db)
284
            if module == 'MySQLdb':
285
                import _mysql
286
                str_ = _mysql.escape_string(value)
287
            else: raise e
288 2374 aaronmk
        return strings.to_unicode(str_)
289 2212 aaronmk
290 2347 aaronmk
    def esc_name(self, name): return esc_name(self, name) # calls global func
291
292 2814 aaronmk
    def std_code(self, str_):
293
        '''Standardizes SQL code.
294
        * Ensures that string literals are prefixed by `E`
295
        '''
296
        if str_.startswith("'"): str_ = 'E'+str_
297
        return str_
298
299 2665 aaronmk
    def can_mogrify(self):
300 2663 aaronmk
        module = util.root_module(self.db)
301 2665 aaronmk
        return module == 'psycopg2'
302 2663 aaronmk
303 2665 aaronmk
    def mogrify(self, query, params=None):
304
        if self.can_mogrify(): return self.db.cursor().mogrify(query, params)
305
        else: raise NotImplementedError("Can't mogrify query")
306
307 2671 aaronmk
    def print_notices(self):
308 2725 aaronmk
        if hasattr(self.db, 'notices'):
309
            for msg in self.db.notices:
310
                if msg not in self._notices_seen:
311
                    self._notices_seen.add(msg)
312
                    self.log_debug(msg, level=2)
313 2671 aaronmk
314 2793 aaronmk
    def run_query(self, query, cacheable=False, log_level=2,
315 2464 aaronmk
        debug_msg_ref=None):
316 2445 aaronmk
        '''
317 2464 aaronmk
        @param log_ignore_excs The log_level will be increased by 2 if the query
318
            throws one of these exceptions.
319 2664 aaronmk
        @param debug_msg_ref If specified, the log message will be returned in
320
            this instead of being output. This allows you to filter log messages
321
            depending on the result of the query.
322 2445 aaronmk
        '''
323 2167 aaronmk
        assert query != None
324
325 2047 aaronmk
        if not self.caching: cacheable = False
326 1903 aaronmk
        used_cache = False
327 2664 aaronmk
328
        def log_msg(query):
329
            if used_cache: cache_status = 'cache hit'
330
            elif cacheable: cache_status = 'cache miss'
331
            else: cache_status = 'non-cacheable'
332
            return 'DB query: '+cache_status+':\n'+strings.as_code(query, 'SQL')
333
334 1903 aaronmk
        try:
335 1927 aaronmk
            # Get cursor
336
            if cacheable:
337
                try:
338 2797 aaronmk
                    cur = self.query_results[query]
339 1927 aaronmk
                    used_cache = True
340
                except KeyError: cur = self.DbCursor(self)
341
            else: cur = self.db.cursor()
342
343 2664 aaronmk
            # Log query
344
            if self.debug and debug_msg_ref == None: # log before running
345
                self.log_debug(log_msg(query), log_level)
346
347 1927 aaronmk
            # Run query
348 2793 aaronmk
            cur.execute(query)
349 1903 aaronmk
        finally:
350 2671 aaronmk
            self.print_notices()
351 2664 aaronmk
            if self.debug and debug_msg_ref != None: # return after running
352 2793 aaronmk
                debug_msg_ref[0] = log_msg(str(get_cur_query(cur, query)))
353 1903 aaronmk
354
        return cur
355 1914 aaronmk
356 2797 aaronmk
    def is_cached(self, query): return query in self.query_results
357 2139 aaronmk
358 2907 aaronmk
    def with_autocommit(self, func):
359 2801 aaronmk
        import psycopg2.extensions
360
361
        prev_isolation_level = self.db.isolation_level
362 2907 aaronmk
        self.db.set_isolation_level(
363
            psycopg2.extensions.ISOLATION_LEVEL_AUTOCOMMIT)
364 2683 aaronmk
        try: return func()
365 2801 aaronmk
        finally: self.db.set_isolation_level(prev_isolation_level)
366 2683 aaronmk
367 2139 aaronmk
    def with_savepoint(self, func):
368 2171 aaronmk
        savepoint = 'level_'+str(self._savepoint)
369 2443 aaronmk
        self.run_query('SAVEPOINT '+savepoint, log_level=4)
370 2139 aaronmk
        self._savepoint += 1
371 2930 aaronmk
        try: return func()
372 2139 aaronmk
        except:
373 2443 aaronmk
            self.run_query('ROLLBACK TO SAVEPOINT '+savepoint, log_level=4)
374 2139 aaronmk
            raise
375 2930 aaronmk
        finally:
376
            # Always release savepoint, because after ROLLBACK TO SAVEPOINT,
377
            # "The savepoint remains valid and can be rolled back to again"
378
            # (http://www.postgresql.org/docs/8.3/static/sql-rollback-to.html).
379 2443 aaronmk
            self.run_query('RELEASE SAVEPOINT '+savepoint, log_level=4)
380 2930 aaronmk
381
            self._savepoint -= 1
382
            assert self._savepoint >= 0
383
384
            self.do_autocommit() # OK to do this after ROLLBACK TO SAVEPOINT
385 2191 aaronmk
386
    def do_autocommit(self):
387
        '''Autocommits if outside savepoint'''
388
        assert self._savepoint >= 0
389
        if self.autocommit and self._savepoint == 0:
390 2924 aaronmk
            self.log_debug('Autocommitting', level=4)
391 2191 aaronmk
            self.db.commit()
392 2643 aaronmk
393 2819 aaronmk
    def col_info(self, col):
394 2643 aaronmk
        table = sql_gen.Table('columns', 'information_schema')
395 2821 aaronmk
        cols = ['data_type', 'column_default',
396
            cast(self, 'boolean', 'is_nullable')]
397 2643 aaronmk
398
        conds = [('table_name', col.table.name), ('column_name', col.name)]
399
        schema = col.table.schema
400
        if schema != None: conds.append(('table_schema', schema))
401
402 2819 aaronmk
        type_, default, nullable = row(select(self, table, cols, conds,
403 2874 aaronmk
            order_by='table_schema', limit=1, log_level=4))
404 2643 aaronmk
            # TODO: order_by search_path schema order
405 2819 aaronmk
        default = sql_gen.as_Code(default, self)
406
407
        return sql_gen.TypedCol(col.name, type_, default, nullable)
408 2917 aaronmk
409
    def TempFunction(self, name):
410
        if self.debug_temp: schema = None
411
        else: schema = 'pg_temp'
412
        return sql_gen.Function(name, schema)
413 1849 aaronmk
414 1869 aaronmk
connect = DbConn
415
416 832 aaronmk
##### Recoverable querying
417 15 aaronmk
418 2139 aaronmk
def with_savepoint(db, func): return db.with_savepoint(func)
419 11 aaronmk
420 2791 aaronmk
def run_query(db, query, recover=None, cacheable=False, log_level=2,
421
    log_ignore_excs=None, **kw_args):
422 2794 aaronmk
    '''For params, see DbConn.run_query()'''
423 830 aaronmk
    if recover == None: recover = False
424 2464 aaronmk
    if log_ignore_excs == None: log_ignore_excs = ()
425
    log_ignore_excs = tuple(log_ignore_excs)
426 830 aaronmk
427 2666 aaronmk
    debug_msg_ref = None # usually, db.run_query() logs query before running it
428
    # But if filtering with log_ignore_excs, wait until after exception parsing
429 2984 aaronmk
    if log_ignore_excs != () or not db.can_mogrify(): debug_msg_ref = [None]
430 2666 aaronmk
431 2148 aaronmk
    try:
432 2464 aaronmk
        try:
433 2794 aaronmk
            def run(): return db.run_query(query, cacheable, log_level,
434 2793 aaronmk
                debug_msg_ref, **kw_args)
435 2796 aaronmk
            if recover and not db.is_cached(query):
436 2464 aaronmk
                return with_savepoint(db, run)
437
            else: return run() # don't need savepoint if cached
438
        except Exception, e:
439
            if not recover: raise # need savepoint to run index_cols()
440
            msg = exc.str_(e)
441
442
            match = re.search(r'duplicate key value violates unique constraint '
443 2493 aaronmk
                r'"((_?[^\W_]+)_.+?)"', msg)
444 2464 aaronmk
            if match:
445
                constraint, table = match.groups()
446
                try: cols = index_cols(db, table, constraint)
447
                except NotImplementedError: raise e
448
                else: raise DuplicateKeyException(constraint, cols, e)
449
450 2493 aaronmk
            match = re.search(r'null value in column "(.+?)" violates not-null'
451 2464 aaronmk
                r' constraint', msg)
452
            if match: raise NullValueException('NOT NULL', [match.group(1)], e)
453
454
            match = re.search(r'\b(?:invalid input (?:syntax|value)\b.*?'
455
                r'|date/time field value out of range): "(.+?)"\n'
456 2535 aaronmk
                r'(?:(?s).*?)\bfunction "(.+?)"', msg)
457 2464 aaronmk
            if match:
458
                value, name = match.groups()
459
                raise FunctionValueException(name, strings.to_unicode(value), e)
460
461 2526 aaronmk
            match = re.search(r'column "(.+?)" is of type (.+?) but expression '
462 2523 aaronmk
                r'is of type', msg)
463
            if match:
464
                col, type_ = match.groups()
465
                raise MissingCastException(type_, col, e)
466
467 2946 aaronmk
            match = re.search(r'\b(\S+) "(.+?)".*? already exists', msg)
468 2945 aaronmk
            if match:
469
                type_, name = match.groups()
470
                raise DuplicateException(type_, name, e)
471 2464 aaronmk
472
            raise # no specific exception raised
473
    except log_ignore_excs:
474
        log_level += 2
475
        raise
476
    finally:
477 2666 aaronmk
        if debug_msg_ref != None and debug_msg_ref[0] != None:
478
            db.log_debug(debug_msg_ref[0], log_level)
479 830 aaronmk
480 832 aaronmk
##### Basic queries
481
482 2153 aaronmk
def next_version(name):
483 2163 aaronmk
    version = 1 # first existing name was version 0
484 2586 aaronmk
    match = re.match(r'^(.*)#(\d+)$', name)
485 2153 aaronmk
    if match:
486 2586 aaronmk
        name, version = match.groups()
487
        version = int(version)+1
488 2932 aaronmk
    return sql_gen.concat(name, '#'+str(version))
489 2153 aaronmk
490 2899 aaronmk
def lock_table(db, table, mode):
491
    table = sql_gen.as_Table(table)
492
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
493
494 2789 aaronmk
def run_query_into(db, query, into=None, add_indexes_=False, **kw_args):
495 2085 aaronmk
    '''Outputs a query to a temp table.
496
    For params, see run_query().
497
    '''
498 2789 aaronmk
    if into == None: return run_query(db, query, **kw_args)
499 2790 aaronmk
500
    assert isinstance(into, sql_gen.Table)
501
502 2992 aaronmk
    into.is_temp = True
503
504 2790 aaronmk
    kw_args['recover'] = True
505 2945 aaronmk
    kw_args.setdefault('log_ignore_excs', (DuplicateException,))
506 2790 aaronmk
507 2916 aaronmk
    temp = not db.debug_temp # tables are permanent in debug_temp mode
508 2790 aaronmk
    # "temporary tables cannot specify a schema name", so remove schema
509
    if temp: into.schema = None
510
511
    # Create table
512
    while True:
513
        create_query = 'CREATE'
514
        if temp: create_query += ' TEMP'
515
        create_query += ' TABLE '+into.to_str(db)+' AS\n'+query
516 2385 aaronmk
517 2790 aaronmk
        try:
518
            cur = run_query(db, create_query, **kw_args)
519
                # CREATE TABLE AS sets rowcount to # rows in query
520
            break
521 2945 aaronmk
        except DuplicateException, e:
522 2790 aaronmk
            into.name = next_version(into.name)
523
            # try again with next version of name
524
525
    if add_indexes_: add_indexes(db, into)
526
527
    return cur
528 2085 aaronmk
529 2120 aaronmk
order_by_pkey = object() # tells mk_select() to order by the pkey
530
531 2199 aaronmk
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
532
533 2233 aaronmk
def mk_select(db, tables, fields=None, conds=None, distinct_on=[], limit=None,
534 2293 aaronmk
    start=None, order_by=order_by_pkey, default_table=None):
535 1981 aaronmk
    '''
536 2121 aaronmk
    @param tables The single table to select from, or a list of tables to join
537 2280 aaronmk
        together, with tables after the first being sql_gen.Join objects
538 1981 aaronmk
    @param fields Use None to select all fields in the table
539 2377 aaronmk
    @param conds WHERE conditions: [(compare_left_side, compare_right_side),...]
540 2379 aaronmk
        * container can be any iterable type
541 2399 aaronmk
        * compare_left_side: sql_gen.Code|str (for col name)
542
        * compare_right_side: sql_gen.ValueCond|literal value
543 2199 aaronmk
    @param distinct_on The columns to SELECT DISTINCT ON, or distinct_on_all to
544
        use all columns
545 2786 aaronmk
    @return query
546 1981 aaronmk
    '''
547 2315 aaronmk
    # Parse tables param
548 2964 aaronmk
    tables = lists.mk_seq(tables)
549 2141 aaronmk
    tables = list(tables) # don't modify input! (list() copies input)
550 2315 aaronmk
    table0 = sql_gen.as_Table(tables.pop(0)) # first table is separate
551 2121 aaronmk
552 2315 aaronmk
    # Parse other params
553 2376 aaronmk
    if conds == None: conds = []
554 2650 aaronmk
    elif dicts.is_dict(conds): conds = conds.items()
555 2379 aaronmk
    conds = list(conds) # don't modify input! (list() copies input)
556 135 aaronmk
    assert limit == None or type(limit) == int
557 865 aaronmk
    assert start == None or type(start) == int
558 2315 aaronmk
    if order_by is order_by_pkey:
559
        if distinct_on != []: order_by = None
560
        else: order_by = pkey(db, table0, recover=True)
561 865 aaronmk
562 2315 aaronmk
    query = 'SELECT'
563 2056 aaronmk
564 2315 aaronmk
    def parse_col(col): return sql_gen.as_Col(col, default_table).to_str(db)
565 2056 aaronmk
566 2200 aaronmk
    # DISTINCT ON columns
567 2233 aaronmk
    if distinct_on != []:
568 2467 aaronmk
        query += '\nDISTINCT'
569 2254 aaronmk
        if distinct_on is not distinct_on_all:
570 2200 aaronmk
            query += ' ON ('+(', '.join(map(parse_col, distinct_on)))+')'
571
572
    # Columns
573 2467 aaronmk
    query += '\n'
574 1135 aaronmk
    if fields == None: query += '*'
575 2765 aaronmk
    else:
576
        assert fields != []
577
        query += '\n, '.join(map(parse_col, fields))
578 2200 aaronmk
579
    # Main table
580 2467 aaronmk
    query += '\nFROM '+table0.to_str(db)
581 865 aaronmk
582 2122 aaronmk
    # Add joins
583 2271 aaronmk
    left_table = table0
584 2263 aaronmk
    for join_ in tables:
585
        table = join_.table
586 2238 aaronmk
587 2343 aaronmk
        # Parse special values
588
        if join_.type_ is sql_gen.filter_out: # filter no match
589 2376 aaronmk
            conds.append((sql_gen.Col(table_not_null_col(db, table), table),
590 2853 aaronmk
                sql_gen.CompareCond(None, '~=')))
591 2343 aaronmk
592 2467 aaronmk
        query += '\n'+join_.to_str(db, left_table)
593 2122 aaronmk
594
        left_table = table
595
596 865 aaronmk
    missing = True
597 2376 aaronmk
    if conds != []:
598 2576 aaronmk
        if len(conds) == 1: whitespace = ' '
599
        else: whitespace = '\n'
600 2578 aaronmk
        query += '\n'+sql_gen.combine_conds([sql_gen.ColValueCond(l, r)
601
            .to_str(db) for l, r in conds], 'WHERE')
602 865 aaronmk
        missing = False
603 2227 aaronmk
    if order_by != None:
604 2467 aaronmk
        query += '\nORDER BY '+sql_gen.as_Col(order_by, table0).to_str(db)
605
    if limit != None: query += '\nLIMIT '+str(limit); missing = False
606 865 aaronmk
    if start != None:
607 2467 aaronmk
        if start != 0: query += '\nOFFSET '+str(start)
608 865 aaronmk
        missing = False
609
    if missing: warnings.warn(DbWarning(
610
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
611
612 2786 aaronmk
    return query
613 11 aaronmk
614 2054 aaronmk
def select(db, *args, **kw_args):
615
    '''For params, see mk_select() and run_query()'''
616
    recover = kw_args.pop('recover', None)
617
    cacheable = kw_args.pop('cacheable', True)
618 2442 aaronmk
    log_level = kw_args.pop('log_level', 2)
619 2054 aaronmk
620 2791 aaronmk
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
621
        log_level=log_level)
622 2054 aaronmk
623 2788 aaronmk
def mk_insert_select(db, table, cols=None, select_query=None, returning=None,
624
    embeddable=False):
625 1960 aaronmk
    '''
626
    @param returning str|None An inserted column (such as pkey) to return
627 2070 aaronmk
    @param embeddable Whether the query should be embeddable as a nested SELECT.
628 2073 aaronmk
        Warning: If you set this and cacheable=True when the query is run, the
629
        query will be fully cached, not just if it raises an exception.
630 1960 aaronmk
    '''
631 2754 aaronmk
    table = sql_gen.remove_table_rename(sql_gen.as_Table(table))
632 2318 aaronmk
    if cols == []: cols = None # no cols (all defaults) = unknown col names
633 2646 aaronmk
    if cols != None:
634
        cols = [sql_gen.to_name_only_col(v, table).to_str(db) for v in cols]
635 2063 aaronmk
    if select_query == None: select_query = 'DEFAULT VALUES'
636 2327 aaronmk
    if returning != None: returning = sql_gen.as_Col(returning, table)
637 2063 aaronmk
638
    # Build query
639 2497 aaronmk
    first_line = 'INSERT INTO '+table.to_str(db)
640
    query = first_line
641 2467 aaronmk
    if cols != None: query += '\n('+', '.join(cols)+')'
642
    query += '\n'+select_query
643 2063 aaronmk
644
    if returning != None:
645 2743 aaronmk
        query += '\nRETURNING '+sql_gen.to_name_only_col(returning).to_str(db)
646 2063 aaronmk
647 2070 aaronmk
    if embeddable:
648 2327 aaronmk
        assert returning != None
649
650 2070 aaronmk
        # Create function
651 2513 aaronmk
        function_name = sql_gen.clean_name(first_line)
652 2327 aaronmk
        return_type = 'SETOF '+returning.to_str(db)+'%TYPE'
653 2189 aaronmk
        while True:
654
            try:
655 2918 aaronmk
                function = db.TempFunction(function_name)
656 2194 aaronmk
657 2189 aaronmk
                function_query = '''\
658 2698 aaronmk
CREATE FUNCTION '''+function.to_str(db)+'''()
659 2467 aaronmk
RETURNS '''+return_type+'''
660
LANGUAGE sql
661
AS $$
662 2788 aaronmk
'''+query+''';
663 2467 aaronmk
$$;
664 2070 aaronmk
'''
665 2446 aaronmk
                run_query(db, function_query, recover=True, cacheable=True,
666 2945 aaronmk
                    log_ignore_excs=(DuplicateException,))
667 2189 aaronmk
                break # this version was successful
668 2945 aaronmk
            except DuplicateException, e:
669 2189 aaronmk
                function_name = next_version(function_name)
670
                # try again with next version of name
671 2070 aaronmk
672 2337 aaronmk
        # Return query that uses function
673 2698 aaronmk
        func_table = sql_gen.NamedTable('f', sql_gen.FunctionCall(function),
674 2742 aaronmk
            [returning]) # AS clause requires function alias
675 2787 aaronmk
        return mk_select(db, func_table, start=0, order_by=None)
676 2070 aaronmk
677 2787 aaronmk
    return query
678 2066 aaronmk
679
def insert_select(db, *args, **kw_args):
680 2085 aaronmk
    '''For params, see mk_insert_select() and run_query_into()
681 2386 aaronmk
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
682
        values in
683 2072 aaronmk
    '''
684 2386 aaronmk
    into = kw_args.pop('into', None)
685
    if into != None: kw_args['embeddable'] = True
686 2066 aaronmk
    recover = kw_args.pop('recover', None)
687
    cacheable = kw_args.pop('cacheable', True)
688 2673 aaronmk
    log_level = kw_args.pop('log_level', 2)
689 2066 aaronmk
690 2789 aaronmk
    return run_query_into(db, mk_insert_select(db, *args, **kw_args), into,
691 2787 aaronmk
        recover=recover, cacheable=cacheable, log_level=log_level)
692 2063 aaronmk
693 2738 aaronmk
default = sql_gen.default # tells insert() to use the default value for a column
694 2066 aaronmk
695 2063 aaronmk
def insert(db, table, row, *args, **kw_args):
696 2085 aaronmk
    '''For params, see insert_select()'''
697 1960 aaronmk
    if lists.is_seq(row): cols = None
698
    else:
699
        cols = row.keys()
700
        row = row.values()
701 2738 aaronmk
    row = list(row) # ensure that "== []" works
702 1960 aaronmk
703 2738 aaronmk
    if row == []: query = None
704
    else: query = sql_gen.Values(row).to_str(db)
705 1961 aaronmk
706 2788 aaronmk
    return insert_select(db, table, cols, query, *args, **kw_args)
707 11 aaronmk
708 2402 aaronmk
def mk_update(db, table, changes=None, cond=None):
709
    '''
710
    @param changes [(col, new_value),...]
711
        * container can be any iterable type
712
        * col: sql_gen.Code|str (for col name)
713
        * new_value: sql_gen.Code|literal value
714
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
715
    @return str query
716
    '''
717
    query = 'UPDATE '+sql_gen.as_Table(table).to_str(db)+'\nSET\n'
718 2405 aaronmk
    query += ',\n'.join((sql_gen.to_name_only_col(col, table).to_str(db)+' = '
719 2402 aaronmk
        +sql_gen.as_Value(new_value).to_str(db) for col, new_value in changes))
720 2467 aaronmk
    if cond != None: query += '\nWHERE\n'+cond.to_str(db)
721 2402 aaronmk
722
    return query
723
724
def update(db, *args, **kw_args):
725
    '''For params, see mk_update() and run_query()'''
726
    recover = kw_args.pop('recover', None)
727
728 2791 aaronmk
    return run_query(db, mk_update(db, *args, **kw_args), recover)
729 2402 aaronmk
730 135 aaronmk
def last_insert_id(db):
731 1849 aaronmk
    module = util.root_module(db.db)
732 135 aaronmk
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
733
    elif module == 'MySQLdb': return db.insert_id()
734
    else: return None
735 13 aaronmk
736 2394 aaronmk
def mk_flatten_mapping(db, into, cols, preserve=[], as_items=False):
737 2383 aaronmk
    '''Creates a mapping from original column names (which may have collisions)
738 2415 aaronmk
    to names that will be distinct among the columns' tables.
739 2383 aaronmk
    This is meant to be used for several tables that are being joined together.
740 2415 aaronmk
    @param cols The columns to combine. Duplicates will be removed.
741
    @param into The table for the new columns.
742 2394 aaronmk
    @param preserve [sql_gen.Col...] Columns not to rename. Note that these
743
        columns will be included in the mapping even if they are not in cols.
744
        The tables of the provided Col objects will be changed to into, so make
745
        copies of them if you want to keep the original tables.
746
    @param as_items Whether to return a list of dict items instead of a dict
747 2383 aaronmk
    @return dict(orig_col=new_col, ...)
748
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
749 2392 aaronmk
        * new_col: sql_gen.Col(orig_col_name, into)
750
        * All mappings use the into table so its name can easily be
751 2383 aaronmk
          changed for all columns at once
752
    '''
753 2415 aaronmk
    cols = lists.uniqify(cols)
754
755 2394 aaronmk
    items = []
756 2389 aaronmk
    for col in preserve:
757 2390 aaronmk
        orig_col = copy.copy(col)
758 2392 aaronmk
        col.table = into
759 2394 aaronmk
        items.append((orig_col, col))
760
    preserve = set(preserve)
761
    for col in cols:
762 2716 aaronmk
        if col not in preserve:
763
            items.append((col, sql_gen.Col(str(col), into, col.srcs)))
764 2394 aaronmk
765
    if not as_items: items = dict(items)
766
    return items
767 2383 aaronmk
768 2393 aaronmk
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
769 2391 aaronmk
    '''For params, see mk_flatten_mapping()
770
    @return See return value of mk_flatten_mapping()
771
    '''
772 2394 aaronmk
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
773
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
774 2786 aaronmk
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
775 2846 aaronmk
        into=into, add_indexes_=True)
776 2394 aaronmk
    return dict(items)
777 2391 aaronmk
778 2751 aaronmk
def mk_track_data_error(db, errors_table, cols, value, error_code, error):
779 2810 aaronmk
    assert cols != ()
780
781 2751 aaronmk
    cols = map(sql_gen.to_name_only_col, cols)
782
783
    columns_cols = ['column']
784
    columns = sql_gen.NamedValues('columns', columns_cols,
785
        [[c.name] for c in cols])
786
    values_cols = ['value', 'error_code', 'error']
787
    values = sql_gen.NamedValues('values', values_cols,
788
        [value, error_code, error])
789
790
    select_cols = columns_cols+values_cols
791
    name_only_cols = map(sql_gen.to_name_only_col, select_cols)
792 2755 aaronmk
    errors_table = sql_gen.NamedTable('errors', errors_table)
793 2751 aaronmk
    joins = [columns, sql_gen.Join(values, type_='CROSS'),
794
        sql_gen.Join(errors_table, dict(zip(name_only_cols, select_cols)),
795
        sql_gen.filter_out)]
796
797
    return mk_insert_select(db, errors_table, name_only_cols,
798 2787 aaronmk
        mk_select(db, joins, select_cols, order_by=None))
799 2751 aaronmk
800 2810 aaronmk
def track_data_error(db, errors_table, cols, *args, **kw_args):
801 2758 aaronmk
    '''
802
    @param errors_table If None, does nothing.
803
    '''
804 2810 aaronmk
    if errors_table == None or cols == (): return
805
    run_query(db, mk_track_data_error(db, errors_table, cols, *args, **kw_args),
806 2758 aaronmk
        cacheable=True, log_level=4)
807
808 2704 aaronmk
def cast(db, type_, col, errors_table=None):
809
    '''Casts an (unrenamed) column or value.
810 2769 aaronmk
    If errors_table set and col has srcs, saves errors in errors_table (using
811
    col's srcs attr as the source columns) and converts errors to warnings.
812 2820 aaronmk
    @param col str|sql_gen.Col|sql_gen.Literal
813 2704 aaronmk
    @param errors_table None|sql_gen.Table|str
814
    '''
815 2820 aaronmk
    col = sql_gen.as_Col(col)
816 2769 aaronmk
    save_errors = (errors_table != None and isinstance(col, sql_gen.Col)
817
        and col.srcs != ())
818 2987 aaronmk
    if not save_errors: return sql_gen.Cast(type_, col) # can't save errors
819 2704 aaronmk
820
    assert not isinstance(col, sql_gen.NamedCol)
821
822 2770 aaronmk
    errors_table = sql_gen.as_Table(errors_table)
823
    srcs = map(sql_gen.to_name_only_col, col.srcs)
824
    function_name = str(sql_gen.FunctionCall(type_, *srcs))
825 2918 aaronmk
    function = db.TempFunction(function_name)
826 2704 aaronmk
827 2718 aaronmk
    while True:
828
        # Create function definition
829
        query = '''\
830 2704 aaronmk
CREATE FUNCTION '''+function.to_str(db)+'''(value text)
831
RETURNS '''+type_+'''
832
LANGUAGE plpgsql
833
STRICT
834
AS $$
835
BEGIN
836
    /* The explicit cast to the return type is needed to make the cast happen
837
    inside the try block. (Implicit casts to the return type happen at the end
838
    of the function, outside any block.) */
839
    RETURN value::'''+type_+''';
840
EXCEPTION
841
    WHEN data_exception THEN
842
        -- Save error in errors table.
843 2751 aaronmk
        -- Insert the value and error for *each* source column.
844
'''+mk_track_data_error(db, errors_table, srcs,
845
    *map(sql_gen.CustomCode, ['value', 'SQLSTATE', 'SQLERRM']))+''';
846 2704 aaronmk
847
        RAISE WARNING '%', SQLERRM;
848
        RETURN NULL;
849
END;
850
$$;
851
'''
852 2718 aaronmk
853
        # Create function
854
        try:
855
            run_query(db, query, recover=True, cacheable=True,
856 2945 aaronmk
                log_ignore_excs=(DuplicateException,))
857 2718 aaronmk
            break # successful
858 2945 aaronmk
        except DuplicateException:
859 2770 aaronmk
            function.name = next_version(function.name)
860
            # try again with next version of name
861 2704 aaronmk
862
    return sql_gen.FunctionCall(function, col)
863
864 2414 aaronmk
##### Database structure queries
865
866 2426 aaronmk
def table_row_count(db, table, recover=None):
867 2786 aaronmk
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
868 2443 aaronmk
        order_by=None, start=0), recover=recover, log_level=3))
869 2426 aaronmk
870 2414 aaronmk
def table_cols(db, table, recover=None):
871
    return list(col_names(select(db, table, limit=0, order_by=None,
872 2443 aaronmk
        recover=recover, log_level=4)))
873 2414 aaronmk
874 2291 aaronmk
def pkey(db, table, recover=None):
875 832 aaronmk
    '''Assumed to be first column in table'''
876 2339 aaronmk
    return table_cols(db, table, recover)[0]
877 832 aaronmk
878 2559 aaronmk
not_null_col = 'not_null_col'
879 2340 aaronmk
880
def table_not_null_col(db, table, recover=None):
881
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
882
    if not_null_col in table_cols(db, table, recover): return not_null_col
883
    else: return pkey(db, table, recover)
884
885 853 aaronmk
def index_cols(db, table, index):
886
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
887
    automatically created. When you don't know whether something is a UNIQUE
888
    constraint or a UNIQUE index, use this function.'''
889 1909 aaronmk
    module = util.root_module(db.db)
890
    if module == 'psycopg2':
891
        return list(values(run_query(db, '''\
892 853 aaronmk
SELECT attname
893 866 aaronmk
FROM
894
(
895
        SELECT attnum, attname
896
        FROM pg_index
897
        JOIN pg_class index ON index.oid = indexrelid
898
        JOIN pg_class table_ ON table_.oid = indrelid
899
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
900
        WHERE
901 2782 aaronmk
            table_.relname = '''+db.esc_value(table)+'''
902
            AND index.relname = '''+db.esc_value(index)+'''
903 866 aaronmk
    UNION
904
        SELECT attnum, attname
905
        FROM
906
        (
907
            SELECT
908
                indrelid
909
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
910
                    AS indkey
911
            FROM pg_index
912
            JOIN pg_class index ON index.oid = indexrelid
913
            JOIN pg_class table_ ON table_.oid = indrelid
914
            WHERE
915 2782 aaronmk
                table_.relname = '''+db.esc_value(table)+'''
916
                AND index.relname = '''+db.esc_value(index)+'''
917 866 aaronmk
        ) s
918
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
919
) s
920 853 aaronmk
ORDER BY attnum
921 2782 aaronmk
'''
922
            , cacheable=True, log_level=4)))
923 1909 aaronmk
    else: raise NotImplementedError("Can't list index columns for "+module+
924
        ' database')
925 853 aaronmk
926 464 aaronmk
def constraint_cols(db, table, constraint):
927 1849 aaronmk
    module = util.root_module(db.db)
928 464 aaronmk
    if module == 'psycopg2':
929
        return list(values(run_query(db, '''\
930
SELECT attname
931
FROM pg_constraint
932
JOIN pg_class ON pg_class.oid = conrelid
933
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
934
WHERE
935 2783 aaronmk
    relname = '''+db.esc_value(table)+'''
936
    AND conname = '''+db.esc_value(constraint)+'''
937 464 aaronmk
ORDER BY attnum
938 2783 aaronmk
'''
939
            )))
940 464 aaronmk
    else: raise NotImplementedError("Can't list constraint columns for "+module+
941
        ' database')
942
943 2096 aaronmk
row_num_col = '_row_num'
944
945 2998 aaronmk
def add_index(db, exprs, table=None, unique=False, ensure_not_null_=True):
946 2688 aaronmk
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
947 2538 aaronmk
    Currently, only function calls are supported as expressions.
948 2998 aaronmk
    @param ensure_not_null_ If set, translates NULL values to sentinel values.
949 2847 aaronmk
        This allows indexes to be used for comparisons where NULLs are equal.
950 2538 aaronmk
    '''
951 2964 aaronmk
    exprs = lists.mk_seq(exprs)
952 2538 aaronmk
953 2688 aaronmk
    # Parse exprs
954
    old_exprs = exprs[:]
955
    exprs = []
956
    cols = []
957
    for i, expr in enumerate(old_exprs):
958 2823 aaronmk
        expr = sql_gen.as_Col(expr, table)
959 2688 aaronmk
960 2823 aaronmk
        # Handle nullable columns
961 2998 aaronmk
        if ensure_not_null_:
962
            try: expr = ensure_not_null(db, expr)
963 2860 aaronmk
            except KeyError: pass # unknown type, so just create plain index
964 2823 aaronmk
965 2688 aaronmk
        # Extract col
966 3002 aaronmk
        expr = copy.deepcopy(expr) # don't modify input!
967 2688 aaronmk
        if isinstance(expr, sql_gen.FunctionCall):
968
            col = expr.args[0]
969
            expr = sql_gen.Expr(expr)
970
        else: col = expr
971 2823 aaronmk
        assert isinstance(col, sql_gen.Col)
972 2688 aaronmk
973
        # Extract table
974
        if table == None:
975
            assert sql_gen.is_table_col(col)
976
            table = col.table
977
978
        col.table = None
979
980
        exprs.append(expr)
981
        cols.append(col)
982 2408 aaronmk
983 2688 aaronmk
    table = sql_gen.as_Table(table)
984
    index = sql_gen.Table(str(sql_gen.Col(','.join(map(str, cols)), table)))
985
986 3005 aaronmk
    # Add index
987
    while True:
988
        str_ = 'CREATE'
989
        if unique: str_ += ' UNIQUE'
990
        str_ += ' INDEX '+index.to_str(db)+' ON '+table.to_str(db)+' ('+(
991
            ', '.join((v.to_str(db) for v in exprs)))+')'
992
993
        try:
994
            run_query(db, str_, recover=True, cacheable=True, log_level=3,
995
                log_ignore_excs=(DuplicateException,))
996
            break
997
        except DuplicateException:
998
            index.name = next_version(index.name)
999
            # try again with next version of name
1000 2408 aaronmk
1001 2686 aaronmk
def add_pkey(db, table, cols=None, recover=None):
1002
    '''Adds a primary key.
1003
    @param cols [sql_gen.Col,...] The columns in the primary key.
1004
        Defaults to the first column in the table.
1005 2406 aaronmk
    @pre The table must not already have a primary key.
1006
    '''
1007
    table = sql_gen.as_Table(table)
1008 2686 aaronmk
    if cols == None: cols = [pkey(db, table, recover)]
1009
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1010 2406 aaronmk
1011 2781 aaronmk
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1012
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1013 2945 aaronmk
        log_ignore_excs=(DuplicateException,))
1014 2406 aaronmk
1015 2997 aaronmk
def add_not_null(db, col):
1016
    table = col.table
1017
    col = sql_gen.to_name_only_col(col)
1018
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1019
        +col.to_str(db)+' SET NOT NULL', cacheable=True)
1020
1021
def add_index_col(db, col, suffix, expr, nullable=True):
1022 3000 aaronmk
    if sql_gen.index_col(col) != None: return # already has index col
1023 2997 aaronmk
1024
    new_col = sql_gen.suffixed_col(col, suffix)
1025
1026 3006 aaronmk
    # Add column
1027
    while True:
1028
        new_typed_col = sql_gen.TypedCol(new_col.name, db.col_info(col).type)
1029
        try:
1030
            add_col(db, col.table, new_typed_col,
1031
                log_ignore_excs=(DuplicateException,))
1032
            break
1033
        except DuplicateException:
1034
            new_col.name = next_version(new_col.name)
1035
            # try again with next version of name
1036
1037 2997 aaronmk
    update(db, col.table, [(new_col, expr)])
1038
    if not nullable: add_not_null(db, new_col)
1039
    add_index(db, new_col)
1040
1041 3000 aaronmk
    col.table.index_cols[col.name] = new_col
1042 2997 aaronmk
1043
def ensure_not_null(db, col):
1044
    '''For params, see sql_gen.ensure_not_null()'''
1045
    expr = sql_gen.ensure_not_null(db, col)
1046
1047
    # If nullable column in a temp table, add separate column instead
1048
    if sql_gen.is_temp_col(col) and isinstance(expr, sql_gen.EnsureNotNull):
1049
        add_index_col(db, col, '::NOT NULL', expr, nullable=False)
1050 3000 aaronmk
        expr = sql_gen.index_col(col)
1051 2997 aaronmk
1052
    return expr
1053
1054 2772 aaronmk
already_indexed = object() # tells add_indexes() the pkey has already been added
1055
1056
def add_indexes(db, table, has_pkey=True):
1057
    '''Adds an index on all columns in a table.
1058
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1059
        index should be added on the first column.
1060
        * If already_indexed, the pkey is assumed to have already been added
1061
    '''
1062
    cols = table_cols(db, table)
1063
    if has_pkey:
1064
        if has_pkey is not already_indexed: add_pkey(db, table)
1065
        cols = cols[1:]
1066
    for col in cols: add_index(db, col, table)
1067
1068 2935 aaronmk
def add_col(db, table, col, **kw_args):
1069 2934 aaronmk
    assert isinstance(col, sql_gen.TypedCol)
1070 3006 aaronmk
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '
1071 2947 aaronmk
        +col.to_str(db), recover=True, cacheable=True, **kw_args)
1072 2934 aaronmk
1073 2935 aaronmk
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1074
    constraints='PRIMARY KEY')
1075
1076 2086 aaronmk
def add_row_num(db, table):
1077 2117 aaronmk
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1078
    be the primary key.'''
1079 2935 aaronmk
    add_col(db, table, row_num_typed_col, log_level=3)
1080 2086 aaronmk
1081 2936 aaronmk
def cast_temp_col(db, type_, col, errors_table=None):
1082
    '''Like cast(), but creates a new column with the cast values if the input
1083
    is a column.
1084
    @return The new column or cast value
1085
    '''
1086
    def cast_(col): return cast(db, type_, col, errors_table)
1087
1088
    try: col = sql_gen.underlying_col(col)
1089
    except sql_gen.NoUnderlyingTableException: return sql_gen.wrap(cast_, col)
1090
1091
    table = col.table
1092
    new_col = sql_gen.Col(sql_gen.concat(col.name, '::'+type_), table, col.srcs)
1093
    expr = cast_(col)
1094
    add_col(db, table, sql_gen.TypedCol(new_col.name, type_))
1095
    update(db, table, [(new_col, expr)])
1096 2955 aaronmk
    add_index(db, new_col)
1097 2936 aaronmk
1098
    return new_col
1099
1100 2889 aaronmk
def drop_table(db, table):
1101
    table = sql_gen.as_Table(table)
1102
    return run_query(db, 'DROP TABLE IF EXISTS '+table.to_str(db)+' CASCADE')
1103
1104 2760 aaronmk
def create_table(db, table, cols, has_pkey=True, col_indexes=True):
1105 2675 aaronmk
    '''Creates a table.
1106 2681 aaronmk
    @param cols [sql_gen.TypedCol,...] The column names and types
1107
    @param has_pkey If set, the first column becomes the primary key.
1108 2760 aaronmk
    @param col_indexes bool|[ref]
1109
        * If True, indexes will be added on all non-pkey columns.
1110
        * If a list reference, [0] will be set to a function to do this.
1111
          This can be used to delay index creation until the table is populated.
1112 2675 aaronmk
    '''
1113
    table = sql_gen.as_Table(table)
1114
1115 2681 aaronmk
    if has_pkey:
1116
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1117 2872 aaronmk
        pkey.constraints = 'PRIMARY KEY'
1118 2681 aaronmk
1119 2675 aaronmk
    str_ = 'CREATE TABLE '+table.to_str(db)+' (\n'
1120 2681 aaronmk
    str_ += '\n, '.join(v.to_str(db) for v in cols)
1121
    str_ += '\n);\n'
1122 2675 aaronmk
    run_query(db, str_, cacheable=True, log_level=2)
1123 2760 aaronmk
1124
    # Add indexes
1125 2773 aaronmk
    if has_pkey: has_pkey = already_indexed
1126
    def add_indexes_(): add_indexes(db, table, has_pkey)
1127
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1128
    elif col_indexes: add_indexes_() # add now
1129 2675 aaronmk
1130 2684 aaronmk
def vacuum(db, table):
1131
    table = sql_gen.as_Table(table)
1132
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1133
        log_level=3))
1134
1135 2970 aaronmk
def truncate(db, table, schema='public', **kw_args):
1136
    '''For params, see run_query()'''
1137 2777 aaronmk
    table = sql_gen.as_Table(table, schema)
1138 2970 aaronmk
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1139 2732 aaronmk
1140 2965 aaronmk
def empty_temp(db, tables):
1141 2972 aaronmk
    if db.debug_temp: return # leave temp tables there for debugging
1142 2965 aaronmk
    tables = lists.mk_seq(tables)
1143 2971 aaronmk
    for table in tables: truncate(db, table, log_level=3)
1144 2965 aaronmk
1145 2729 aaronmk
def tables(db, schema_like='public', table_like='%', exact=False):
1146
    if exact: compare = '='
1147
    else: compare = 'LIKE'
1148
1149 1849 aaronmk
    module = util.root_module(db.db)
1150 832 aaronmk
    if module == 'psycopg2':
1151 2779 aaronmk
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1152
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1153
        return values(select(db, 'pg_tables', ['tablename'], conds,
1154
            order_by='tablename', log_level=4))
1155 1968 aaronmk
    elif module == 'MySQLdb':
1156 2779 aaronmk
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1157
            , cacheable=True, log_level=4))
1158 832 aaronmk
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1159 830 aaronmk
1160 2726 aaronmk
def table_exists(db, table):
1161
    table = sql_gen.as_Table(table)
1162 2730 aaronmk
    return list(tables(db, table.schema, table.name, exact=True)) != []
1163 2726 aaronmk
1164 2913 aaronmk
def function_exists(db, function):
1165
    function = sql_gen.as_Function(function)
1166
1167
    info_table = sql_gen.Table('routines', 'information_schema')
1168
    conds = [('routine_name', function.name)]
1169
    schema = function.schema
1170
    if schema != None: conds.append(('routine_schema', schema))
1171 2914 aaronmk
    # Exclude trigger functions, since they cannot be called directly
1172
    conds.append(('data_type', sql_gen.CompareCond('trigger', '!=')))
1173 2913 aaronmk
1174
    return list(values(select(db, info_table, ['routine_name'], conds,
1175
        order_by='routine_schema', limit=1, log_level=4))) != []
1176
        # TODO: order_by search_path schema order
1177
1178 2726 aaronmk
def errors_table(db, table, if_exists=True):
1179
    '''
1180
    @param if_exists If set, returns None if the errors table doesn't exist
1181
    @return None|sql_gen.Table
1182
    '''
1183
    table = sql_gen.as_Table(table)
1184
    if table.srcs != (): table = table.srcs[0]
1185
1186
    errors_table = sql_gen.suffixed_table(table, '.errors')
1187
    if if_exists and not table_exists(db, errors_table): return None
1188
    return errors_table
1189
1190 833 aaronmk
##### Database management
1191
1192 1968 aaronmk
def empty_db(db, schema='public', **kw_args):
1193
    '''For kw_args, see tables()'''
1194
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1195 833 aaronmk
1196 832 aaronmk
##### Heuristic queries
1197
1198 2104 aaronmk
def put(db, table, row, pkey_=None, row_ct_ref=None):
1199 1554 aaronmk
    '''Recovers from errors.
1200 2077 aaronmk
    Only works under PostgreSQL (uses INSERT RETURNING).
1201
    '''
1202 2642 aaronmk
    row = sql_gen.ColDict(db, table, row)
1203 2104 aaronmk
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
1204
1205 471 aaronmk
    try:
1206 2149 aaronmk
        cur = insert(db, table, row, pkey_, recover=True)
1207 1554 aaronmk
        if row_ct_ref != None and cur.rowcount >= 0:
1208
            row_ct_ref[0] += cur.rowcount
1209
        return value(cur)
1210 471 aaronmk
    except DuplicateKeyException, e:
1211 2653 aaronmk
        row = sql_gen.ColDict(db, table,
1212
            util.dict_subset_right_join(row, e.cols))
1213
        return value(select(db, table, [pkey_], row, recover=True))
1214 471 aaronmk
1215 473 aaronmk
def get(db, table, row, pkey, row_ct_ref=None, create=False):
1216 830 aaronmk
    '''Recovers from errors'''
1217 2209 aaronmk
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
1218 14 aaronmk
    except StopIteration:
1219 40 aaronmk
        if not create: raise
1220 471 aaronmk
        return put(db, table, row, pkey, row_ct_ref) # insert new row
1221 2078 aaronmk
1222 2593 aaronmk
def is_func_result(col):
1223
    return col.table.name.find('(') >= 0 and col.name == 'result'
1224
1225 2592 aaronmk
def into_table_name(out_table, in_tables0, mapping, is_func):
1226 2615 aaronmk
    def in_col_str(in_col):
1227
        in_col = sql_gen.remove_col_rename(in_col)
1228
        if isinstance(in_col, sql_gen.Col):
1229
            table = in_col.table
1230
            if table == in_tables0:
1231
                in_col = sql_gen.to_name_only_col(in_col)
1232
            elif is_func_result(in_col): in_col = table # omit col name
1233
        return str(in_col)
1234
1235 2580 aaronmk
    str_ = str(out_table)
1236
    if is_func:
1237 2615 aaronmk
        str_ += '('
1238 2580 aaronmk
1239 2615 aaronmk
        try: value_in_col = mapping['value']
1240
        except KeyError:
1241 2654 aaronmk
            str_ += ', '.join((str(k)+'='+in_col_str(v)
1242 2615 aaronmk
                for k, v in mapping.iteritems()))
1243
        else: str_ += in_col_str(value_in_col)
1244
1245
        str_ += ')'
1246 2812 aaronmk
    else:
1247
        out_col = 'rank'
1248
        try: in_col = mapping[out_col]
1249
        except KeyError: str_ += '_pkeys'
1250
        else: # has a rank column, so hierarchical
1251
            str_ += '['+str(out_col)+'='+in_col_str(in_col)+']'
1252 2580 aaronmk
    return str_
1253
1254 2508 aaronmk
def put_table(db, out_table, in_tables, mapping, row_ct_ref=None, into=None,
1255 2805 aaronmk
    default=None, is_func=False, on_error=exc.raise_):
1256 2078 aaronmk
    '''Recovers from errors.
1257
    Only works under PostgreSQL (uses INSERT RETURNING).
1258 2909 aaronmk
    IMPORTANT: Must be run at the *beginning* of a transaction.
1259 2131 aaronmk
    @param in_tables The main input table to select from, followed by a list of
1260
        tables to join with it using the main input table's pkey
1261 2312 aaronmk
    @param mapping dict(out_table_col=in_table_col, ...)
1262 2612 aaronmk
        * out_table_col: str (*not* sql_gen.Col)
1263
        * in_table_col: sql_gen.Col|literal-value
1264 2489 aaronmk
    @param into The table to contain the output and input pkeys.
1265 2574 aaronmk
        Defaults to `out_table.name+'_pkeys'`.
1266 2509 aaronmk
    @param default The *output* column to use as the pkey for missing rows.
1267
        If this output column does not exist in the mapping, uses None.
1268 2552 aaronmk
    @param is_func Whether out_table is the name of a SQL function, not a table
1269 2312 aaronmk
    @return sql_gen.Col Where the output pkeys are made available
1270 2078 aaronmk
    '''
1271 2329 aaronmk
    out_table = sql_gen.as_Table(out_table)
1272 2312 aaronmk
1273 2450 aaronmk
    def log_debug(msg): db.log_debug(msg, level=1.5)
1274 2505 aaronmk
    def col_ustr(str_):
1275 2567 aaronmk
        return strings.repr_no_u(sql_gen.remove_col_rename(str_))
1276 2450 aaronmk
1277 2910 aaronmk
    log_debug('********** New iteration **********')
1278
    log_debug('Inserting these input columns into '+strings.as_tt(
1279
        out_table.to_str(db))+':\n'+strings.as_table(mapping, ustr=col_ustr))
1280
1281 2942 aaronmk
    is_function = function_exists(db, out_table)
1282
1283
    if is_function: out_pkey = 'result'
1284
    else: out_pkey = pkey(db, out_table, recover=True)
1285 2768 aaronmk
    out_pkey_col = sql_gen.as_Col(out_pkey, out_table)
1286
1287
    if mapping == {}: # need at least one column for INSERT SELECT
1288
        mapping = {out_pkey: None} # ColDict will replace with default value
1289
1290 2382 aaronmk
    # Create input joins from list of input tables
1291
    in_tables_ = in_tables[:] # don't modify input!
1292
    in_tables0 = in_tables_.pop(0) # first table is separate
1293 2735 aaronmk
    errors_table_ = errors_table(db, in_tables0)
1294 2279 aaronmk
    in_pkey = pkey(db, in_tables0, recover=True)
1295 2285 aaronmk
    in_pkey_col = sql_gen.as_Col(in_pkey, in_tables0)
1296 2460 aaronmk
    input_joins = [in_tables0]+[sql_gen.Join(v,
1297
        {in_pkey: sql_gen.join_same_not_null}) for v in in_tables_]
1298 2131 aaronmk
1299 2592 aaronmk
    if into == None:
1300
        into = into_table_name(out_table, in_tables0, mapping, is_func)
1301
    into = sql_gen.as_Table(into)
1302
1303 2702 aaronmk
    # Set column sources
1304
    in_cols = filter(sql_gen.is_table_col, mapping.values())
1305
    for col in in_cols:
1306
        if col.table == in_tables0: col.set_srcs(sql_gen.src_self)
1307
1308 2486 aaronmk
    log_debug('Joining together input tables into temp table')
1309 2395 aaronmk
    # Place in new table for speed and so don't modify input if values edited
1310 2584 aaronmk
    in_table = sql_gen.Table('in')
1311 2702 aaronmk
    mapping = dicts.join(mapping, flatten(db, in_table, input_joins, in_cols,
1312
        preserve=[in_pkey_col], start=0))
1313 2395 aaronmk
    input_joins = [in_table]
1314 2486 aaronmk
    db.log_debug('Temp table: '+strings.as_tt(in_table.to_str(db)), level=2)
1315 2395 aaronmk
1316 2656 aaronmk
    mapping = sql_gen.ColDict(db, out_table, mapping)
1317
        # after applying dicts.join() because that returns a plain dict
1318
1319 2509 aaronmk
    # Resolve default value column
1320 2841 aaronmk
    if default != None:
1321
        try: default = mapping[default]
1322
        except KeyError:
1323 2509 aaronmk
            db.log_debug('Default value column '
1324
                +strings.as_tt(strings.repr_no_u(default))
1325 2511 aaronmk
                +' does not exist in mapping, falling back to None', level=2.1)
1326 2509 aaronmk
            default = None
1327
1328 2387 aaronmk
    pkeys_names = [in_pkey, out_pkey]
1329 2236 aaronmk
    pkeys_cols = [in_pkey_col, out_pkey_col]
1330
1331 2201 aaronmk
    pkeys_table_exists_ref = [False]
1332 2960 aaronmk
    def insert_into_pkeys(joins, cols, distinct=False):
1333
        kw_args = {}
1334
        if distinct: kw_args.update(dict(distinct_on=[in_pkey_col]))
1335
        query = mk_select(db, joins, cols, order_by=None, start=0, **kw_args)
1336
1337 2201 aaronmk
        if pkeys_table_exists_ref[0]:
1338 2786 aaronmk
            insert_select(db, into, pkeys_names, query)
1339 2201 aaronmk
        else:
1340 2786 aaronmk
            run_query_into(db, query, into=into)
1341 2201 aaronmk
            pkeys_table_exists_ref[0] = True
1342
1343 2429 aaronmk
    limit_ref = [None]
1344 2380 aaronmk
    conds = set()
1345 2811 aaronmk
    distinct_on = sql_gen.ColDict(db, out_table)
1346 2325 aaronmk
    def mk_main_select(joins, cols):
1347 2811 aaronmk
        distinct_on_cols = [c.to_Col() for c in distinct_on.values()]
1348
        return mk_select(db, joins, cols, conds, distinct_on_cols,
1349 2429 aaronmk
            limit=limit_ref[0], start=0)
1350 2132 aaronmk
1351 2519 aaronmk
    exc_strs = set()
1352 2309 aaronmk
    def log_exc(e):
1353 2519 aaronmk
        e_str = exc.str_(e, first_line_only=True)
1354
        log_debug('Caught exception: '+e_str)
1355
        assert e_str not in exc_strs # avoid infinite loops
1356
        exc_strs.add(e_str)
1357 2735 aaronmk
1358 2451 aaronmk
    def remove_all_rows():
1359 2896 aaronmk
        log_debug('Ignoring all rows')
1360 2429 aaronmk
        limit_ref[0] = 0 # just create an empty pkeys table
1361 2735 aaronmk
1362 2758 aaronmk
    def ignore(in_col, value, e):
1363
        track_data_error(db, errors_table_, in_col.srcs, value, e.cause.pgcode,
1364
            e.cause.pgerror)
1365 2895 aaronmk
        log_debug('Ignoring rows with '+strings.as_tt(repr(in_col))+' = '
1366 2545 aaronmk
            +strings.as_tt(repr(value)))
1367 2895 aaronmk
1368 2758 aaronmk
    def remove_rows(in_col, value, e):
1369
        ignore(in_col, value, e)
1370 2378 aaronmk
        cond = (in_col, sql_gen.CompareCond(value, '!='))
1371
        assert cond not in conds # avoid infinite loops
1372 2380 aaronmk
        conds.add(cond)
1373 2895 aaronmk
1374 2758 aaronmk
    def invalid2null(in_col, value, e):
1375
        ignore(in_col, value, e)
1376 2403 aaronmk
        update(db, in_table, [(in_col, None)],
1377
            sql_gen.ColValueCond(in_col, value))
1378 2245 aaronmk
1379 2589 aaronmk
    def insert_pkeys_table(which):
1380 2932 aaronmk
        return sql_gen.Table(sql_gen.concat(in_table.name,
1381 2589 aaronmk
            '_insert_'+which+'_pkeys'))
1382
    insert_out_pkeys = insert_pkeys_table('out')
1383
    insert_in_pkeys = insert_pkeys_table('in')
1384
1385 2206 aaronmk
    # Do inserts and selects
1386 2642 aaronmk
    join_cols = sql_gen.ColDict(db, out_table)
1387 2206 aaronmk
    while True:
1388 2521 aaronmk
        if limit_ref[0] == 0: # special case
1389
            log_debug('Creating an empty pkeys table')
1390 2786 aaronmk
            cur = run_query_into(db, mk_select(db, out_table, [out_pkey],
1391 2521 aaronmk
                limit=limit_ref[0]), into=insert_out_pkeys)
1392
            break # don't do main case
1393
1394 2303 aaronmk
        has_joins = join_cols != {}
1395
1396 2903 aaronmk
        log_debug('Trying to insert new rows')
1397
1398 2305 aaronmk
        # Prepare to insert new rows
1399 2325 aaronmk
        insert_joins = input_joins[:] # don't modify original!
1400 2403 aaronmk
        insert_args = dict(recover=True, cacheable=False)
1401 2303 aaronmk
        if has_joins:
1402 2325 aaronmk
            insert_joins.append(sql_gen.Join(out_table, join_cols,
1403
                sql_gen.filter_out))
1404
        else:
1405 2404 aaronmk
            insert_args.update(dict(returning=out_pkey, into=insert_out_pkeys))
1406 2786 aaronmk
        main_select = mk_main_select(insert_joins, mapping.values())
1407 2303 aaronmk
1408 2929 aaronmk
        def main_insert():
1409 2942 aaronmk
            if is_function:
1410
                log_debug('Calling function on input rows')
1411
                args = dict(((k.name, v) for k, v in mapping.iteritems()))
1412
                func_call = sql_gen.NamedCol(out_pkey,
1413
                    sql_gen.FunctionCall(out_table, **args))
1414
                insert_into_pkeys(input_joins, [in_pkey_col, func_call])
1415
                return None
1416
            else:
1417
                lock_table(db, out_table, 'EXCLUSIVE')
1418
                return insert_select(db, out_table, mapping.keys(), main_select,
1419
                    **insert_args)
1420 2929 aaronmk
1421 2206 aaronmk
        try:
1422 2929 aaronmk
            cur = with_savepoint(db, main_insert)
1423 2357 aaronmk
            break # insert successful
1424 2931 aaronmk
        except MissingCastException, e:
1425
            log_exc(e)
1426
1427
            out_col = e.col
1428
            type_ = e.type
1429
1430
            log_debug('Casting '+strings.as_tt(out_col)+' input to '
1431
                +strings.as_tt(type_))
1432 2937 aaronmk
            mapping[out_col] = cast_temp_col(db, type_, mapping[out_col],
1433
                errors_table_)
1434 2206 aaronmk
        except DuplicateKeyException, e:
1435 2309 aaronmk
            log_exc(e)
1436
1437 2258 aaronmk
            old_join_cols = join_cols.copy()
1438 2811 aaronmk
            distinct_on.update(util.dict_subset(mapping, e.cols))
1439 2565 aaronmk
            join_cols.update(util.dict_subset_right_join(mapping, e.cols))
1440 2486 aaronmk
            log_debug('Ignoring existing rows, comparing on these columns:\n'
1441 2505 aaronmk
                +strings.as_inline_table(join_cols, ustr=col_ustr))
1442 2258 aaronmk
            assert join_cols != old_join_cols # avoid infinite loops
1443 2230 aaronmk
        except NullValueException, e:
1444 2309 aaronmk
            log_exc(e)
1445
1446 2230 aaronmk
            out_col, = e.cols
1447
            try: in_col = mapping[out_col]
1448 2356 aaronmk
            except KeyError:
1449 2486 aaronmk
                log_debug('Missing mapping for NOT NULL column '+out_col)
1450 2451 aaronmk
                remove_all_rows()
1451 2758 aaronmk
            else: remove_rows(in_col, None, e)
1452 2542 aaronmk
        except FunctionValueException, e:
1453
            log_exc(e)
1454
1455
            func_name = e.name
1456
            value = e.value
1457
            for out_col, in_col in mapping.iteritems():
1458 2758 aaronmk
                in_col = sql_gen.unwrap_func_call(in_col, func_name)
1459
                invalid2null(in_col, value, e)
1460 2429 aaronmk
        except DatabaseErrors, e:
1461
            log_exc(e)
1462
1463 2808 aaronmk
            log_debug('No handler for exception')
1464
            on_error(e)
1465 2451 aaronmk
            remove_all_rows()
1466 2358 aaronmk
        # after exception handled, rerun loop with additional constraints
1467 2132 aaronmk
1468 2942 aaronmk
    if cur != None and row_ct_ref != None and cur.rowcount >= 0:
1469 2357 aaronmk
        row_ct_ref[0] += cur.rowcount
1470
1471 2942 aaronmk
    if is_function: pass # pkeys table already created
1472
    elif has_joins:
1473 2357 aaronmk
        select_joins = input_joins+[sql_gen.Join(out_table, join_cols)]
1474 2486 aaronmk
        log_debug('Getting output table pkeys of existing/inserted rows')
1475 2960 aaronmk
        insert_into_pkeys(select_joins, pkeys_cols, distinct=True)
1476 2357 aaronmk
    else:
1477 2404 aaronmk
        add_row_num(db, insert_out_pkeys) # for joining with input pkeys
1478 2357 aaronmk
1479 2486 aaronmk
        log_debug('Getting input table pkeys of inserted rows')
1480 2786 aaronmk
        run_query_into(db, mk_main_select(input_joins, [in_pkey]),
1481 2404 aaronmk
            into=insert_in_pkeys)
1482
        add_row_num(db, insert_in_pkeys) # for joining with output pkeys
1483 2357 aaronmk
1484 2428 aaronmk
        assert table_row_count(db, insert_out_pkeys) == table_row_count(db,
1485
            insert_in_pkeys)
1486
1487 2486 aaronmk
        log_debug('Combining output and input pkeys in inserted order')
1488 2404 aaronmk
        pkey_joins = [insert_in_pkeys, sql_gen.Join(insert_out_pkeys,
1489 2357 aaronmk
            {row_num_col: sql_gen.join_same_not_null})]
1490 2420 aaronmk
        insert_into_pkeys(pkey_joins, pkeys_names)
1491 2959 aaronmk
1492 2974 aaronmk
        empty_temp(db, [insert_out_pkeys, insert_in_pkeys])
1493 2357 aaronmk
1494 2486 aaronmk
    db.log_debug('Adding pkey on pkeys table to enable fast joins', level=2.5)
1495 2594 aaronmk
    add_pkey(db, into)
1496 2407 aaronmk
1497 2508 aaronmk
    log_debug('Setting pkeys of missing rows to '+strings.as_tt(repr(default)))
1498 2489 aaronmk
    missing_rows_joins = input_joins+[sql_gen.Join(into,
1499 2357 aaronmk
        {in_pkey: sql_gen.join_same_not_null}, sql_gen.filter_out)]
1500
        # must use join_same_not_null or query will take forever
1501 2420 aaronmk
    insert_into_pkeys(missing_rows_joins,
1502 2508 aaronmk
        [in_pkey_col, sql_gen.NamedCol(out_pkey, default)])
1503 2357 aaronmk
1504 2489 aaronmk
    assert table_row_count(db, into) == table_row_count(db, in_table)
1505 2428 aaronmk
1506 2974 aaronmk
    empty_temp(db, in_table)
1507 2959 aaronmk
1508 2702 aaronmk
    srcs = []
1509
    if is_func: srcs = sql_gen.cols_srcs(in_cols)
1510
    return sql_gen.Col(out_pkey, into, srcs)
1511 2115 aaronmk
1512
##### Data cleanup
1513
1514 2290 aaronmk
def cleanup_table(db, table, cols):
1515 2677 aaronmk
    table = sql_gen.as_Table(table)
1516
    cols = map(sql_gen.as_Col, cols)
1517 2115 aaronmk
1518 2677 aaronmk
    expr = ('nullif(nullif(trim(both from %s), '+db.esc_value('')+'), '
1519
        +db.esc_value(r'\N')+')')
1520
    changes = [(v, sql_gen.CustomCode(expr % v.to_str(db)))
1521
        for v in cols]
1522 2115 aaronmk
1523 2677 aaronmk
    update(db, table, changes)