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
            return_value = self.inner.execute(query, params)
133
            self.query = get_cur_query(self.inner)
134
            return return_value
135
        
136
        def fetchone(self):
137
            row = self.inner.fetchone()
138
            if row != None: self.result.append(row)
139
            # otherwise, fetched all rows
140
            elif self.query_results != None: # is caching
141
                assert self.query_lookup != None
142
                self.query_results[self.query_lookup] = (self.query,
143
                    self.result)
144
            return row
145
    
146
    class CacheCursor:
147
        def __init__(self, query, result):
148
            self.query = query
149
            self.rowcount = len(result)
150
            self.iter = iter(result)
151
        
152
        def fetchone(self):
153
            try: return self.iter.next()
154
            except StopIteration: return None
155
    
156
    def run_query(self, query, params=None, cacheable=False):
157
        query_lookup = _query_lookup(query, params)
158
        try: actual_query, result = self.query_results[query_lookup]
159
        except KeyError:
160
            cur = self.DbCursor(self, cacheable)
161
            try: cur.execute(query, params)
162
            except Exception, e:
163
                _add_cursor_info(e, cur)
164
                raise
165
            if self.log_debug != log_debug_none: # only compute msg if needed
166
                self.log_debug(strings.one_line(get_cur_query(cur)))
167
            return cur
168
        else: return self.CacheCursor(actual_query, result)
169

    
170
connect = DbConn
171

    
172
##### Querying
173

    
174
def run_raw_query(db, *args, **kw_args):
175
    '''For args, see DbConn.run_query()'''
176
    return db.run_query(*args, **kw_args)
177

    
178
##### Recoverable querying
179

    
180
def with_savepoint(db, func):
181
    savepoint = 'savepoint_'+str(rand.rand_int()) # must be unique
182
    run_raw_query(db, 'SAVEPOINT '+savepoint)
183
    try: return_val = func()
184
    except:
185
        run_raw_query(db, 'ROLLBACK TO SAVEPOINT '+savepoint)
186
        raise
187
    else:
188
        run_raw_query(db, 'RELEASE SAVEPOINT '+savepoint)
189
        return return_val
190

    
191
def run_query(db, query, params=None, recover=None, cacheable=False):
192
    if recover == None: recover = False
193
    
194
    def run(): return run_raw_query(db, query, params, cacheable)
195
    if recover: return with_savepoint(db, run)
196
    else: return run()
197

    
198
##### Result retrieval
199

    
200
def col_names(cur): return (col[0] for col in cur.description)
201

    
202
def rows(cur): return iter(lambda: cur.fetchone(), None)
203

    
204
def next_row(cur): return rows(cur).next()
205

    
206
def row(cur):
207
    row_iter = rows(cur)
208
    row_ = row_iter.next()
209
    iters.consume_iter(row_iter) # fetch all rows so result will be cached
210
    return row_
211

    
212
def next_value(cur): return next_row(cur)[0]
213

    
214
def value(cur): return row(cur)[0]
215

    
216
def values(cur): return iters.func_iter(lambda: next_value(cur))
217

    
218
def value_or_none(cur):
219
    try: return value(cur)
220
    except StopIteration: return None
221

    
222
##### Basic queries
223

    
224
def select(db, table, fields=None, conds=None, limit=None, start=None,
225
    recover=None, cacheable=True):
226
    '''@param fields Use None to select all fields in the table'''
227
    if conds == None: conds = {}
228
    assert limit == None or type(limit) == int
229
    assert start == None or type(start) == int
230
    check_name(table)
231
    if fields != None: map(check_name, fields)
232
    map(check_name, conds.keys())
233
    
234
    def cond(entry):
235
        col, value = entry
236
        cond_ = esc_name(db, col)+' '
237
        if value == None: cond_ += 'IS'
238
        else: cond_ += '='
239
        cond_ += ' %s'
240
        return cond_
241
    query = 'SELECT '
242
    if fields == None: query += '*'
243
    else: query += ', '.join([esc_name(db, field) for field in fields])
244
    query += ' FROM '+esc_name(db, table)
245
    
246
    missing = True
247
    if conds != {}:
248
        query += ' WHERE '+' AND '.join(map(cond, conds.iteritems()))
249
        missing = False
250
    if limit != None: query += ' LIMIT '+str(limit); missing = False
251
    if start != None:
252
        if start != 0: query += ' OFFSET '+str(start)
253
        missing = False
