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 862 aaronmk
import strings
15 131 aaronmk
import util
16 11 aaronmk
17 832 aaronmk
##### Exceptions
18
19 135 aaronmk
def get_cur_query(cur):
20
    if hasattr(cur, 'query'): return cur.query
21
    elif hasattr(cur, '_last_executed'): return cur._last_executed
22
    else: return None
23 14 aaronmk
24 300 aaronmk
def _add_cursor_info(e, cur): exc.add_msg(e, 'query: '+get_cur_query(cur))
25 135 aaronmk
26 300 aaronmk
class DbException(exc.ExceptionWithCause):
27 14 aaronmk
    def __init__(self, msg, cause=None, cur=None):
28 2145 aaronmk
        exc.ExceptionWithCause.__init__(self, msg, cause, cause_newline=True)
29 14 aaronmk
        if cur != None: _add_cursor_info(self, cur)
30
31 2143 aaronmk
class ExceptionWithName(DbException):
32
    def __init__(self, name, cause=None):
33 2145 aaronmk
        DbException.__init__(self, 'for name: '+str(name), cause)
34 2143 aaronmk
        self.name = name
35 360 aaronmk
36 468 aaronmk
class ExceptionWithColumns(DbException):
37
    def __init__(self, cols, cause=None):
38 2145 aaronmk
        DbException.__init__(self, 'for columns: '+(', '.join(cols)), cause)
39 468 aaronmk
        self.cols = cols
40 11 aaronmk
41 2143 aaronmk
class NameException(DbException): pass
42
43 468 aaronmk
class DuplicateKeyException(ExceptionWithColumns): pass
44 13 aaronmk
45 468 aaronmk
class NullValueException(ExceptionWithColumns): pass
46 13 aaronmk
47 2143 aaronmk
class DuplicateTableException(ExceptionWithName): pass
48
49 89 aaronmk
class EmptyRowException(DbException): pass
50
51 865 aaronmk
##### Warnings
52
53
class DbWarning(UserWarning): pass
54
55 1930 aaronmk
##### Result retrieval
56
57
def col_names(cur): return (col[0] for col in cur.description)
58
59
def rows(cur): return iter(lambda: cur.fetchone(), None)
60
61
def consume_rows(cur):
62
    '''Used to fetch all rows so result will be cached'''
63
    iters.consume_iter(rows(cur))
64
65
def next_row(cur): return rows(cur).next()
66
67
def row(cur):
68
    row_ = next_row(cur)
69
    consume_rows(cur)
70
    return row_
71
72
def next_value(cur): return next_row(cur)[0]
73
74
def value(cur): return row(cur)[0]
75
76
def values(cur): return iters.func_iter(lambda: next_value(cur))
77
78
def value_or_none(cur):
79
    try: return value(cur)
80
    except StopIteration: return None
81
82 2101 aaronmk
##### Input validation
83
84
def clean_name(name): return re.sub(r'\W', r'', name)
85
86
def check_name(name):
87
    if re.search(r'\W', name) != None: raise NameException('Name "'+name
88
        +'" may contain only alphanumeric characters and _')
89
90
def esc_name_by_module(module, name, ignore_case=False):
91
    if module == 'psycopg2':
92
        if ignore_case:
93
            # Don't enclose in quotes because this disables case-insensitivity
94
            check_name(name)
95
            return name
96
        else: quote = '"'
97
    elif module == 'MySQLdb': quote = '`'
98
    else: raise NotImplementedError("Can't escape name for "+module+' database')
99
    return quote + name.replace(quote, '') + quote
100
101
def esc_name_by_engine(engine, name, **kw_args):
102
    return esc_name_by_module(db_engines[engine][0], name, **kw_args)
103
104
def esc_name(db, name, **kw_args):
105
    return esc_name_by_module(util.root_module(db.db), name, **kw_args)
106
107
def qual_name(db, schema, table):
108
    def esc_name_(name): return esc_name(db, name)
109
    table = esc_name_(table)
110
    if schema != None: return esc_name_(schema)+'.'+table
111
    else: return table
