Project

General

Profile

1
# Database access
2

    
3
import copy
4
import re
5
import sys
6
import warnings
7

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

    
15
##### Exceptions
16

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

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

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

    
29
class NameException(DbException): pass
30

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

    
36
class DuplicateKeyException(ExceptionWithColumns): pass
37

    
38
class NullValueException(ExceptionWithColumns): pass
39

    
40
class EmptyRowException(DbException): pass
41

    
42
##### Warnings
43

    
44
class DbWarning(UserWarning): pass
45

    
46
##### Input validation
47

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

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

    
60
##### Database connections
61

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

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

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

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

    
78
class DbConn:
79
    def __init__(self, db_config, serializable=True, debug=False):
80
        self.db_config = db_config
81
        self.serializable = serializable
82
        self.debug = debug
83
        
84
        self.__db = None
85
        self.pkeys = {}
86
        self.index_cols = {}
87
        self.query_results = {}
88
    
89
    def __getattr__(self, name):
90
        if name == '__dict__': raise Exception('getting __dict__')
91
        if name == 'db': return self._db()
92
        else: raise AttributeError()
93
    
94
    def __getstate__(self):
95
        state = copy.copy(self.__dict__) # shallow copy
96
        state['_DbConn__db'] = None # don't pickle the connection
97
        return state
98
    
99
    def _db(self):
100
        if self.__db == None:
101
            # Process db_config
102
            db_config = self.db_config.copy() # don't modify input!
103
            module_name, mappings = db_engines[db_config.pop('engine')]
104
            module = __import__(module_name)
105
            _add_module(module)
106
            for orig, new in mappings.iteritems():
107
                try: util.rename_key(db_config, orig, new)
108
                except KeyError: pass
109
            
110
            # Connect
111
            self.__db = module.connect(**db_config)
112
            
113
            # Configure connection
114
            if self.serializable: run_raw_query(self,
115
                'SET TRANSACTION ISOLATION LEVEL SERIALIZABLE')
116
        
117
        return self.__db
118
    
119
    class DbCursor(Proxy):
120
        def __init__(self, outer):
121
            Proxy.__init__(self, outer.db.cursor())
122
            self.outer = outer
123
            self.result = []
124
        
125
        def fetchone(self):
126
            row = self.inner.fetchone()
127
            if row == None: # fetched all rows
128
                self.outer.query_results[self.inner.query] = self.result
129
            else: self.result.append(row)
130
            return row
131
    
132
    class CacheCursor:
133
        def __init__(self, result): self.iter = iter(result)
134
        
135
        def fetchone(self):
136
            try: return self.iter.next()
137
            except StopIteration: return None
138
    
139
    def run_query(self, query, params=None):
140
        cur = self.DbCursor(self)
141
        query = cur.mogrify(query, params)
142
        try: return self.CacheCursor(self.query_results[query])
143
        except KeyError:
144
            try: cur.execute(query)
145
            except Exception, e:
146
                _add_cursor_info(e, cur)
147
                raise
148
            if self.debug:
149
                sys.stderr.write(strings.one_line(get_cur_query(cur))+'\n')
150
            return cur
151

    
152
connect = DbConn
153

    
154
##### Querying
155

    
156
def run_raw_query(db, query, params=None): return db.run_query(query, params)
157

    
158
##### Recoverable querying
159

    
160
def with_savepoint(db, func):
161
    savepoint = 'savepoint_'+str(rand.rand_int()) # must be unique
162
    run_raw_query(db, 'SAVEPOINT '+savepoint)
163
    try: return_val = func()
164
    except:
165
        run_raw_query(db, 'ROLLBACK TO SAVEPOINT '+savepoint)
166
        raise
167
    else:
168
        run_raw_query(db, 'RELEASE SAVEPOINT '+savepoint)
169
        return return_val
170

    
171
def run_query(db, query, params=None, recover=None):
172
    if recover == None: recover = False
173
    
174
    def run(): return run_raw_query(db, query, params)
