Project

General

Profile

1
# Database access
2

    
3
import copy
4
import re
5
import warnings
6

    
7
import exc
8
import iters
9
from Proxy import Proxy
10
import rand
11
import strings
12
import util
13

    
14
##### Exceptions
15

    
16
def get_cur_query(cur):
17
    if hasattr(cur, 'query'): return cur.query
18
    elif hasattr(cur, '_last_executed'): return cur._last_executed
19
    else: return None
20

    
21
def _add_cursor_info(e, cur): exc.add_msg(e, 'query: '+get_cur_query(cur))
22

    
23
class DbException(exc.ExceptionWithCause):
24
    def __init__(self, msg, cause=None, cur=None):
25
        exc.ExceptionWithCause.__init__(self, msg, cause)
26
        if cur != None: _add_cursor_info(self, cur)
27

    
28
class NameException(DbException): pass
29

    
30
class ExceptionWithColumns(DbException):
31
    def __init__(self, cols, cause=None):
32
        DbException.__init__(self, 'columns: ' + ', '.join(cols), cause)
33
        self.cols = cols
34

    
35
class DuplicateKeyException(ExceptionWithColumns): pass
36

    
37
class NullValueException(ExceptionWithColumns): pass
38

    
39
class EmptyRowException(DbException): pass
40

    
41
##### Warnings
42

    
43
class DbWarning(UserWarning): pass
44

    
45
##### Input validation
46

    
47
def check_name(name):
48
    if re.search(r'\W', name) != None: raise NameException('Name "'+name
49
        +'" may contain only alphanumeric characters and _')
50

    
51
def esc_name(db, name):
52
    module = util.root_module(db.db)
53
    if module == 'psycopg2': return name
54
        # Don't enclose in quotes because this disables case-insensitivity
55
    elif module == 'MySQLdb': quote = '`'
56
    else: raise NotImplementedError("Can't escape name for "+module+' database')
57
    return quote + name.replace(quote, '') + quote
58

    
59
##### Database connections
60

    
61
db_engines = {
62
    'MySQL': ('MySQLdb', {'password': 'passwd', 'database': 'db'}),
63
    'PostgreSQL': ('psycopg2', {}),
64
}
65

    
66
DatabaseErrors_set = set([DbException])
67
DatabaseErrors = tuple(DatabaseErrors_set)
68

    
69
def _add_module(module):
70
    DatabaseErrors_set.add(module.DatabaseError)
71
    global DatabaseErrors
72
    DatabaseErrors = tuple(DatabaseErrors_set)
73

    
74
def db_config_str(db_config):
75
    return db_config['engine']+' database '+db_config['database']
76

    
77
def _query_lookup(query, params): return (query, util.cast(tuple, params))
78

    
79
log_debug_none = lambda msg: None
80

    
81
class DbConn:
82
    def __init__(self, db_config, serializable=True, log_debug=log_debug_none):
83
        self.db_config = db_config
84
        self.serializable = serializable
85
        self.log_debug = log_debug
86
        
87
        self.__db = None
88
        self.pkeys = {}
89
        self.index_cols = {}
90
        self.query_results = {}
91
    
92
    def __getattr__(self, name):
93
        if name == '__dict__': raise Exception('getting __dict__')
94
        if name == 'db': return self._db()
95
        else: raise AttributeError()
96
    
97
    def __getstate__(self):
98
        state = copy.copy(self.__dict__) # shallow copy
99
        state['_DbConn__db'] = None # don't pickle the connection
100
        return state
101
    
102
    def _db(self):
103
        if self.__db == None:
104
            # Process db_config
105
            db_config = self.db_config.copy() # don't modify input!
106
            module_name, mappings = db_engines[db_config.pop('engine')]
107
            module = __import__(module_name)
108
            _add_module(module)
109
            for orig, new in mappings.iteritems():
110
                try: util.rename_key(db_config, orig, new)