112
113 1869 aaronmk
##### Database connections
114 1849 aaronmk
115 2097 aaronmk
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
116 1926 aaronmk
117 1869 aaronmk
db_engines = {
118
    'MySQL': ('MySQLdb', {'password': 'passwd', 'database': 'db'}),
119
    'PostgreSQL': ('psycopg2', {}),
120
}
121
122
DatabaseErrors_set = set([DbException])
123
DatabaseErrors = tuple(DatabaseErrors_set)
124
125
def _add_module(module):
126
    DatabaseErrors_set.add(module.DatabaseError)
127
    global DatabaseErrors
128
    DatabaseErrors = tuple(DatabaseErrors_set)
129
130
def db_config_str(db_config):
131
    return db_config['engine']+' database '+db_config['database']
132
133 1909 aaronmk
def _query_lookup(query, params): return (query, dicts.make_hashable(params))
134 1894 aaronmk
135 1901 aaronmk
log_debug_none = lambda msg: None
136
137 1849 aaronmk
class DbConn:
138 2047 aaronmk
    def __init__(self, db_config, serializable=True, log_debug=log_debug_none,
139 2050 aaronmk
        caching=True):
140 1869 aaronmk
        self.db_config = db_config
141
        self.serializable = serializable
142 1901 aaronmk
        self.log_debug = log_debug
143 2047 aaronmk
        self.caching = caching
144 1869 aaronmk
145
        self.__db = None
146 1889 aaronmk
        self.query_results = {}
147 2139 aaronmk
        self._savepoint = 0
148 1869 aaronmk
149
    def __getattr__(self, name):
150
        if name == '__dict__': raise Exception('getting __dict__')
151
        if name == 'db': return self._db()
152
        else: raise AttributeError()
153
154
    def __getstate__(self):
155
        state = copy.copy(self.__dict__) # shallow copy
156 1915 aaronmk
        state['log_debug'] = None # don't pickle the debug callback
157 1869 aaronmk
        state['_DbConn__db'] = None # don't pickle the connection
158
        return state
159
160
    def _db(self):
161
        if self.__db == None:
162
            # Process db_config
163
            db_config = self.db_config.copy() # don't modify input!
164 2097 aaronmk
            schemas = db_config.pop('schemas', None)
165 1869 aaronmk
            module_name, mappings = db_engines[db_config.pop('engine')]
166
            module = __import__(module_name)
167
            _add_module(module)
168
            for orig, new in mappings.iteritems():
169
                try: util.rename_key(db_config, orig, new)
170
                except KeyError: pass
171
172
            # Connect
173
            self.__db = module.connect(**db_config)
174
175
            # Configure connection
176
            if self.serializable: run_raw_query(self,
177
                'SET TRANSACTION ISOLATION LEVEL SERIALIZABLE')
178 2101 aaronmk
            if schemas != None:
179
                schemas_ = ''.join((esc_name(self, s)+', '
180
                    for s in schemas.split(',')))
181
                run_raw_query(self, "SELECT set_config('search_path', \
182
%s || current_setting('search_path'), false)", [schemas_])
183 1869 aaronmk
184
        return self.__db
185 1889 aaronmk
186 1891 aaronmk
    class DbCursor(Proxy):
187 1927 aaronmk
        def __init__(self, outer):
188 1891 aaronmk
            Proxy.__init__(self, outer.db.cursor())
189 1927 aaronmk
            self.query_results = outer.query_results
190 1894 aaronmk
            self.query_lookup = None
191 1891 aaronmk
            self.result = []
192 1889 aaronmk
193 1894 aaronmk
        def execute(self, query, params=None):
194 1930 aaronmk
            self._is_insert = query.upper().find('INSERT') >= 0
195 1894 aaronmk
            self.query_lookup = _query_lookup(query, params)
196 2148 aaronmk
            try:
197
                try: return_value = self.inner.execute(query, params)
198
                finally: self.query = get_cur_query(self.inner)
199 1904 aaronmk
            except Exception, e:
200 2148 aaronmk
                _add_cursor_info(e, self)
201 1904 aaronmk
                self.result = e # cache the exception as the result
202
                self._cache_result()
203
                raise
204 1930 aaronmk
            # Fetch all rows so result will be cached
205
            if self.rowcount == 0 and not self._is_insert: consume_rows(self)
206 1894 aaronmk
            return return_value
207
208 1891 aaronmk
        def fetchone(self):