175
    if recover: return with_savepoint(db, run)
176
    else: return run()
177

    
178
##### Result retrieval
179

    
180
def col_names(cur): return (col[0] for col in cur.description)
181

    
182
def rows(cur): return iter(lambda: cur.fetchone(), None)
183

    
184
def next_row(cur): return rows(cur).next()
185

    
186
def row(cur):
187
    row_iter = rows(cur)
188
    row_ = row_iter.next()
189
    iters.consume_iter(row_iter) # fetch all rows so result will be cached
190
    return row_
191

    
192
def next_value(cur): return next_row(cur)[0]
193

    
194
def value(cur): return row(cur)[0]
195

    
196
def values(cur): return iters.func_iter(lambda: next_value(cur))
197

    
198
def value_or_none(cur):
199
    try: return value(cur)
200
    except StopIteration: return None
201

    
202
##### Basic queries
203

    
204
def select(db, table, fields=None, conds=None, limit=None, start=None,
205
    recover=None):
206
    '''@param fields Use None to select all fields in the table'''
207
    if conds == None: conds = {}
208
    assert limit == None or type(limit) == int
209
    assert start == None or type(start) == int
210
    check_name(table)
211
    if fields != None: map(check_name, fields)
212
    map(check_name, conds.keys())
213
    
214
    def cond(entry):
215
        col, value = entry
216
        cond_ = esc_name(db, col)+' '
217
        if value == None: cond_ += 'IS'
218
        else: cond_ += '='
219
        cond_ += ' %s'
220
        return cond_
221
    query = 'SELECT '
222
    if fields == None: query += '*'
223
    else: query += ', '.join([esc_name(db, field) for field in fields])
224
    query += ' FROM '+esc_name(db, table)
225
    
226
    missing = True
227
    if conds != {}:
228
        query += ' WHERE '+' AND '.join(map(cond, conds.iteritems()))
229
        missing = False
230
    if limit != None: query += ' LIMIT '+str(limit); missing = False
231
    if start != None:
232
        if start != 0: query += ' OFFSET '+str(start)
233
        missing = False
