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