209
            row = self.inner.fetchone()
210 1899 aaronmk
            if row != None: self.result.append(row)
211
            # otherwise, fetched all rows
212 1904 aaronmk
            else: self._cache_result()
213
            return row
214
215
        def _cache_result(self):
216 1906 aaronmk
            # For inserts, only cache exceptions since inserts are not
217
            # idempotent, but an invalid insert will always be invalid
218 1930 aaronmk
            if self.query_results != None and (not self._is_insert
219 1906 aaronmk
                or isinstance(self.result, Exception)):
220
221 1894 aaronmk
                assert self.query_lookup != None
222 1916 aaronmk
                self.query_results[self.query_lookup] = self.CacheCursor(
223
                    util.dict_subset(dicts.AttrsDictView(self),
224
                    ['query', 'result', 'rowcount', 'description']))
225 1906 aaronmk
226 1916 aaronmk
        class CacheCursor:
227
            def __init__(self, cached_result): self.__dict__ = cached_result
228
229 1927 aaronmk
            def execute(self, *args, **kw_args):
230 1916 aaronmk
                if isinstance(self.result, Exception): raise self.result
231
                # otherwise, result is a rows list
232
                self.iter = iter(self.result)
233
234
            def fetchone(self):
235
                try: return self.iter.next()
236
                except StopIteration: return None
237 1891 aaronmk
238 1894 aaronmk
    def run_query(self, query, params=None, cacheable=False):
239 2148 aaronmk
        '''Translates known DB errors to typed exceptions:
240
        See self.DbCursor.execute().'''
241 2047 aaronmk
        if not self.caching: cacheable = False
242 1903 aaronmk
        used_cache = False
243
        try:
244 1927 aaronmk
            # Get cursor
245
            if cacheable:
246
                query_lookup = _query_lookup(query, params)
247
                try:
248
                    cur = self.query_results[query_lookup]
249
                    used_cache = True
250
                except KeyError: cur = self.DbCursor(self)
251
            else: cur = self.db.cursor()
252
253
            # Run query
254 2148 aaronmk
            cur.execute(query, params)
255 1903 aaronmk
        finally:
256
            if self.log_debug != log_debug_none: # only compute msg if needed
257
                if used_cache: cache_status = 'Cache hit'
258
                elif cacheable: cache_status = 'Cache miss'
259
                else: cache_status = 'Non-cacheable'
260 1927 aaronmk
                self.log_debug(cache_status+': '
261
                    +strings.one_line(get_cur_query(cur)))
262 1903 aaronmk
263
        return cur
264 1914 aaronmk
265
    def is_cached(self, query, params=None):
266
        return _query_lookup(query, params) in self.query_results
267 2139 aaronmk
268
    def with_savepoint(self, func):
269
        savepoint = 'savepoint_'+str(self._savepoint)
270
        self.run_query('SAVEPOINT '+savepoint)
271
        self._savepoint += 1
272
        try:
273
            try: return_val = func()
274
            finally:
275
                self._savepoint -= 1
276
                assert self._savepoint >= 0
277
        except:
278
            self.run_query('ROLLBACK TO SAVEPOINT '+savepoint)
279
            raise
280
        else:
281
            self.run_query('RELEASE SAVEPOINT '+savepoint)
282
            return return_val
283 1849 aaronmk
284 1869 aaronmk
connect = DbConn
285
286 832 aaronmk
##### Querying
287
288 1894 aaronmk
def run_raw_query(db, *args, **kw_args):
289 2085 aaronmk
    '''For params, see DbConn.run_query()'''
290 1894 aaronmk
    return db.run_query(*args, **kw_args)
291 11 aaronmk
292 2068 aaronmk
def mogrify(db, query, params):
293
    module = util.root_module(db.db)
294
    if module == 'psycopg2': return db.db.cursor().mogrify(query, params)
295
    else: raise NotImplementedError("Can't mogrify query for "+module+
296
        ' database')
297
298 832 aaronmk
##### Recoverable querying
299 15 aaronmk
300 2139 aaronmk
def with_savepoint(db, func): return db.with_savepoint(func)
301 11 aaronmk
302 1894 aaronmk
def run_query(db, query, params=None, recover=None, cacheable=False):
303 830 aaronmk
    if recover == None: recover = False