234
    if missing: warnings.warn(DbWarning(
235
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
236
    
237
    return run_query(db, query, conds.values(), recover)
238

    
239
def insert(db, table, row, returning=None, recover=None):
240
    '''@param returning str|None An inserted column (such as pkey) to return'''
241
    check_name(table)
242
    cols = row.keys()
243
    map(check_name, cols)
244
    query = 'INSERT INTO '+table
245
    
246
    if row != {}: query += ' ('+', '.join(cols)+') VALUES ('\
247
        +', '.join(['%s']*len(cols))+')'
248
    else: query += ' DEFAULT VALUES'
249
    
250
    if returning != None:
251
        check_name(returning)
252
        query += ' RETURNING '+returning
253
    
254
    return run_query(db, query, row.values(), recover)
255

    
256
def last_insert_id(db):
257
    module = util.root_module(db.db)
258
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
259
    elif module == 'MySQLdb': return db.insert_id()
260
    else: return None
261

    
262
def truncate(db, table):
263
    check_name(table)
264
    return run_raw_query(db, 'TRUNCATE '+table+' CASCADE')
265

    
266
##### Database structure queries
267

    
268
def pkey(db, table, recover=None):
269
    '''Assumed to be first column in table'''
270
    check_name(table)
271
    if table not in db.pkeys:
272
        db.pkeys[table] = col_names(run_query(db,
273
            'SELECT * FROM '+table+' LIMIT 0', recover=recover)).next()
274
    return db.pkeys[table]
275

    
276
def index_cols(db, table, index):
277
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
278
    automatically created. When you don't know whether something is a UNIQUE
279
    constraint or a UNIQUE index, use this function.'''
280
    check_name(table)
281
    check_name(index)
282
    lookup = (table, index)
283
    if lookup not in db.index_cols:
284
        module = util.root_module(db.db)
285
        if module == 'psycopg2':
286
            db.index_cols[lookup] = list(values(run_query(db, '''\
287
SELECT attname
288
FROM
289
(
290
        SELECT attnum, attname
291
        FROM pg_index
292
        JOIN pg_class index ON index.oid = indexrelid
293
        JOIN pg_class table_ ON table_.oid = indrelid
294
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
295
        WHERE
296
            table_.relname = %(table)s
297
            AND index.relname = %(index)s
298
    UNION
299
        SELECT attnum, attname
300
        FROM
301
        (
302
            SELECT
303
                indrelid
304
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
305
                    AS indkey
306
            FROM pg_index
307
            JOIN pg_class index ON index.oid = indexrelid
308
            JOIN pg_class table_ ON table_.oid = indrelid
309
            WHERE
310
                table_.relname = %(table)s
311
                AND index.relname = %(index)s
312
        ) s
313
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
314
) s
315
ORDER BY attnum
316
''',
317
                {'table': table, 'index': index})))
318
        else: raise NotImplementedError("Can't list index columns for "+module+
319
            ' database')
320
    return db.index_cols[lookup]
321

    
322
def constraint_cols(db, table, constraint):
323
    check_name(table)
324
    check_name(constraint)
325
    module = util.root_module(db.db)
326
    if module == 'psycopg2':
327
        return list(values(run_query(db, '''\
328
SELECT attname
329
FROM pg_constraint
330
JOIN pg_class ON pg_class.oid = conrelid
331
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
332
WHERE
333
    relname = %(table)s
334
    AND conname = %(constraint)s
335
ORDER BY attnum
336
''',
337
            {'table': table, 'constraint': constraint})))
338
    else: raise NotImplementedError("Can't list constraint columns for "+module+
339
        ' database')
340

    
341
def tables(db):
342
    module = util.root_module(db.db)
343
    if module == 'psycopg2':
344
        return values(run_query(db, "SELECT tablename from pg_tables "
345
            "WHERE schemaname = 'public' ORDER BY tablename"))
346
    elif module == 'MySQLdb': return values(run_query(db, 'SHOW TABLES'))
347
    else: raise NotImplementedError("Can't list tables for "+module+' database')
348

    
349
##### Database management
350

    
351
def empty_db(db):
352
    for table in tables(db): truncate(db, table)
353

    
354
##### Heuristic queries
355

    
356
def try_insert(db, table, row, returning=None):
357
    '''Recovers from errors'''
358
    try: return insert(db, table, row, returning, recover=True)
359
    except Exception, e:
360
        msg = str(e)
361
        match = re.search(r'duplicate key value violates unique constraint '
362
            r'"(([^\W_]+)_[^"]+)"', msg)
363
        if match:
364
            constraint, table = match.groups()
365
            try: cols = index_cols(db, table, constraint)
366
            except NotImplementedError: raise e
367
            else: raise DuplicateKeyException(cols, e)
368
        match = re.search(r'null value in column "(\w+)" violates not-null '
369
            'constraint', msg)
370
        if match: raise NullValueException([match.group(1)], e)
371
        raise # no specific exception raised
372

    
373
def put(db, table, row, pkey, row_ct_ref=None):
374
    '''Recovers from errors.
375
    Only works under PostgreSQL (uses `INSERT ... RETURNING`)'''
376
    try:
377
        cur = try_insert(db, table, row, pkey)
378
        if row_ct_ref != None and cur.rowcount >= 0:
379
            row_ct_ref[0] += cur.rowcount
380
        return value(cur)
381
    except DuplicateKeyException, e:
382
        return value(select(db, table, [pkey],
383
            util.dict_subset_right_join(row, e.cols), recover=True))
384

    
385
def get(db, table, row, pkey, row_ct_ref=None, create=False):
386
    '''Recovers from errors'''
387
    try: return value(select(db, table, [pkey], row, 1, recover=True))
388
    except StopIteration:
389
        if not create: raise
390
        return put(db, table, row, pkey, row_ct_ref) # insert new row
(22-22/33)