254
    if missing: warnings.warn(DbWarning(
255
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
256
    
257
    return run_query(db, query, conds.values(), cacheable, recover)
258

    
259
def insert(db, table, row, returning=None, recover=None):
260
    '''@param returning str|None An inserted column (such as pkey) to return'''
261
    check_name(table)
262
    cols = row.keys()
263
    map(check_name, cols)
264
    query = 'INSERT INTO '+table
265
    
266
    if row != {}: query += ' ('+', '.join(cols)+') VALUES ('\
267
        +', '.join(['%s']*len(cols))+')'
268
    else: query += ' DEFAULT VALUES'
269
    
270
    if returning != None:
271
        check_name(returning)
272
        query += ' RETURNING '+returning
273
    
274
    return run_query(db, query, row.values(), recover)
275

    
276
def last_insert_id(db):
277
    module = util.root_module(db.db)
278
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
279
    elif module == 'MySQLdb': return db.insert_id()
280
    else: return None
281

    
282
def truncate(db, table):
283
    check_name(table)
284
    return run_raw_query(db, 'TRUNCATE '+table+' CASCADE')
285

    
286
##### Database structure queries
287

    
288
def pkey(db, table, recover=None):
289
    '''Assumed to be first column in table'''
290
    check_name(table)
291
    if table not in db.pkeys:
292
        db.pkeys[table] = col_names(run_query(db,
293
            'SELECT * FROM '+table+' LIMIT 0', recover=recover)).next()
294
    return db.pkeys[table]
295

    
296
def index_cols(db, table, index):
297
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
298
    automatically created. When you don't know whether something is a UNIQUE
299
    constraint or a UNIQUE index, use this function.'''
300
    check_name(table)
301
    check_name(index)
302
    lookup = (table, index)
303
    if lookup not in db.index_cols:
304
        module = util.root_module(db.db)
305
        if module == 'psycopg2':
306
            db.index_cols[lookup] = list(values(run_query(db, '''\
307
SELECT attname
308
FROM
309
(
310
        SELECT attnum, attname
311
        FROM pg_index
312
        JOIN pg_class index ON index.oid = indexrelid
313
        JOIN pg_class table_ ON table_.oid = indrelid
314
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
315
        WHERE
316
            table_.relname = %(table)s
317
            AND index.relname = %(index)s
318
    UNION
319
        SELECT attnum, attname
320
        FROM
321
        (
322
            SELECT
323
                indrelid
324
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
325
                    AS indkey
326
            FROM pg_index
327
            JOIN pg_class index ON index.oid = indexrelid
328
            JOIN pg_class table_ ON table_.oid = indrelid
329
            WHERE
330
                table_.relname = %(table)s
331
                AND index.relname = %(index)s
332
        ) s
333
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
334
) s
335
ORDER BY attnum
336
''',
337
                {'table': table, 'index': index})))
338
        else: raise NotImplementedError("Can't list index columns for "+module+
339
            ' database')
340
    return db.index_cols[lookup]
341

    
342
def constraint_cols(db, table, constraint):
343
    check_name(table)
344
    check_name(constraint)
345
    module = util.root_module(db.db)
346
    if module == 'psycopg2':
347
        return list(values(run_query(db, '''\
348
SELECT attname
349
FROM pg_constraint
350
JOIN pg_class ON pg_class.oid = conrelid
351
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
352
WHERE
353
    relname = %(table)s
354
    AND conname = %(constraint)s
355
ORDER BY attnum
356
''',
357
            {'table': table, 'constraint': constraint})))
358
    else: raise NotImplementedError("Can't list constraint columns for "+module+
359
        ' database')
360

    
361
def tables(db):
362
    module = util.root_module(db.db)
363
    if module == 'psycopg2':
364
        return values(run_query(db, "SELECT tablename from pg_tables "
365
            "WHERE schemaname = 'public' ORDER BY tablename"))
366
    elif module == 'MySQLdb': return values(run_query(db, 'SHOW TABLES'))
367
    else: raise NotImplementedError("Can't list tables for "+module+' database')
368

    
369
##### Database management
370

    
371
def empty_db(db):
372
    for table in tables(db): truncate(db, table)
373

    
374
##### Heuristic queries
375

    
376
def try_insert(db, table, row, returning=None):
377
    '''Recovers from errors'''
378
    try: return insert(db, table, row, returning, recover=True)
379
    except Exception, e:
380
        msg = str(e)
381
        match = re.search(r'duplicate key value violates unique constraint '
382
            r'"(([^\W_]+)_[^"]+)"', msg)
383
        if match:
384
            constraint, table = match.groups()
385
            try: cols = index_cols(db, table, constraint)
386
            except NotImplementedError: raise e
387
            else: raise DuplicateKeyException(cols, e)
388
        match = re.search(r'null value in column "(\w+)" violates not-null '
389
            'constraint', msg)
390
        if match: raise NullValueException([match.group(1)], e)
391
        raise # no specific exception raised
392

    
393
def put(db, table, row, pkey, row_ct_ref=None):
394
    '''Recovers from errors.
395
    Only works under PostgreSQL (uses `INSERT ... RETURNING`)'''
396
    try:
397
        cur = try_insert(db, table, row, pkey)
398
        if row_ct_ref != None and cur.rowcount >= 0:
399
            row_ct_ref[0] += cur.rowcount
400
        return value(cur)
401
    except DuplicateKeyException, e:
402
        return value(select(db, table, [pkey],
403
            util.dict_subset_right_join(row, e.cols), recover=True))
404

    
405
def get(db, table, row, pkey, row_ct_ref=None, create=False):
406
    '''Recovers from errors'''
407
    try: return value(select(db, table, [pkey], row, 1, recover=True))
408
    except StopIteration:
409
        if not create: raise
410
        return put(db, table, row, pkey, row_ct_ref) # insert new row
(22-22/33)