304
305 2148 aaronmk
    try:
306
        def run(): return run_raw_query(db, query, params, cacheable)
307
        if recover and not db.is_cached(query, params):
308
            return with_savepoint(db, run)
309
        else: return run() # don't need savepoint if cached
310
    except Exception, e:
311
        if not recover: raise # need savepoint to run index_cols()
312
        msg = str(e)
313
        match = re.search(r'duplicate key value violates unique constraint '
314
            r'"((_?[^\W_]+)_[^"]+)"', msg)
315
        if match:
316
            constraint, table = match.groups()
317
            try: cols = index_cols(db, table, constraint)
318
            except NotImplementedError: raise e
319
            else: raise DuplicateKeyException(cols, e)
320
        match = re.search(r'null value in column "(\w+)" violates not-null '
321
            'constraint', msg)
322
        if match: raise NullValueException([match.group(1)], e)
323
        match = re.search(r'relation "(\w+)" already exists', msg)
324
        if match: raise DuplicateTableException(match.group(1), e)
325
        raise # no specific exception raised
326 830 aaronmk
327 832 aaronmk
##### Basic queries
328
329 2151 aaronmk
def run_query_into(db, query, params, into_ref=None, *args, **kw_args):
330 2085 aaronmk
    '''Outputs a query to a temp table.
331
    For params, see run_query().
332
    '''
333 2151 aaronmk
    if into_ref == None: return run_query(db, query, params, *args, **kw_args)
334 2085 aaronmk
    else: # place rows in temp table
335 2151 aaronmk
        check_name(into_ref[0])
336
        return run_query(db, 'CREATE TEMP TABLE '+into_ref[0]+' AS '+query,
337
            params, *args, **kw_args) # CREATE TABLE AS sets rowcount to # rows
338 2085 aaronmk
339 2120 aaronmk
order_by_pkey = object() # tells mk_select() to order by the pkey
340
341 2127 aaronmk
join_using = object() # tells mk_select() to join the column with USING
342
343 2121 aaronmk
def mk_select(db, tables, fields=None, conds=None, limit=None, start=None,
344 2120 aaronmk
    order_by=order_by_pkey, table_is_esc=False):
345 1981 aaronmk
    '''
346 2121 aaronmk
    @param tables The single table to select from, or a list of tables to join
347 2124 aaronmk
        together: [table0, (table1, dict(right_col=left_col, ...)), ...]
348 1981 aaronmk
    @param fields Use None to select all fields in the table
349
    @param table_is_esc Whether the table name has already been escaped
350 2054 aaronmk
    @return tuple(query, params)
351 1981 aaronmk
    '''
352 2060 aaronmk
    def esc_name_(name): return esc_name(db, name)
353 2058 aaronmk
354 2121 aaronmk
    if not lists.is_seq(tables): tables = [tables]
355 2141 aaronmk
    tables = list(tables) # don't modify input! (list() copies input)
356 2121 aaronmk
    table0 = tables.pop(0) # first table is separate
357
358 1135 aaronmk
    if conds == None: conds = {}
359 135 aaronmk
    assert limit == None or type(limit) == int
360 865 aaronmk
    assert start == None or type(start) == int
361 2120 aaronmk
    if order_by == order_by_pkey:
362 2121 aaronmk
        order_by = pkey(db, table0, recover=True, table_is_esc=table_is_esc)
363
    if not table_is_esc: table0 = esc_name_(table0)
364 865 aaronmk
365 2056 aaronmk
    params = []
366
367
    def parse_col(field):
368
        '''Parses fields'''
369 2121 aaronmk
        if isinstance(field, tuple): # field is literal value
370 2056 aaronmk
            value, col = field
371
            sql_ = '%s'
372
            params.append(value)
373 2058 aaronmk
            if col != None: sql_ += ' AS '+esc_name_(col)
374
        else: sql_ = esc_name_(field) # field is col name
375 2056 aaronmk
        return sql_
376 11 aaronmk
    def cond(entry):
377 2056 aaronmk
        '''Parses conditions'''
378 13 aaronmk
        col, value = entry
379 2058 aaronmk
        cond_ = esc_name_(col)+' '
