Project

General

Profile

1
# Database access
2

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

    
8
import exc
9
import strings
10
import util
11

    
12
##### Exceptions
13

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

    
19
def _add_cursor_info(e, cur): exc.add_msg(e, 'query: '+get_cur_query(cur))
20

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

    
26
class NameException(DbException): pass
27

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

    
33
class DuplicateKeyException(ExceptionWithColumns): pass
34

    
35
class NullValueException(ExceptionWithColumns): pass
36

    
37
class EmptyRowException(DbException): pass
38

    
39
##### Warnings
40

    
41
class DbWarning(UserWarning): pass
42

    
43
##### Input validation
44

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

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

    
57
##### Querying
58

    
59
def run_raw_query(db, query, params=None):
60
    cur = db.cursor()
61
    try: cur.execute(query, params)
62
    except Exception, e:
63
        _add_cursor_info(e, cur)
64
        raise
65
    if run_raw_query.debug:
66
        sys.stderr.write(strings.one_line(get_cur_query(cur))+'\n')
67
    return cur
68

    
69
##### Recoverable querying
70

    
71
def with_savepoint(db, func):
72
    savepoint = 'savepoint_'+str(random.randint(0, sys.maxint)) # must be unique
73
    run_raw_query(db, 'SAVEPOINT '+savepoint)
74
    try: return_val = func()
75
    except:
76
        run_raw_query(db, 'ROLLBACK TO SAVEPOINT '+savepoint)
77
        raise
78
    else:
79
        run_raw_query(db, 'RELEASE SAVEPOINT '+savepoint)
80
        return return_val
81

    
82
def run_query(db, query, params=None, recover=None):
83
    if recover == None: recover = False
84
    
85
    def run(): return run_raw_query(db, query, params)
86
    if recover: return with_savepoint(db, run)
87
    else: return run()
88

    
89
##### Result retrieval
90

    
91
def col_names(cur): return (col[0] for col in cur.description)
92

    
93
def rows(cur): return iter(lambda: cur.fetchone(), None)
94

    
95
def row(cur): return rows(cur).next()
96

    
97
def value(cur): return row(cur)[0]
98

    
99
def values(cur): return iter(lambda: value(cur), None)
100

    
101
def value_or_none(cur):
102
    try: return value(cur)
103
    except StopIteration: return None
104

    
105
##### Basic queries
106

    
107
def select(db, table, fields=None, conds=None, limit=None, start=None,
108
    recover=None):
109
    '''@param fields Use None to select all fields in the table'''
110
    if conds == None: conds = {}
111
    assert limit == None or type(limit) == int
112
    assert start == None or type(start) == int
113
    check_name(table)
114
    if fields != None: map(check_name, fields)
115
    map(check_name, conds.keys())
116
    
117
    def cond(entry):
118
        col, value = entry
119
        cond_ = esc_name(db, col)+' '
120
        if value == None: cond_ += 'IS'
121
        else: cond_ += '='
122
        cond_ += ' %s'
123
        return cond_
124
    query = 'SELECT '
125
    if fields == None: query += '*'
126
    else: query += ', '.join([esc_name(db, field) for field in fields])
127
    query += ' FROM '+esc_name(db, table)
128
    
129
    missing = True
130
    if conds != {}:
131
        query += ' WHERE '+' AND '.join(map(cond, conds.iteritems()))
132
        missing = False
133
    if limit != None: query += ' LIMIT '+str(limit); missing = False
134
    if start != None:
135
        if start != 0: query += ' OFFSET '+str(start)
136
        missing = False
