Project

General

Profile

1
# Database access
2

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

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

    
151
connect = DbConn
152

    
153
##### Querying
154

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

    
157
##### Recoverable querying
158

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

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

    
177
##### Result retrieval
178

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

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

    
183
def row(cur): return rows(cur).next()
184

    
185
def value(cur): return row(cur)[0]
186

    
187
def values(cur): return iter(lambda: value(cur), None)
188

    
189
def value_or_none(cur):
190
    try: return value(cur)
191
    except StopIteration: return None
192

    
193
##### Basic queries
194

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

    
230
def insert(db, table, row, returning=None, recover=None):
231
    '''@param returning str|None An inserted column (such as pkey) to return'''
232
    check_name(table)
233
    cols = row.keys()
234
    map(check_name, cols)
235
    query = 'INSERT INTO '+table
236
    
237
    if row != {}: query += ' ('+', '.join(cols)+') VALUES ('\
238
        +', '.join(['%s']*len(cols))+')'
239
    else: query += ' DEFAULT VALUES'
240
    
241
    if returning != None:
242
        check_name(returning)
243
        query += ' RETURNING '+returning
244
    
245
    return run_query(db, query, row.values(), recover)
246

    
247
def last_insert_id(db):
248
    module = util.root_module(db.db)
249
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
250
    elif module == 'MySQLdb': return db.insert_id()
251
    else: return None
252

    
253
def truncate(db, table):
254
    check_name(table)
255
    return run_raw_query(db, 'TRUNCATE '+table+' CASCADE')
256

    
257
##### Database structure queries
258

    
259
def pkey(db, table, recover=None):
260
    '''Assumed to be first column in table'''
261
    check_name(table)
262
    if table not in db.pkeys:
263
        db.pkeys[table] = col_names(run_query(db,
264
            'SELECT * FROM '+table+' LIMIT 0', recover=recover)).next()
265
    return db.pkeys[table]
266

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

    
313
def constraint_cols(db, table, constraint):
314
    check_name(table)
315
    check_name(constraint)
316
    module = util.root_module(db.db)
317
    if module == 'psycopg2':
318
        return list(values(run_query(db, '''\
319
SELECT attname
320
FROM pg_constraint
321
JOIN pg_class ON pg_class.oid = conrelid
322
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
323
WHERE
324
    relname = %(table)s
325
    AND conname = %(constraint)s
326
ORDER BY attnum
327
''',
328
            {'table': table, 'constraint': constraint})))
329
    else: raise NotImplementedError("Can't list constraint columns for "+module+
330
        ' database')
331

    
332
def tables(db):
333
    module = util.root_module(db.db)
334
    if module == 'psycopg2':
335
        return values(run_query(db, "SELECT tablename from pg_tables "
336
            "WHERE schemaname = 'public' ORDER BY tablename"))
337
    elif module == 'MySQLdb': return values(run_query(db, 'SHOW TABLES'))
338
    else: raise NotImplementedError("Can't list tables for "+module+' database')
339

    
340
##### Database management
341

    
342
def empty_db(db):
343
    for table in tables(db): truncate(db, table)
344

    
345
##### Heuristic queries
346

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

    
364
def put(db, table, row, pkey, row_ct_ref=None):
365
    '''Recovers from errors.
366
    Only works under PostgreSQL (uses `INSERT ... RETURNING`)'''
367
    try:
368
        cur = try_insert(db, table, row, pkey)
369
        if row_ct_ref != None and cur.rowcount >= 0:
370
            row_ct_ref[0] += cur.rowcount
371
        return value(cur)
372
    except DuplicateKeyException, e:
373
        return value(select(db, table, [pkey],
374
            util.dict_subset_right_join(row, e.cols), recover=True))
375

    
376
def get(db, table, row, pkey, row_ct_ref=None, create=False):
377
    '''Recovers from errors'''
378
    try: return value(select(db, table, [pkey], row, 1, recover=True))
379
    except StopIteration:
380
        if not create: raise
381
        return put(db, table, row, pkey, row_ct_ref) # insert new row
(22-22/33)