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
    else: return repr(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
    exc.add_msg(e, 'query: '+str(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 2145 aaronmk
        DbException.__init__(self, 'for name: '+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
        DbException.__init__(self,
45 2247 aaronmk
            'for name: '+str(name)+'; value: '+strings.ustr(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 2307 aaronmk
        DbException.__init__(self, 'Violated constraint '+name+ ' on columns: '
52
            +(', '.join(cols)), cause)
53 2306 aaronmk
        self.name = name
54 468 aaronmk
        self.cols = cols
55 11 aaronmk
56 2143 aaronmk
class NameException(DbException): pass
57
58 2306 aaronmk
class DuplicateKeyException(ConstraintException): pass
59 13 aaronmk
60 2306 aaronmk
class NullValueException(ConstraintException): pass
61 13 aaronmk
62 2240 aaronmk
class FunctionValueException(ExceptionWithNameValue): pass
63 2239 aaronmk
64 2143 aaronmk
class DuplicateTableException(ExceptionWithName): pass
65
66 2188 aaronmk
class DuplicateFunctionException(ExceptionWithName): pass
67
68 89 aaronmk
class EmptyRowException(DbException): pass
69
70 865 aaronmk
##### Warnings
71
72
class DbWarning(UserWarning): pass
73
74 1930 aaronmk
##### Result retrieval
75
76
def col_names(cur): return (col[0] for col in cur.description)
77
78
def rows(cur): return iter(lambda: cur.fetchone(), None)
79
80
def consume_rows(cur):
81
    '''Used to fetch all rows so result will be cached'''
82
    iters.consume_iter(rows(cur))
83
84
def next_row(cur): return rows(cur).next()
85
86
def row(cur):
87
    row_ = next_row(cur)
88
    consume_rows(cur)
89
    return row_
90
91
def next_value(cur): return next_row(cur)[0]
92
93
def value(cur): return row(cur)[0]
94
95
def values(cur): return iters.func_iter(lambda: next_value(cur))
96
97
def value_or_none(cur):
98
    try: return value(cur)
99
    except StopIteration: return None
100
101 2101 aaronmk
##### Input validation
102
103 2198 aaronmk
def clean_name(name): return re.sub(r'\W', r'', name).lower()
104 2101 aaronmk
105
def check_name(name):
106
    if re.search(r'\W', name) != None: raise NameException('Name "'+name
107
        +'" may contain only alphanumeric characters and _')
108
109
def esc_name_by_module(module, name, ignore_case=False):
110
    if module == 'psycopg2':
111
        if ignore_case:
112
            # Don't enclose in quotes because this disables case-insensitivity
113
            check_name(name)
114
            return name
115
        else: quote = '"'
116
    elif module == 'MySQLdb': quote = '`'
117
    else: raise NotImplementedError("Can't escape name for "+module+' database')
118
    return quote + name.replace(quote, '') + quote
119
120
def esc_name_by_engine(engine, name, **kw_args):
121
    return esc_name_by_module(db_engines[engine][0], name, **kw_args)
122
123
def esc_name(db, name, **kw_args):
124
    return esc_name_by_module(util.root_module(db.db), name, **kw_args)
125
126
def qual_name(db, schema, table):
127
    def esc_name_(name): return esc_name(db, name)
128
    table = esc_name_(table)
129
    if schema != None: return esc_name_(schema)+'.'+table
130
    else: return table
131
132 1869 aaronmk
##### Database connections
133 1849 aaronmk
134 2097 aaronmk
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
135 1926 aaronmk
136 1869 aaronmk
db_engines = {
137
    'MySQL': ('MySQLdb', {'password': 'passwd', 'database': 'db'}),
138
    'PostgreSQL': ('psycopg2', {}),
139
}
140
141
DatabaseErrors_set = set([DbException])
142
DatabaseErrors = tuple(DatabaseErrors_set)
143
144
def _add_module(module):
145
    DatabaseErrors_set.add(module.DatabaseError)
146
    global DatabaseErrors
147
    DatabaseErrors = tuple(DatabaseErrors_set)
148
149
def db_config_str(db_config):
150
    return db_config['engine']+' database '+db_config['database']
151
152 1909 aaronmk
def _query_lookup(query, params): return (query, dicts.make_hashable(params))
153 1894 aaronmk
154 1901 aaronmk
log_debug_none = lambda msg: None
155
156 1849 aaronmk
class DbConn:
157 2190 aaronmk
    def __init__(self, db_config, serializable=True, autocommit=False,
158
        caching=True, log_debug=log_debug_none):
159 1869 aaronmk
        self.db_config = db_config
160
        self.serializable = serializable
161 2190 aaronmk
        self.autocommit = autocommit
162
        self.caching = caching
163 1901 aaronmk
        self.log_debug = log_debug
164 2193 aaronmk
        self.debug = log_debug != log_debug_none
165 1869 aaronmk
166
        self.__db = None
167 1889 aaronmk
        self.query_results = {}
168 2139 aaronmk
        self._savepoint = 0
169 1869 aaronmk
170
    def __getattr__(self, name):
171
        if name == '__dict__': raise Exception('getting __dict__')
172
        if name == 'db': return self._db()
173
        else: raise AttributeError()
174
175
    def __getstate__(self):
176
        state = copy.copy(self.__dict__) # shallow copy
177 1915 aaronmk
        state['log_debug'] = None # don't pickle the debug callback
178 1869 aaronmk
        state['_DbConn__db'] = None # don't pickle the connection
179
        return state
180
181 2165 aaronmk
    def connected(self): return self.__db != None
182
183 1869 aaronmk
    def _db(self):
184
        if self.__db == None:
185
            # Process db_config
186
            db_config = self.db_config.copy() # don't modify input!
187 2097 aaronmk
            schemas = db_config.pop('schemas', None)
188 1869 aaronmk
            module_name, mappings = db_engines[db_config.pop('engine')]
189
            module = __import__(module_name)
190
            _add_module(module)
191
            for orig, new in mappings.iteritems():
192
                try: util.rename_key(db_config, orig, new)
193
                except KeyError: pass
194
195
            # Connect
196
            self.__db = module.connect(**db_config)
197
198
            # Configure connection
199 2234 aaronmk
            if self.serializable and not self.autocommit: run_raw_query(self,
200
                'SET TRANSACTION ISOLATION LEVEL SERIALIZABLE')
201 2101 aaronmk
            if schemas != None:
202
                schemas_ = ''.join((esc_name(self, s)+', '
203
                    for s in schemas.split(',')))
204
                run_raw_query(self, "SELECT set_config('search_path', \
205
%s || current_setting('search_path'), false)", [schemas_])
206 1869 aaronmk
207
        return self.__db
208 1889 aaronmk
209 1891 aaronmk
    class DbCursor(Proxy):
210 1927 aaronmk
        def __init__(self, outer):
211 1891 aaronmk
            Proxy.__init__(self, outer.db.cursor())
212 2191 aaronmk
            self.outer = outer
213 1927 aaronmk
            self.query_results = outer.query_results
214 1894 aaronmk
            self.query_lookup = None
215 1891 aaronmk
            self.result = []
216 1889 aaronmk
217 1894 aaronmk
        def execute(self, query, params=None):
218 1930 aaronmk
            self._is_insert = query.upper().find('INSERT') >= 0
219 1894 aaronmk
            self.query_lookup = _query_lookup(query, params)
220 2148 aaronmk
            try:
221 2191 aaronmk
                try:
222
                    return_value = self.inner.execute(query, params)
223
                    self.outer.do_autocommit()
224 2148 aaronmk
                finally: self.query = get_cur_query(self.inner)
225 1904 aaronmk
            except Exception, e:
226 2170 aaronmk
                _add_cursor_info(e, self, query, params)
227 1904 aaronmk
                self.result = e # cache the exception as the result
228
                self._cache_result()
229
                raise
230 1930 aaronmk
            # Fetch all rows so result will be cached
231
            if self.rowcount == 0 and not self._is_insert: consume_rows(self)
232 1894 aaronmk
            return return_value
233
234 1891 aaronmk
        def fetchone(self):
235
            row = self.inner.fetchone()
236 1899 aaronmk
            if row != None: self.result.append(row)
237
            # otherwise, fetched all rows
238 1904 aaronmk
            else: self._cache_result()
239
            return row
240
241
        def _cache_result(self):
242 1906 aaronmk
            # For inserts, only cache exceptions since inserts are not
243
            # idempotent, but an invalid insert will always be invalid
244 1930 aaronmk
            if self.query_results != None and (not self._is_insert
245 1906 aaronmk
                or isinstance(self.result, Exception)):
246
247 1894 aaronmk
                assert self.query_lookup != None
248 1916 aaronmk
                self.query_results[self.query_lookup] = self.CacheCursor(
249
                    util.dict_subset(dicts.AttrsDictView(self),
250
                    ['query', 'result', 'rowcount', 'description']))
251 1906 aaronmk
252 1916 aaronmk
        class CacheCursor:
253
            def __init__(self, cached_result): self.__dict__ = cached_result
254
255 1927 aaronmk
            def execute(self, *args, **kw_args):
256 1916 aaronmk
                if isinstance(self.result, Exception): raise self.result
257
                # otherwise, result is a rows list
258
                self.iter = iter(self.result)
259
260
            def fetchone(self):
261
                try: return self.iter.next()
262
                except StopIteration: return None
263 1891 aaronmk
264 2212 aaronmk
    def esc_value(self, value):
265 2215 aaronmk
        module = util.root_module(self.db)
266
        if module == 'psycopg2': return self.db.cursor().mogrify('%s', [value])
267 2212 aaronmk
        elif module == 'MySQLdb':
268
            import _mysql
269
            return _mysql.escape_string(value)
270
        else: raise NotImplementedError("Can't escape value for "+module
271
            +' database')
272
273 1894 aaronmk
    def run_query(self, query, params=None, cacheable=False):
274 2148 aaronmk
        '''Translates known DB errors to typed exceptions:
275
        See self.DbCursor.execute().'''
276 2167 aaronmk
        assert query != None
277
278 2047 aaronmk
        if not self.caching: cacheable = False
279 1903 aaronmk
        used_cache = False
280
        try:
281 1927 aaronmk
            # Get cursor
282
            if cacheable:
283
                query_lookup = _query_lookup(query, params)
284
                try:
285
                    cur = self.query_results[query_lookup]
286
                    used_cache = True
287
                except KeyError: cur = self.DbCursor(self)
288
            else: cur = self.db.cursor()
289
290
            # Run query
291 2148 aaronmk
            cur.execute(query, params)
292 1903 aaronmk
        finally:
293 2193 aaronmk
            if self.debug: # only compute msg if needed
294 1903 aaronmk
                if used_cache: cache_status = 'Cache hit'
295
                elif cacheable: cache_status = 'Cache miss'
296
                else: cache_status = 'Non-cacheable'
297 1927 aaronmk
                self.log_debug(cache_status+': '
298 2170 aaronmk
                    +strings.one_line(str(get_cur_query(cur, query, params))))
299 1903 aaronmk
300
        return cur
301 1914 aaronmk
302
    def is_cached(self, query, params=None):
303
        return _query_lookup(query, params) in self.query_results
304 2139 aaronmk
305
    def with_savepoint(self, func):
306 2171 aaronmk
        savepoint = 'level_'+str(self._savepoint)
307 2139 aaronmk
        self.run_query('SAVEPOINT '+savepoint)
308
        self._savepoint += 1
309
        try:
310
            try: return_val = func()
311
            finally:
312
                self._savepoint -= 1
313
                assert self._savepoint >= 0
314
        except:
315
            self.run_query('ROLLBACK TO SAVEPOINT '+savepoint)
316
            raise
317
        else:
318
            self.run_query('RELEASE SAVEPOINT '+savepoint)
319 2191 aaronmk
            self.do_autocommit()
320 2139 aaronmk
            return return_val
321 2191 aaronmk
322
    def do_autocommit(self):
323
        '''Autocommits if outside savepoint'''
324
        assert self._savepoint >= 0
325
        if self.autocommit and self._savepoint == 0:
326
            self.log_debug('Autocommiting')
327
            self.db.commit()
328 1849 aaronmk
329 1869 aaronmk
connect = DbConn
330
331 832 aaronmk
##### Querying
332
333 1894 aaronmk
def run_raw_query(db, *args, **kw_args):
334 2085 aaronmk
    '''For params, see DbConn.run_query()'''
335 1894 aaronmk
    return db.run_query(*args, **kw_args)
336 11 aaronmk
337 2068 aaronmk
def mogrify(db, query, params):
338
    module = util.root_module(db.db)
339
    if module == 'psycopg2': return db.db.cursor().mogrify(query, params)
340
    else: raise NotImplementedError("Can't mogrify query for "+module+
341
        ' database')
342
343 832 aaronmk
##### Recoverable querying
344 15 aaronmk
345 2139 aaronmk
def with_savepoint(db, func): return db.with_savepoint(func)
346 11 aaronmk
347 1894 aaronmk
def run_query(db, query, params=None, recover=None, cacheable=False):
348 830 aaronmk
    if recover == None: recover = False
349
350 2148 aaronmk
    try:
351
        def run(): return run_raw_query(db, query, params, cacheable)
352
        if recover and not db.is_cached(query, params):
353
            return with_savepoint(db, run)
354
        else: return run() # don't need savepoint if cached
355
    except Exception, e:
356
        if not recover: raise # need savepoint to run index_cols()
357 2247 aaronmk
        msg = exc.str_(e)
358 2240 aaronmk
359 2148 aaronmk
        match = re.search(r'duplicate key value violates unique constraint '
360
            r'"((_?[^\W_]+)_[^"]+)"', msg)
361
        if match:
362
            constraint, table = match.groups()
363
            try: cols = index_cols(db, table, constraint)
364
            except NotImplementedError: raise e
365 2306 aaronmk
            else: raise DuplicateKeyException(constraint, cols, e)
366 2240 aaronmk
367 2148 aaronmk
        match = re.search(r'null value in column "(\w+)" violates not-null '
368 2239 aaronmk
            r'constraint', msg)
369 2306 aaronmk
        if match: raise NullValueException('', [match.group(1)], e)
370 2240 aaronmk
371 2247 aaronmk
        match = re.search(r'invalid input (?:syntax|value)\b.*: "(.+)"\n'
372 2242 aaronmk
            r'(?:(?s).*)\bfunction "(\w+)".*\bat assignment', msg)
373 2240 aaronmk
        if match:
374 2247 aaronmk
            raise FunctionValueException(match.group(2),
375
                strings.to_unicode(match.group(1)), e)
376 2240 aaronmk
377 2148 aaronmk
        match = re.search(r'relation "(\w+)" already exists', msg)
378
        if match: raise DuplicateTableException(match.group(1), e)
379 2240 aaronmk
380 2188 aaronmk
        match = re.search(r'function "(\w+)" already exists', msg)
381
        if match: raise DuplicateFunctionException(match.group(1), e)
382 2240 aaronmk
383 2148 aaronmk
        raise # no specific exception raised
384 830 aaronmk
385 832 aaronmk
##### Basic queries
386
387 2153 aaronmk
def next_version(name):
388
    '''Prepends the version # so it won't be removed if the name is truncated'''
389 2163 aaronmk
    version = 1 # first existing name was version 0
390 2153 aaronmk
    match = re.match(r'^v(\d+)_(.*)$', name)
391
    if match:
392
        version = int(match.group(1))+1
393
        name = match.group(2)
394
    return 'v'+str(version)+'_'+name
395
396 2151 aaronmk
def run_query_into(db, query, params, into_ref=None, *args, **kw_args):
397 2085 aaronmk
    '''Outputs a query to a temp table.
398
    For params, see run_query().
399
    '''
400 2151 aaronmk
    if into_ref == None: return run_query(db, query, params, *args, **kw_args)
401 2085 aaronmk
    else: # place rows in temp table
402 2151 aaronmk
        check_name(into_ref[0])
403 2153 aaronmk
        kw_args['recover'] = True
404
        while True:
405
            try:
406 2194 aaronmk
                create_query = 'CREATE'
407
                if not db.debug: create_query += ' TEMP'
408
                create_query += ' TABLE '+into_ref[0]+' AS '+query
409
410
                return run_query(db, create_query, params, *args, **kw_args)
411 2153 aaronmk
                    # CREATE TABLE AS sets rowcount to # rows in query
412
            except DuplicateTableException, e:
413
                into_ref[0] = next_version(into_ref[0])
414
                # try again with next version of name
415 2085 aaronmk
416 2120 aaronmk
order_by_pkey = object() # tells mk_select() to order by the pkey
417
418 2199 aaronmk
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
419
420 2233 aaronmk
def mk_select(db, tables, fields=None, conds=None, distinct_on=[], limit=None,
421 2293 aaronmk
    start=None, order_by=order_by_pkey, default_table=None):
422 1981 aaronmk
    '''
423 2121 aaronmk
    @param tables The single table to select from, or a list of tables to join
424 2280 aaronmk
        together, with tables after the first being sql_gen.Join objects
425 1981 aaronmk
    @param fields Use None to select all fields in the table
426 2218 aaronmk
    @param conds WHERE conditions: dict(compare_left_side=compare_right_side):
427
        * compare_left_side: Code|str (for col name)
428
        * compare_right_side: ValueCond|literal value
429 2199 aaronmk
    @param distinct_on The columns to SELECT DISTINCT ON, or distinct_on_all to
430
        use all columns
431 2054 aaronmk
    @return tuple(query, params)
432 1981 aaronmk
    '''
433 2121 aaronmk
    if not lists.is_seq(tables): tables = [tables]
434 2141 aaronmk
    tables = list(tables) # don't modify input! (list() copies input)
435 2121 aaronmk
    table0 = tables.pop(0) # first table is separate
436
437 1135 aaronmk
    if conds == None: conds = {}
438 135 aaronmk
    assert limit == None or type(limit) == int
439 865 aaronmk
    assert start == None or type(start) == int
440 2293 aaronmk
    table0 = sql_gen.as_Table(table0)
441 2291 aaronmk
    if order_by is order_by_pkey: order_by = pkey(db, table0, recover=True)
442 865 aaronmk
443 2056 aaronmk
    params = []
444
445 2227 aaronmk
    def parse_col(field):
446 2056 aaronmk
        '''Parses fields'''
447 2286 aaronmk
        return sql_gen.as_Col(field, default_table).to_str(db)
448 2056 aaronmk
449 2200 aaronmk
    query = 'SELECT'
450
451
    # DISTINCT ON columns
452 2233 aaronmk
    if distinct_on != []:
453 2200 aaronmk
        query += ' DISTINCT'
454 2254 aaronmk
        if distinct_on is not distinct_on_all:
455 2200 aaronmk
            query += ' ON ('+(', '.join(map(parse_col, distinct_on)))+')'
456
457
    # Columns
458
    query += ' '
459 1135 aaronmk
    if fields == None: query += '*'
460 2056 aaronmk
    else: query += ', '.join(map(parse_col, fields))
461 2200 aaronmk
462
    # Main table
463 2271 aaronmk
    query += ' FROM '+table0.to_str(db)
464 865 aaronmk
465 2122 aaronmk
    # Add joins
466 2271 aaronmk
    left_table = table0
467 2263 aaronmk
    for join_ in tables:
468 2277 aaronmk
        # Parse special values
469 2263 aaronmk
        table = join_.table
470 2267 aaronmk
        if join_.type_ is sql_gen.filter_out:
471 2277 aaronmk
            conds[sql_gen.Col(pkey(db, table), table)] = None # filter no match
472 2238 aaronmk
473 2277 aaronmk
        query += ' '+join_.to_str(db, left_table)
474 2122 aaronmk
475
        left_table = table
476
477 865 aaronmk
    missing = True
478 89 aaronmk
    if conds != {}:
479 2284 aaronmk
        query += ' WHERE '+(' AND '.join((sql_gen.as_ValueCond(r).to_str(db, l)
480
            for l, r in conds.iteritems())))
481 2056 aaronmk
        params += conds.values()
482 865 aaronmk
        missing = False
483 2227 aaronmk
    if order_by != None:
484 2285 aaronmk
        query += ' ORDER BY '+sql_gen.as_Col(order_by, table0).to_str(db)
485 865 aaronmk
    if limit != None: query += ' LIMIT '+str(limit); missing = False
486
    if start != None:
487
        if start != 0: query += ' OFFSET '+str(start)
488
        missing = False
489
    if missing: warnings.warn(DbWarning(
490
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
491
492 2056 aaronmk
    return (query, params)
493 11 aaronmk
494 2054 aaronmk
def select(db, *args, **kw_args):
495
    '''For params, see mk_select() and run_query()'''
496
    recover = kw_args.pop('recover', None)
497
    cacheable = kw_args.pop('cacheable', True)
498
499
    query, params = mk_select(db, *args, **kw_args)
500
    return run_query(db, query, params, recover, cacheable)
501
502 2066 aaronmk
def mk_insert_select(db, table, cols=None, select_query=None, params=None,
503 2292 aaronmk
    returning=None, embeddable=False):
504 1960 aaronmk
    '''
505
    @param returning str|None An inserted column (such as pkey) to return
506 2070 aaronmk
    @param embeddable Whether the query should be embeddable as a nested SELECT.
507 2073 aaronmk
        Warning: If you set this and cacheable=True when the query is run, the
508
        query will be fully cached, not just if it raises an exception.
509 1960 aaronmk
    '''
510 2063 aaronmk
    if select_query == None: select_query = 'DEFAULT VALUES'
511
    if cols == []: cols = None # no cols (all defaults) = unknown col names
512 2292 aaronmk
    table = sql_gen.as_Table(table).to_str(db)
513 2063 aaronmk
514
    # Build query
515
    query = 'INSERT INTO '+table
516
    if cols != None:
517
        map(check_name, cols)
518
        query += ' ('+', '.join(cols)+')'
519
    query += ' '+select_query
520
521
    if returning != None:
522
        check_name(returning)
523
        query += ' RETURNING '+returning
524
525 2070 aaronmk
    if embeddable:
526
        # Create function
527 2189 aaronmk
        function_name = '_'.join(map(clean_name, ['insert', table] + cols))
528 2070 aaronmk
        return_type = 'SETOF '+table+'.'+returning+'%TYPE'
529 2189 aaronmk
        while True:
530
            try:
531 2194 aaronmk
                function = function_name
532
                if not db.debug: function = 'pg_temp.'+function
533
534 2189 aaronmk
                function_query = '''\
535
CREATE FUNCTION '''+function+'''() RETURNS '''+return_type+'''
536 2070 aaronmk
    LANGUAGE sql
537
    AS $$'''+mogrify(db, query, params)+''';$$;
538
'''
539 2189 aaronmk
                run_query(db, function_query, recover=True, cacheable=True)
540
                break # this version was successful
541
            except DuplicateFunctionException, e:
542
                function_name = next_version(function_name)
543
                # try again with next version of name
544 2070 aaronmk
545
        # Return query that uses function
546 2271 aaronmk
        return mk_select(db, sql_gen.CustomCode(function+'() AS f ('+returning
547
            +')'), start=0, order_by=None) # AS clause requires function alias
548 2070 aaronmk
549 2066 aaronmk
    return (query, params)
550
551
def insert_select(db, *args, **kw_args):
552 2085 aaronmk
    '''For params, see mk_insert_select() and run_query_into()
553 2152 aaronmk
    @param into_ref List with name of temp table to place RETURNING values in
554 2072 aaronmk
    '''
555 2151 aaronmk
    into_ref = kw_args.pop('into_ref', None)
556
    if into_ref != None: kw_args['embeddable'] = True
557 2066 aaronmk
    recover = kw_args.pop('recover', None)
558
    cacheable = kw_args.pop('cacheable', True)
559
560
    query, params = mk_insert_select(db, *args, **kw_args)
561 2153 aaronmk
    return run_query_into(db, query, params, into_ref, recover=recover,
562
        cacheable=cacheable)
563 2063 aaronmk
564 2066 aaronmk
default = object() # tells insert() to use the default value for a column
565
566 2063 aaronmk
def insert(db, table, row, *args, **kw_args):
567 2085 aaronmk
    '''For params, see insert_select()'''
568 1960 aaronmk
    if lists.is_seq(row): cols = None
569
    else:
570
        cols = row.keys()
571
        row = row.values()
572
    row = list(row) # ensure that "!= []" works
573
574 1961 aaronmk
    # Check for special values
575
    labels = []
576
    values = []
577
    for value in row:
578 2254 aaronmk
        if value is default: labels.append('DEFAULT')
579 1961 aaronmk
        else:
580
            labels.append('%s')
581
            values.append(value)
582
583
    # Build query
584 2063 aaronmk
    if values != []: query = ' VALUES ('+(', '.join(labels))+')'
585
    else: query = None
586 1554 aaronmk
587 2064 aaronmk
    return insert_select(db, table, cols, query, values, *args, **kw_args)
588 11 aaronmk
589 135 aaronmk
def last_insert_id(db):
590 1849 aaronmk
    module = util.root_module(db.db)
591 135 aaronmk
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
592
    elif module == 'MySQLdb': return db.insert_id()
593
    else: return None
594 13 aaronmk
595 1968 aaronmk
def truncate(db, table, schema='public'):
596
    return run_query(db, 'TRUNCATE '+qual_name(db, schema, table)+' CASCADE')
597 832 aaronmk
598
##### Database structure queries
599
600 2291 aaronmk
def pkey(db, table, recover=None):
601 832 aaronmk
    '''Assumed to be first column in table'''
602 2291 aaronmk
    return col_names(select(db, table, limit=0, order_by=None,
603
        recover=recover)).next()
604 832 aaronmk
605 853 aaronmk
def index_cols(db, table, index):
606
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
607
    automatically created. When you don't know whether something is a UNIQUE
608
    constraint or a UNIQUE index, use this function.'''
609
    check_name(table)
610
    check_name(index)
611 1909 aaronmk
    module = util.root_module(db.db)
612
    if module == 'psycopg2':
613
        return list(values(run_query(db, '''\
614 853 aaronmk
SELECT attname
615 866 aaronmk
FROM
616
(
617
        SELECT attnum, attname
618
        FROM pg_index
619
        JOIN pg_class index ON index.oid = indexrelid
620
        JOIN pg_class table_ ON table_.oid = indrelid
621
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
622
        WHERE
623
            table_.relname = %(table)s
624
            AND index.relname = %(index)s
625
    UNION
626
        SELECT attnum, attname
627
        FROM
628
        (
629
            SELECT
630
                indrelid
631
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
632
                    AS indkey
633
            FROM pg_index
634
            JOIN pg_class index ON index.oid = indexrelid
635
            JOIN pg_class table_ ON table_.oid = indrelid
636
            WHERE
637
                table_.relname = %(table)s
638
                AND index.relname = %(index)s
639
        ) s
640
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
641
) s
642 853 aaronmk
ORDER BY attnum
643
''',
644 1909 aaronmk
            {'table': table, 'index': index}, cacheable=True)))
645
    else: raise NotImplementedError("Can't list index columns for "+module+
646
        ' database')
647 853 aaronmk
648 464 aaronmk
def constraint_cols(db, table, constraint):
649
    check_name(table)
650
    check_name(constraint)
651 1849 aaronmk
    module = util.root_module(db.db)
652 464 aaronmk
    if module == 'psycopg2':
653
        return list(values(run_query(db, '''\
654
SELECT attname
655
FROM pg_constraint
656
JOIN pg_class ON pg_class.oid = conrelid
657
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
658
WHERE
659
    relname = %(table)s
660
    AND conname = %(constraint)s
661
ORDER BY attnum
662
''',
663
            {'table': table, 'constraint': constraint})))
664
    else: raise NotImplementedError("Can't list constraint columns for "+module+
665
        ' database')
666
667 2096 aaronmk
row_num_col = '_row_num'
668
669 2086 aaronmk
def add_row_num(db, table):
670 2117 aaronmk
    '''Adds a row number column to a table. Its name is in row_num_col. It will
671
    be the primary key.'''
672 2086 aaronmk
    check_name(table)
673 2096 aaronmk
    run_query(db, 'ALTER TABLE '+table+' ADD COLUMN '+row_num_col
674 2117 aaronmk
        +' serial NOT NULL PRIMARY KEY')
675 2086 aaronmk
676 1968 aaronmk
def tables(db, schema='public', table_like='%'):
677 1849 aaronmk
    module = util.root_module(db.db)
678 1968 aaronmk
    params = {'schema': schema, 'table_like': table_like}
679 832 aaronmk
    if module == 'psycopg2':
680 1968 aaronmk
        return values(run_query(db, '''\
681
SELECT tablename
682
FROM pg_tables
683
WHERE
684
    schemaname = %(schema)s
685
    AND tablename LIKE %(table_like)s
686
ORDER BY tablename
687
''',
688
            params, cacheable=True))
689
    elif module == 'MySQLdb':
690
        return values(run_query(db, 'SHOW TABLES LIKE %(table_like)s', params,
691
            cacheable=True))
692 832 aaronmk
    else: raise NotImplementedError("Can't list tables for "+module+' database')
693 830 aaronmk
694 833 aaronmk
##### Database management
695
696 1968 aaronmk
def empty_db(db, schema='public', **kw_args):
697
    '''For kw_args, see tables()'''
698
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
699 833 aaronmk
700 832 aaronmk
##### Heuristic queries
701
702 2104 aaronmk
def put(db, table, row, pkey_=None, row_ct_ref=None):
703 1554 aaronmk
    '''Recovers from errors.
704 2077 aaronmk
    Only works under PostgreSQL (uses INSERT RETURNING).
705
    '''
706 2104 aaronmk
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
707
708 471 aaronmk
    try:
709 2149 aaronmk
        cur = insert(db, table, row, pkey_, recover=True)
710 1554 aaronmk
        if row_ct_ref != None and cur.rowcount >= 0:
711
            row_ct_ref[0] += cur.rowcount
712
        return value(cur)
713 471 aaronmk
    except DuplicateKeyException, e:
714 2104 aaronmk
        return value(select(db, table, [pkey_],
715 1069 aaronmk
            util.dict_subset_right_join(row, e.cols), recover=True))
716 471 aaronmk
717 473 aaronmk
def get(db, table, row, pkey, row_ct_ref=None, create=False):
718 830 aaronmk
    '''Recovers from errors'''
719 2209 aaronmk
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
720 14 aaronmk
    except StopIteration:
721 40 aaronmk
        if not create: raise
722 471 aaronmk
        return put(db, table, row, pkey, row_ct_ref) # insert new row
723 2078 aaronmk
724 2134 aaronmk
def put_table(db, out_table, in_tables, mapping, limit=None, start=0,
725 2279 aaronmk
    row_ct_ref=None):
726 2078 aaronmk
    '''Recovers from errors.
727
    Only works under PostgreSQL (uses INSERT RETURNING).
728 2131 aaronmk
    @param in_tables The main input table to select from, followed by a list of
729
        tables to join with it using the main input table's pkey
730 2279 aaronmk
    @return sql_gen.Col Where the pkeys (from INSERT RETURNING) are made
731 2078 aaronmk
        available
732
    '''
733 2251 aaronmk
    temp_prefix = clean_name(out_table)
734
    pkeys_ref = [temp_prefix+'_pkeys']
735 2131 aaronmk
736 2132 aaronmk
    # Join together input tables
737 2131 aaronmk
    in_tables = in_tables[:] # don't modify input!
738
    in_tables0 = in_tables.pop(0) # first table is separate
739 2279 aaronmk
    in_pkey = pkey(db, in_tables0, recover=True)
740 2285 aaronmk
    in_pkey_col = sql_gen.as_Col(in_pkey, in_tables0)
741 2278 aaronmk
    insert_joins = [in_tables0]+[sql_gen.Join(v, {in_pkey: sql_gen.join_using})
742
        for v in in_tables]
743 2131 aaronmk
744 2279 aaronmk
    out_pkey = pkey(db, out_table, recover=True)
745 2285 aaronmk
    out_pkey_col = sql_gen.as_Col(out_pkey, out_table)
746 2142 aaronmk
747 2236 aaronmk
    pkeys = [in_pkey, out_pkey]
748
    pkeys_cols = [in_pkey_col, out_pkey_col]
749
750 2201 aaronmk
    pkeys_table_exists_ref = [False]
751
    def run_query_into_pkeys(query, params):
752
        if pkeys_table_exists_ref[0]:
753 2236 aaronmk
            insert_select(db, pkeys_ref[0], pkeys, query, params)
754 2201 aaronmk
        else:
755
            run_query_into(db, query, params, into_ref=pkeys_ref)
756
            pkeys_table_exists_ref[0] = True
757
758 2208 aaronmk
    conds = {}
759 2233 aaronmk
    distinct_on = []
760 2207 aaronmk
    def mk_main_select(cols):
761 2208 aaronmk
        return mk_select(db, insert_joins, cols, conds, distinct_on,
762 2297 aaronmk
            limit=limit, start=start, default_table=in_tables0)
763 2132 aaronmk
764 2309 aaronmk
    def log_exc(e):
765
        db.log_debug('Caught exception: '+exc.str_(e, first_line_only=True))
766 2245 aaronmk
    def log_ignore(in_col, value):
767
        db.log_debug('Ignoring rows with '+in_col+' = '+value)
768
769 2206 aaronmk
    # Do inserts and selects
770 2257 aaronmk
    join_cols = {}
771
    filter_join_added = False
772 2251 aaronmk
    out_pkeys_ref = [temp_prefix+'_out_pkeys']
773 2252 aaronmk
    in_pkeys_ref = [temp_prefix+'_in_pkeys']
774 2206 aaronmk
    while True:
775 2303 aaronmk
        has_joins = join_cols != {}
776
777 2305 aaronmk
        # Prepare to insert new rows
778 2303 aaronmk
        if has_joins:
779 2305 aaronmk
            distinct_on = filter(util.is_str, join_cols.values())
780 2303 aaronmk
            if not filter_join_added:
781 2305 aaronmk
                insert_joins.append(sql_gen.Join(out_table, join_cols,
782
                    sql_gen.filter_out))
783 2303 aaronmk
                filter_join_added = True
784 2305 aaronmk
            returning = None
785
            into_ref = None
786
        else:
787
            returning = out_pkey
788
            into_ref = out_pkeys_ref
789 2303 aaronmk
790 2305 aaronmk
        db.log_debug('Inserting new rows')
791 2206 aaronmk
        try:
792
            cur = insert_select(db, out_table, mapping.keys(),
793 2305 aaronmk
                *mk_main_select(mapping.values()), returning=returning,
794
                into_ref=into_ref, recover=True)
795 2206 aaronmk
        except DuplicateKeyException, e:
796 2309 aaronmk
            log_exc(e)
797
798 2258 aaronmk
            old_join_cols = join_cols.copy()
799 2257 aaronmk
            join_cols.update(util.dict_subset_right_join(mapping, e.cols))
800 2245 aaronmk
            db.log_debug('Ignoring existing rows, comparing on '+str(join_cols))
801 2258 aaronmk
            assert join_cols != old_join_cols # avoid infinite loops
802 2309 aaronmk
803 2206 aaronmk
            # rerun loop with additional constraints
804 2230 aaronmk
        except NullValueException, e:
805 2309 aaronmk
            log_exc(e)
806
807 2230 aaronmk
            out_col, = e.cols
808
            try: in_col = mapping[out_col]
809
            except KeyError: # no mapping for missing col, so every row invalid
810 2245 aaronmk
                db.log_debug('Missing mapping for '+out_col)
811 2230 aaronmk
                run_query_into_pkeys(*mk_select(db, insert_joins,
812 2297 aaronmk
                    [in_pkey_col, sql_gen.NamedCode(out_pkey, None)], start=0))
813 2230 aaronmk
                break
814
            else:
815 2245 aaronmk
                log_ignore(in_col, 'NULL')
816 2230 aaronmk
                conds[in_col] = sql_gen.CompareCond(None, '!=')
817
                # rerun loop with additional constraints
818 2243 aaronmk
        except FunctionValueException, e:
819 2309 aaronmk
            log_exc(e)
820
821 2243 aaronmk
            assert e.name == sql_gen.unescape_table(out_table)
822
            out_col = 'value' # assume function param was named "value"
823
            in_col = mapping[out_col]
824 2245 aaronmk
            value = e.value
825
            log_ignore(in_col, value)
826
            conds[in_col] = sql_gen.CompareCond(value, '!=')
827 2243 aaronmk
            # rerun loop with additional constraints
828 2303 aaronmk
        else:
829
            if row_ct_ref != None and cur.rowcount >= 0:
830
                row_ct_ref[0] += cur.rowcount
831
                add_row_num(db, out_pkeys_ref[0]) # for joining with input pkeys
832
833 2305 aaronmk
            if has_joins:
834
                select_joins = insert_joins+[sql_gen.Join(out_table, join_cols)]
835
                db.log_debug('Getting output pkeys of existing/inserted rows')
836
                run_query_into_pkeys(*mk_select(db, select_joins, pkeys_cols,
837
                    start=0))
838
            else:
839
                db.log_debug('Getting input pkeys for rows in insert')
840
                run_query_into(db, *mk_main_select([in_pkey]),
841
                    into_ref=in_pkeys_ref)
842
                add_row_num(db, in_pkeys_ref[0]) # for joining with output pkeys
843
844
                db.log_debug('Joining together output and input pkeys')
845
                run_query_into_pkeys(*mk_select(db, [in_pkeys_ref[0],
846
                    sql_gen.Join(out_pkeys_ref[0],
847
                    {row_num_col: sql_gen.join_using})], pkeys, start=0))
848 2303 aaronmk
849
            break # insert successful
850 2132 aaronmk
851 2268 aaronmk
    return sql_gen.Col(out_pkey, pkeys_ref[0])
852 2115 aaronmk
853
##### Data cleanup
854
855 2290 aaronmk
def cleanup_table(db, table, cols):
856 2115 aaronmk
    def esc_name_(name): return esc_name(db, name)
857
858 2290 aaronmk
    table = sql_gen.as_Table(table).to_str(db)
859 2115 aaronmk
    cols = map(esc_name_, cols)
860
861
    run_query(db, 'UPDATE '+table+' SET\n'+(',\n'.join(('\n'+col
862
        +' = nullif(nullif(trim(both from '+col+"), %(null0)s), %(null1)s)"
863
            for col in cols))),
864
        dict(null0='', null1=r'\N'))