380 11 aaronmk
        if value == None: cond_ += 'IS'
381
        else: cond_ += '='
382
        cond_ += ' %s'
383
        return cond_
384 2056 aaronmk
385 1135 aaronmk
    query = 'SELECT '
386
    if fields == None: query += '*'
387 2056 aaronmk
    else: query += ', '.join(map(parse_col, fields))
388 2121 aaronmk
    query += ' FROM '+table0
389 865 aaronmk
390 2122 aaronmk
    # Add joins
391
    left_table = table0
392
    for table, joins in tables:
393
        if not table_is_esc: table = esc_name_(table)
394 2127 aaronmk
        query += ' JOIN '+table
395 2122 aaronmk
396
        def join(entry):
397 2127 aaronmk
            '''Parses non-USING joins'''
398 2124 aaronmk
            right_col, left_col = entry
399
            right_col = table+'.'+esc_name_(right_col)
400 2122 aaronmk
            left_col = left_table+'.'+esc_name_(left_col)
401 2123 aaronmk
            return (right_col+' = '+left_col
402
                +' OR ('+right_col+' IS NULL AND '+left_col+' IS NULL)')
403 2122 aaronmk
404 2127 aaronmk
        if reduce(operator.and_, (v == join_using for v in joins.itervalues())):
405
            # all cols w/ USING
406 2130 aaronmk
            query += ' USING ('+(', '.join(joins.iterkeys()))+')'
407 2127 aaronmk
        else: query += ' ON '+(' AND '.join(map(join, joins.iteritems())))
408
409 2122 aaronmk
        left_table = table
410
411 865 aaronmk
    missing = True
412 89 aaronmk
    if conds != {}:
413 2122 aaronmk
        query += ' WHERE '+(' AND '.join(map(cond, conds.iteritems())))
414 2056 aaronmk
        params += conds.values()
415 865 aaronmk
        missing = False
416 2120 aaronmk
    if order_by != None: query += ' ORDER BY '+esc_name_(order_by)
417 865 aaronmk
    if limit != None: query += ' LIMIT '+str(limit); missing = False
418
    if start != None:
419
        if start != 0: query += ' OFFSET '+str(start)
420
        missing = False