111
                except KeyError: pass
112
            
113
            # Connect
114
            self.__db = module.connect(**db_config)
115
            
116
            # Configure connection
117
            if self.serializable: run_raw_query(self,
118
                'SET TRANSACTION ISOLATION LEVEL SERIALIZABLE')
119
        
120
        return self.__db
121
    
122
    class DbCursor(Proxy):
123
        def __init__(self, outer, cache_results):
124
            Proxy.__init__(self, outer.db.cursor())
125
            if cache_results: self.query_results = outer.query_results
126
            else: self.query_results = None
127
            self.query_lookup = None
128
            self.result = []
129
        
130
        def execute(self, query, params=None):
131
            self.query_lookup = _query_lookup(query, params)
132
            try: return_value = self.inner.execute(query, params)
133
            except Exception, e:
134
                self.result = e # cache the exception as the result
135
                self._cache_result()
136
                raise
137
            finally: self.query = get_cur_query(self.inner)
138
            return return_value
139
        
140
        def fetchone(self):
141
            row = self.inner.fetchone()
142
            if row != None: self.result.append(row)
143
            # otherwise, fetched all rows
144
            else: self._cache_result()
145
            return row
146
        
147
        def _cache_result(self):
148
            if self.query_results != None: # is caching
149
                assert self.query_lookup != None
150
                self.query_results[self.query_lookup] = (self.query,
151
                    self.result)
152
    
153
    class CacheCursor:
154
        def __init__(self, query, result):
155
            self.query = query
156
            if isinstance(result, Exception): raise result
157
            # otherwise, result is a rows list
158
            self.rowcount = len(result)
159
            self.iter = iter(result)
160
        
161
        def fetchone(self):
162
            try: return self.iter.next()
163
            except StopIteration: return None
164
    
165
    def run_query(self, query, params=None, cacheable=False):
166
        query_lookup = _query_lookup(query, params)
167
        used_cache = False
168
        try:
169
            try:
170
                if not cacheable: raise KeyError
171
                actual_query, result = self.query_results[query_lookup]
172
                used_cache = True
173
            except KeyError:
174
                cur = self.DbCursor(self, cacheable)
175
                try: cur.execute(query, params)
176
                except Exception, e:
177
                    _add_cursor_info(e, cur)
178
                    raise
179
            else: cur = self.CacheCursor(actual_query, result)
180
        finally:
181
            if self.log_debug != log_debug_none: # only compute msg if needed
182
                if used_cache: cache_status = 'Cache hit'
183
                elif cacheable: cache_status = 'Cache miss'
184
                else: cache_status = 'Non-cacheable'
185
                self.log_debug(cache_status+': '+strings.one_line(cur.query))
186
        
187
        return cur
188

    
189
connect = DbConn
190

    
191
##### Querying
192

    
193
def run_raw_query(db, *args, **kw_args):
194
    '''For args, see DbConn.run_query()'''
195
    return db.run_query(*args, **kw_args)
196

    
197
##### Recoverable querying
198

    
199
def with_savepoint(db, func):
200
    savepoint = 'savepoint_'+str(rand.rand_int()) # must be unique
201
    run_raw_query(db, 'SAVEPOINT '+savepoint)
202
    try: return_val = func()
203
    except:
204
        run_raw_query(db, 'ROLLBACK TO SAVEPOINT '+savepoint)
205
        raise
206
    else:
207
        run_raw_query(db, 'RELEASE SAVEPOINT '+savepoint)
208
        return return_val
209

    
210
def run_query(db, query, params=None, recover=None, cacheable=False):
211
    if recover == None: recover = False
212
    
213
    def run(): return run_raw_query(db, query, params, cacheable)
214
    if recover: return with_savepoint(db, run)
215
    else: return run()