137
    if missing: warnings.warn(DbWarning(
138
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
139
    
140
    return run_query(db, query, conds.values(), recover)
141

    
142
def insert(db, table, row, returning=None, recover=None):
143
    '''@param returning str|None An inserted column (such as pkey) to return'''
144
    check_name(table)
145
    cols = row.keys()
146
    map(check_name, cols)
147
    query = 'INSERT INTO '+table
148
    
149
    if row != {}: query += ' ('+', '.join(cols)+') VALUES ('\
150
        +', '.join(['%s']*len(cols))+')'
151
    else: query += ' DEFAULT VALUES'
152
    
153
    if returning != None:
154
        check_name(returning)
155
        query += ' RETURNING '+returning
156
    
157
    return run_query(db, query, row.values(), recover)
158

    
159
def last_insert_id(db):
160
    module = util.root_module(db)
161
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
162
    elif module == 'MySQLdb': return db.insert_id()
163
    else: return None
164

    
165
def truncate(db, table):
166
    check_name(table)
167
    return run_raw_query(db, 'TRUNCATE '+table+' CASCADE')
168

    
169
##### Database structure queries
170

    
171
def pkey(db, cache, table, recover=None):
172
    '''Assumed to be first column in table'''
173
    check_name(table)
174
    if table not in cache:
175
        cache[table] = col_names(run_query(db,
176
            'SELECT * FROM '+table+' LIMIT 0', recover=recover)).next()
177
    return cache[table]
178

    
179
def index_cols(db, table, index):
180
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
181
    automatically created. When you don't know whether something is a UNIQUE
182
    constraint or a UNIQUE index, use this function.'''
183
    check_name(table)
184
    check_name(index)
185
    module = util.root_module(db)
186
    if module == 'psycopg2':
187
        return list(values(run_query(db, '''\
188
SELECT attname
189
FROM
190
(
191
        SELECT attnum, attname
192
        FROM pg_index
193
        JOIN pg_class index ON index.oid = indexrelid
194
        JOIN pg_class table_ ON table_.oid = indrelid
195
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
196
        WHERE
197
            table_.relname = %(table)s
198
            AND index.relname = %(index)s
199
    UNION
200
        SELECT attnum, attname
201
        FROM
202
        (
203
            SELECT
204
                indrelid
205
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
206
                    AS indkey
207
            FROM pg_index
208
            JOIN pg_class index ON index.oid = indexrelid
209
            JOIN pg_class table_ ON table_.oid = indrelid
210
            WHERE
211
                table_.relname = %(table)s
212
                AND index.relname = %(index)s
213
        ) s
214
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
215
) s
216
ORDER BY attnum
217
''',
218
            {'table': table, 'index': index})))
219
    else: raise NotImplementedError("Can't list index columns for "+module+
220
        ' database')
221

    
222
def constraint_cols(db, table, constraint):
223
    check_name(table)
224
    check_name(constraint)
225
    module = util.root_module(db)
226
    if module == 'psycopg2':
227
        return list(values(run_query(db, '''\
228
SELECT attname
229
FROM pg_constraint
230
JOIN pg_class ON pg_class.oid = conrelid
231
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
232
WHERE
233
    relname = %(table)s
234
    AND conname = %(constraint)s
235
ORDER BY attnum
236
''',
237
            {'table': table, 'constraint': constraint})))
238
    else: raise NotImplementedError("Can't list constraint columns for "+module+
239
        ' database')
240

    
241
def tables(db):
242
    module = util.root_module(db)
243
    if module == 'psycopg2':
244
        return values(run_query(db, "SELECT tablename from pg_tables "
245
            "WHERE schemaname = 'public' ORDER BY tablename"))
246
    elif module == 'MySQLdb': return values(run_query(db, 'SHOW TABLES'))
247
    else: raise NotImplementedError("Can't list tables for "+module+' database')
248

    
249
##### Database management
250

    
251
def empty_db(db):
252
    for table in tables(db): truncate(db, table)
253

    
254
##### Heuristic queries
255

    
256
def try_insert(db, table, row, returning=None):
257
    '''Recovers from errors'''
258
    try: return insert(db, table, row, returning, recover=True)
259
    except Exception, e:
260
        msg = str(e)
261
        match = re.search(r'duplicate key value violates unique constraint '
262
            r'"(([^\W_]+)_[^"]+)"', msg)
263
        if match:
264
            constraint, table = match.groups()
265
            try: cols = index_cols(db, table, constraint)
266
            except NotImplementedError: raise e
267
            else: raise DuplicateKeyException(cols, e)
268
        match = re.search(r'null value in column "(\w+)" violates not-null '
269
            'constraint', msg)
270
        if match: raise NullValueException([match.group(1)], e)
271
        raise # no specific exception raised
272

    
273
def put(db, table, row, pkey, row_ct_ref=None):
274
    '''Recovers from errors.
275
    Only works under PostgreSQL (uses `INSERT ... RETURNING`)'''
276
    try:
277
        cur = try_insert(db, table, row, pkey)
278
        if row_ct_ref != None and cur.rowcount >= 0:
279
            row_ct_ref[0] += cur.rowcount
280
        return value(cur)
281
    except DuplicateKeyException, e:
282
        return value(select(db, table, [pkey],
283
            util.dict_subset_right_join(row, e.cols), recover=True))
284

    
285
def get(db, table, row, pkey, row_ct_ref=None, create=False):
286
    '''Recovers from errors'''
287
    try: return value(select(db, table, [pkey], row, 1, recover=True))
288
    except StopIteration:
289
        if not create: raise
290
        return put(db, table, row, pkey, row_ct_ref) # insert new row
291

    
292
##### Database connections
293

    
294
db_engines = {
295
    'MySQL': ('MySQLdb', {'password': 'passwd', 'database': 'db'}),
296
    'PostgreSQL': ('psycopg2', {}),
297
}
298

    
299
DatabaseErrors_set = set([DbException])
300
DatabaseErrors = tuple(DatabaseErrors_set)
301

    
302
def _add_module(module):
303
    DatabaseErrors_set.add(module.DatabaseError)
304
    global DatabaseErrors
305
    DatabaseErrors = tuple(DatabaseErrors_set)
306

    
307
def connect(db_config, serializable=True):
308
    db_config = db_config.copy() # don't modify input!
309
    module_name, mappings = db_engines[db_config.pop('engine')]
310
    module = __import__(module_name)
311
    _add_module(module)
312
    for orig, new in mappings.iteritems():
313
        try: util.rename_key(db_config, orig, new)
314
        except KeyError: pass
315
    db = module.connect(**db_config)
316
    if serializable:
317
        run_raw_query(db, 'SET TRANSACTION ISOLATION LEVEL SERIALIZABLE')
318
    return db
319

    
320
def db_config_str(db_config):
321
    return db_config['engine']+' database '+db_config['database']
(13-13/24)