421
    if missing: warnings.warn(DbWarning(
422
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
423
424 2056 aaronmk
    return (query, params)
425 11 aaronmk
426 2054 aaronmk
def select(db, *args, **kw_args):
427
    '''For params, see mk_select() and run_query()'''
428
    recover = kw_args.pop('recover', None)
429
    cacheable = kw_args.pop('cacheable', True)
430
431
    query, params = mk_select(db, *args, **kw_args)
432
    return run_query(db, query, params, recover, cacheable)
433
434 2066 aaronmk
def mk_insert_select(db, table, cols=None, select_query=None, params=None,
435 2070 aaronmk
    returning=None, embeddable=False, table_is_esc=False):
436 1960 aaronmk
    '''
437
    @param returning str|None An inserted column (such as pkey) to return
438 2070 aaronmk
    @param embeddable Whether the query should be embeddable as a nested SELECT.
439 2073 aaronmk
        Warning: If you set this and cacheable=True when the query is run, the
440
        query will be fully cached, not just if it raises an exception.
441 1960 aaronmk
    @param table_is_esc Whether the table name has already been escaped
442
    '''
443 2063 aaronmk
    if select_query == None: select_query = 'DEFAULT VALUES'
444
    if cols == []: cols = None # no cols (all defaults) = unknown col names
445 1960 aaronmk
    if not table_is_esc: check_name(table)
446 2063 aaronmk
447
    # Build query
448
    query = 'INSERT INTO '+table
449
    if cols != None:
450
        map(check_name, cols)
451
        query += ' ('+', '.join(cols)+')'
452
    query += ' '+select_query
453
454
    if returning != None:
455
        check_name(returning)
456
        query += ' RETURNING '+returning
457
458 2070 aaronmk
    if embeddable:
459
        # Create function
460 2083 aaronmk
        function = 'pg_temp.'+('_'.join(map(clean_name,
461
            ['insert', table] + cols)))
462 2070 aaronmk
        return_type = 'SETOF '+table+'.'+returning+'%TYPE'
463
        function_query = '''\
464 2083 aaronmk
CREATE OR REPLACE FUNCTION '''+function+'''() RETURNS '''+return_type+'''
465 2070 aaronmk
    LANGUAGE sql
466
    AS $$'''+mogrify(db, query, params)+''';$$;
467
'''
468
        run_query(db, function_query, cacheable=True)
469
470
        # Return query that uses function
471 2134 aaronmk
        return mk_select(db, function+'() AS f ('+returning+')', start=0,
472
            order_by=None, table_is_esc=True)# AS clause requires function alias
473 2070 aaronmk
474 2066 aaronmk
    return (query, params)
475
476
def insert_select(db, *args, **kw_args):
477 2085 aaronmk
    '''For params, see mk_insert_select() and run_query_into()
478 2152 aaronmk
    @param into_ref List with name of temp table to place RETURNING values in
479 2072 aaronmk
    '''
480 2151 aaronmk
    into_ref = kw_args.pop('into_ref', None)
481
    if into_ref != None: kw_args['embeddable'] = True
482 2066 aaronmk
    recover = kw_args.pop('recover', None)
483
    cacheable = kw_args.pop('cacheable', True)
484
485
    query, params = mk_insert_select(db, *args, **kw_args)
486 2151 aaronmk
    return run_query_into(db, query, params, into_ref, recover, cacheable)
487 2063 aaronmk
488 2066 aaronmk
default = object() # tells insert() to use the default value for a column
489
490 2063 aaronmk
def insert(db, table, row, *args, **kw_args):
491 2085 aaronmk
    '''For params, see insert_select()'''
492 1960 aaronmk
    if lists.is_seq(row): cols = None
493
    else:
494
        cols = row.keys()
495
        row = row.values()
496
    row = list(row) # ensure that "!= []" works
497
498 1961 aaronmk
    # Check for special values
499
    labels = []
500
    values = []
501
    for value in row:
502
        if value == default: labels.append('DEFAULT')
503
        else:
504
            labels.append('%s')
505
            values.append(value)
506
507
    # Build query
508 2063 aaronmk
    if values != []: query = ' VALUES ('+(', '.join(labels))+')'
509
    else: query = None
510 1554 aaronmk
511 2064 aaronmk
    return insert_select(db, table, cols, query, values, *args, **kw_args)
512 11 aaronmk
513 135 aaronmk
def last_insert_id(db):
514 1849 aaronmk
    module = util.root_module(db.db)
515 135 aaronmk
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
516
    elif module == 'MySQLdb': return db.insert_id()
517
    else: return None
518 13 aaronmk
519 1968 aaronmk
def truncate(db, table, schema='public'):
520
    return run_query(db, 'TRUNCATE '+qual_name(db, schema, table)+' CASCADE')
521 832 aaronmk
522
##### Database structure queries
523
524 2084 aaronmk
def pkey(db, table, recover=None, table_is_esc=False):
525 832 aaronmk
    '''Assumed to be first column in table'''
526 2120 aaronmk
    return col_names(select(db, table, limit=0, order_by=None, recover=recover,
527 2084 aaronmk
        table_is_esc=table_is_esc)).next()
528 832 aaronmk
529 853 aaronmk
def index_cols(db, table, index):
530
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
531
    automatically created. When you don't know whether something is a UNIQUE
532
    constraint or a UNIQUE index, use this function.'''
533
    check_name(table)
534
    check_name(index)
535 1909 aaronmk
    module = util.root_module(db.db)
536
    if module == 'psycopg2':
537
        return list(values(run_query(db, '''\
538 853 aaronmk
SELECT attname
539 866 aaronmk
FROM
540
(
541
        SELECT attnum, attname
542
        FROM pg_index
543
        JOIN pg_class index ON index.oid = indexrelid
544
        JOIN pg_class table_ ON table_.oid = indrelid
545
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
546
        WHERE
547
            table_.relname = %(table)s
548
            AND index.relname = %(index)s
549
    UNION
550
        SELECT attnum, attname
551
        FROM
552
        (
553
            SELECT
554
                indrelid
555
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
556
                    AS indkey
557
            FROM pg_index
558
            JOIN pg_class index ON index.oid = indexrelid
559
            JOIN pg_class table_ ON table_.oid = indrelid
560
            WHERE
561
                table_.relname = %(table)s
562
                AND index.relname = %(index)s
563
        ) s
564
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
565
) s
566 853 aaronmk
ORDER BY attnum
567
''',
568 1909 aaronmk
            {'table': table, 'index': index}, cacheable=True)))
569
    else: raise NotImplementedError("Can't list index columns for "+module+
570
        ' database')
571 853 aaronmk
572 464 aaronmk
def constraint_cols(db, table, constraint):
573
    check_name(table)
574
    check_name(constraint)
575 1849 aaronmk
    module = util.root_module(db.db)
576 464 aaronmk
    if module == 'psycopg2':
577
        return list(values(run_query(db, '''\
578
SELECT attname
579
FROM pg_constraint
580
JOIN pg_class ON pg_class.oid = conrelid
581
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
582
WHERE
583
    relname = %(table)s
584
    AND conname = %(constraint)s
585
ORDER BY attnum
586
''',
587
            {'table': table, 'constraint': constraint})))
588
    else: raise NotImplementedError("Can't list constraint columns for "+module+
589
        ' database')
590
591 2096 aaronmk
row_num_col = '_row_num'
592
593 2086 aaronmk
def add_row_num(db, table):
594 2117 aaronmk
    '''Adds a row number column to a table. Its name is in row_num_col. It will
595
    be the primary key.'''
596 2086 aaronmk
    check_name(table)
597 2096 aaronmk
    run_query(db, 'ALTER TABLE '+table+' ADD COLUMN '+row_num_col
598 2117 aaronmk
        +' serial NOT NULL PRIMARY KEY')
599 2086 aaronmk
600 1968 aaronmk
def tables(db, schema='public', table_like='%'):
601 1849 aaronmk
    module = util.root_module(db.db)
602 1968 aaronmk
    params = {'schema': schema, 'table_like': table_like}
603 832 aaronmk
    if module == 'psycopg2':
604 1968 aaronmk
        return values(run_query(db, '''\
605
SELECT tablename
606
FROM pg_tables
607
WHERE
608
    schemaname = %(schema)s
609
    AND tablename LIKE %(table_like)s
610
ORDER BY tablename
611
''',
612
            params, cacheable=True))
613
    elif module == 'MySQLdb':
614
        return values(run_query(db, 'SHOW TABLES LIKE %(table_like)s', params,
615
            cacheable=True))
616 832 aaronmk
    else: raise NotImplementedError("Can't list tables for "+module+' database')
617 830 aaronmk
618 833 aaronmk
##### Database management
619
620 1968 aaronmk
def empty_db(db, schema='public', **kw_args):
621
    '''For kw_args, see tables()'''
622
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
623 833 aaronmk
624 832 aaronmk
##### Heuristic queries
625
626 2104 aaronmk
def put(db, table, row, pkey_=None, row_ct_ref=None):
627 1554 aaronmk
    '''Recovers from errors.
628 2077 aaronmk
    Only works under PostgreSQL (uses INSERT RETURNING).
629
    '''
630 2104 aaronmk
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
631
632 471 aaronmk
    try:
633 2149 aaronmk
        cur = insert(db, table, row, pkey_, recover=True)
634 1554 aaronmk
        if row_ct_ref != None and cur.rowcount >= 0:
635
            row_ct_ref[0] += cur.rowcount
636
        return value(cur)
637 471 aaronmk
    except DuplicateKeyException, e:
638 2104 aaronmk
        return value(select(db, table, [pkey_],
639 1069 aaronmk
            util.dict_subset_right_join(row, e.cols), recover=True))
640 471 aaronmk
641 473 aaronmk
def get(db, table, row, pkey, row_ct_ref=None, create=False):
642 830 aaronmk
    '''Recovers from errors'''
643
    try: return value(select(db, table, [pkey], row, 1, recover=True))
644 14 aaronmk
    except StopIteration:
645 40 aaronmk
        if not create: raise
646 471 aaronmk
        return put(db, table, row, pkey, row_ct_ref) # insert new row
647 2078 aaronmk
648 2134 aaronmk
def put_table(db, out_table, in_tables, mapping, limit=None, start=0,
649
    row_ct_ref=None, table_is_esc=False):
650 2078 aaronmk
    '''Recovers from errors.
651
    Only works under PostgreSQL (uses INSERT RETURNING).
652 2131 aaronmk
    @param in_tables The main input table to select from, followed by a list of
653
        tables to join with it using the main input table's pkey
654 2133 aaronmk
    @return (table, col) Where the pkeys (from INSERT RETURNING) are made
655 2078 aaronmk
        available
656
    '''
657 2142 aaronmk
    temp_prefix = '_'.join(map(clean_name,
658
        [out_table] + list(iters.flatten(mapping.items()))))
659
    pkeys = temp_prefix+'_pkeys'
660 2131 aaronmk
661 2132 aaronmk
    # Join together input tables
662 2131 aaronmk
    in_tables = in_tables[:] # don't modify input!
663
    in_tables0 = in_tables.pop(0) # first table is separate
664
    in_pkey = pkey(db, in_tables0, recover=True, table_is_esc=table_is_esc)
665 2142 aaronmk
    in_joins = [in_tables0] + [(t, {in_pkey: join_using}) for t in in_tables]
666 2131 aaronmk
667 2142 aaronmk
    out_pkey = pkey(db, out_table, recover=True, table_is_esc=table_is_esc)
668
    pkeys_cols = [in_pkey, out_pkey]
669
670 2132 aaronmk
    def mk_select_(cols):
671 2142 aaronmk
        return mk_select(db, in_joins, cols, limit=limit, start=start,
672 2134 aaronmk
            table_is_esc=table_is_esc)
673 2132 aaronmk
674 2142 aaronmk
    out_pkeys = temp_prefix+'_out_pkeys'
675 2078 aaronmk
    def insert_():
676 2148 aaronmk
        '''Inserts and capture output pkeys.'''
677 2132 aaronmk
        cur = insert_select(db, out_table, mapping.keys(),
678 2133 aaronmk
            *mk_select_(mapping.values()), returning=out_pkey,
679 2151 aaronmk
            into_ref=[out_pkeys], recover=True, table_is_esc=table_is_esc)
680 2078 aaronmk
        if row_ct_ref != None and cur.rowcount >= 0:
681
            row_ct_ref[0] += cur.rowcount
682 2132 aaronmk
        add_row_num(db, out_pkeys) # for joining it with in_pkeys
683 2086 aaronmk
684 2132 aaronmk
        # Get input pkeys corresponding to rows in insert
685 2142 aaronmk
        in_pkeys = temp_prefix+'_in_pkeys'
686 2151 aaronmk
        run_query_into(db, *mk_select_([in_pkey]), into_ref=[in_pkeys])
687 2132 aaronmk
        add_row_num(db, in_pkeys) # for joining it with out_pkeys
688 2086 aaronmk
689 2132 aaronmk
        # Join together out_pkeys and in_pkeys
690
        run_query_into(db, *mk_select(db,
691
            [in_pkeys, (out_pkeys, {row_num_col: join_using})],
692 2152 aaronmk
            pkeys_cols, start=0), into_ref=[pkeys])
693 2132 aaronmk
694 2142 aaronmk
    # Do inserts and selects
695 2148 aaronmk
    try: insert_()
696 2142 aaronmk
    except DuplicateKeyException, e:
697
        join_cols = util.dict_subset_right_join(mapping, e.cols)
698
        joins = in_joins + [(out_table, join_cols)]
699
        run_query_into(db, *mk_select(db, joins, pkeys_cols,
700 2152 aaronmk
            table_is_esc=table_is_esc), into_ref=[pkeys], recover=True)
701 2142 aaronmk
702
    return (pkeys, out_pkey)
703 2115 aaronmk
704
##### Data cleanup
705
706
def cleanup_table(db, table, cols, table_is_esc=False):
707
    def esc_name_(name): return esc_name(db, name)
708
709
    if not table_is_esc: check_name(table)
710
    cols = map(esc_name_, cols)
711
712
    run_query(db, 'UPDATE '+table+' SET\n'+(',\n'.join(('\n'+col
713
        +' = nullif(nullif(trim(both from '+col+"), %(null0)s), %(null1)s)"
714
            for col in cols))),
715
        dict(null0='', null1=r'\N'))