216

    
217
##### Result retrieval
218

    
219
def col_names(cur): return (col[0] for col in cur.description)
220

    
221
def rows(cur): return iter(lambda: cur.fetchone(), None)
222

    
223
def next_row(cur): return rows(cur).next()
224

    
225
def row(cur):
226
    row_iter = rows(cur)
227
    row_ = row_iter.next()
228
    iters.consume_iter(row_iter) # fetch all rows so result will be cached
229
    return row_
230

    
231
def next_value(cur): return next_row(cur)[0]
232

    
233
def value(cur): return row(cur)[0]
234

    
235
def values(cur): return iters.func_iter(lambda: next_value(cur))
236

    
237
def value_or_none(cur):
238
    try: return value(cur)
239
    except StopIteration: return None
240

    
241
##### Basic queries
242

    
243
def select(db, table, fields=None, conds=None, limit=None, start=None,
244
    recover=None, cacheable=True):
245
    '''@param fields Use None to select all fields in the table'''
246
    if conds == None: conds = {}
247
    assert limit == None or type(limit) == int
248
    assert start == None or type(start) == int
249
    check_name(table)
250
    if fields != None: map(check_name, fields)
251
    map(check_name, conds.keys())
252
    
253
    def cond(entry):
254
        col, value = entry
255
        cond_ = esc_name(db, col)+' '
256
        if value == None: cond_ += 'IS'
257
        else: cond_ += '='
258
        cond_ += ' %s'
259
        return cond_
260
    query = 'SELECT '
261
    if fields == None: query += '*'
262
    else: query += ', '.join([esc_name(db, field) for field in fields])
263
    query += ' FROM '+esc_name(db, table)
264
    
265
    missing = True
266
    if conds != {}:
267
        query += ' WHERE '+' AND '.join(map(cond, conds.iteritems()))
268
        missing = False
269
    if limit != None: query += ' LIMIT '+str(limit); missing = False
270
    if start != None:
271
        if start != 0: query += ' OFFSET '+str(start)
272
        missing = False
273
    if missing: warnings.warn(DbWarning(
274
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
275
    
276
    return run_query(db, query, conds.values(), recover, cacheable)
277

    
278
def insert(db, table, row, returning=None, recover=None, cacheable=True):
279
    '''@param returning str|None An inserted column (such as pkey) to return'''
280
    check_name(table)
281
    cols = row.keys()
282
    map(check_name, cols)
283
    query = 'INSERT INTO '+table
284
    
285
    if row != {}: query += ' ('+', '.join(cols)+') VALUES ('\
286
        +', '.join(['%s']*len(cols))+')'
287
    else: query += ' DEFAULT VALUES'
288
    
289
    if returning != None:
290
        check_name(returning)
291
        query += ' RETURNING '+returning
292
    
293
    return run_query(db, query, row.values(), recover, cacheable)
294

    
295
def last_insert_id(db):
296
    module = util.root_module(db.db)
297
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
298
    elif module == 'MySQLdb': return db.insert_id()
299
    else: return None
300

    
301
def truncate(db, table):
302
    check_name(table)
303
    return run_raw_query(db, 'TRUNCATE '+table+' CASCADE')
304

    
305
##### Database structure queries
306

    
307
def pkey(db, table, recover=None):
308
    '''Assumed to be first column in table'''
309
    check_name(table)
310
    if table not in db.pkeys:
311
        db.pkeys[table] = col_names(run_query(db,
312
            'SELECT * FROM '+table+' LIMIT 0', recover=recover)).next()
313
    return db.pkeys[table]
314

    
315
def index_cols(db, table, index):
316
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
317
    automatically created. When you don't know whether something is a UNIQUE
318
    constraint or a UNIQUE index, use this function.'''
319
    check_name(table)
320
    check_name(index)
321
    lookup = (table, index)
322
    if lookup not in db.index_cols:
323
        module = util.root_module(db.db)
324
        if module == 'psycopg2':
325
            db.index_cols[lookup] = list(values(run_query(db, '''\
326
SELECT attname
327
FROM
328
(
329
        SELECT attnum, attname
330
        FROM pg_index
331
        JOIN pg_class index ON index.oid = indexrelid
332
        JOIN pg_class table_ ON table_.oid = indrelid
333
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
334
        WHERE
335
            table_.relname = %(table)s
336
            AND index.relname = %(index)s
337
    UNION
338
        SELECT attnum, attname
339
        FROM
340
        (
341
            SELECT
342
                indrelid
343
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
344
                    AS indkey
345
            FROM pg_index
346
            JOIN pg_class index ON index.oid = indexrelid
347
            JOIN pg_class table_ ON table_.oid = indrelid
348
            WHERE
349
                table_.relname = %(table)s
350
                AND index.relname = %(index)s
351
        ) s
352
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
353
) s
354
ORDER BY attnum
355
''',
356
                {'table': table, 'index': index})))
357
        else: raise NotImplementedError("Can't list index columns for "+module+
358
            ' database')
359
    return db.index_cols[lookup]
360

    
361
def constraint_cols(db, table, constraint):
362
    check_name(table)
363
    check_name(constraint)
364
    module = util.root_module(db.db)
365
    if module == 'psycopg2':
366
        return list(values(run_query(db, '''\
367
SELECT attname
368
FROM pg_constraint
369
JOIN pg_class ON pg_class.oid = conrelid
370
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
371
WHERE
372
    relname = %(table)s
373
    AND conname = %(constraint)s
374
ORDER BY attnum
375
''',
376
            {'table': table, 'constraint': constraint})))
377
    else: raise NotImplementedError("Can't list constraint columns for "+module+
378
        ' database')
379

    
380
def tables(db):
381
    module = util.root_module(db.db)
382
    if module == 'psycopg2':
383
        return values(run_query(db, "SELECT tablename from pg_tables "
384
            "WHERE schemaname = 'public' ORDER BY tablename"))
385
    elif module == 'MySQLdb': return values(run_query(db, 'SHOW TABLES'))
386
    else: raise NotImplementedError("Can't list tables for "+module+' database')
387

    
388
##### Database management
389

    
390
def empty_db(db):
391
    for table in tables(db): truncate(db, table)
392

    
393
##### Heuristic queries
394

    
395
def try_insert(db, table, row, returning=None):
396
    '''Recovers from errors'''
397
    try: return insert(db, table, row, returning, recover=True)
398
    except Exception, e:
399
        msg = str(e)
400
        match = re.search(r'duplicate key value violates unique constraint '
401
            r'"(([^\W_]+)_[^"]+)"', msg)
402
        if match:
403
            constraint, table = match.groups()
404
            try: cols = index_cols(db, table, constraint)
405
            except NotImplementedError: raise e
406
            else: raise DuplicateKeyException(cols, e)
407
        match = re.search(r'null value in column "(\w+)" violates not-null '
408
            'constraint', msg)
409
        if match: raise NullValueException([match.group(1)], e)
410
        raise # no specific exception raised
411

    
412
def put(db, table, row, pkey, row_ct_ref=None):
413
    '''Recovers from errors.
414
    Only works under PostgreSQL (uses `INSERT ... RETURNING`)'''
415
    try:
416
        cur = try_insert(db, table, row, pkey)
417
        if row_ct_ref != None and cur.rowcount >= 0:
418
            row_ct_ref[0] += cur.rowcount
419
        return value(cur)
420
    except DuplicateKeyException, e:
421
        return value(select(db, table, [pkey],
422
            util.dict_subset_right_join(row, e.cols), recover=True))
423

    
424
def get(db, table, row, pkey, row_ct_ref=None, create=False):
425
    '''Recovers from errors'''
426
    try: return value(select(db, table, [pkey], row, 1, recover=True))
427
    except StopIteration:
428
        if not create: raise
429
        return put(db, table, row, pkey, row_ct_ref) # insert new row
(22-22/33)