1
|
# Database access
|
2
|
|
3
|
import copy
|
4
|
import re
|
5
|
import warnings
|
6
|
|
7
|
import exc
|
8
|
import dicts
|
9
|
import iters
|
10
|
import lists
|
11
|
from Proxy import Proxy
|
12
|
import rand
|
13
|
import strings
|
14
|
import util
|
15
|
|
16
|
##### Exceptions
|
17
|
|
18
|
def get_cur_query(cur):
|
19
|
if hasattr(cur, 'query'): return cur.query
|
20
|
elif hasattr(cur, '_last_executed'): return cur._last_executed
|
21
|
else: return None
|
22
|
|
23
|
def _add_cursor_info(e, cur): exc.add_msg(e, 'query: '+get_cur_query(cur))
|
24
|
|
25
|
class DbException(exc.ExceptionWithCause):
|
26
|
def __init__(self, msg, cause=None, cur=None):
|
27
|
exc.ExceptionWithCause.__init__(self, msg, cause)
|
28
|
if cur != None: _add_cursor_info(self, cur)
|
29
|
|
30
|
class NameException(DbException): pass
|
31
|
|
32
|
class ExceptionWithColumns(DbException):
|
33
|
def __init__(self, cols, cause=None):
|
34
|
DbException.__init__(self, 'columns: ' + ', '.join(cols), cause)
|
35
|
self.cols = cols
|
36
|
|
37
|
class DuplicateKeyException(ExceptionWithColumns): pass
|
38
|
|
39
|
class NullValueException(ExceptionWithColumns): pass
|
40
|
|
41
|
class EmptyRowException(DbException): pass
|
42
|
|
43
|
##### Warnings
|
44
|
|
45
|
class DbWarning(UserWarning): pass
|
46
|
|
47
|
##### Result retrieval
|
48
|
|
49
|
def col_names(cur): return (col[0] for col in cur.description)
|
50
|
|
51
|
def rows(cur): return iter(lambda: cur.fetchone(), None)
|
52
|
|
53
|
def consume_rows(cur):
|
54
|
'''Used to fetch all rows so result will be cached'''
|
55
|
iters.consume_iter(rows(cur))
|
56
|
|
57
|
def next_row(cur): return rows(cur).next()
|
58
|
|
59
|
def row(cur):
|
60
|
row_ = next_row(cur)
|
61
|
consume_rows(cur)
|
62
|
return row_
|
63
|
|
64
|
def next_value(cur): return next_row(cur)[0]
|
65
|
|
66
|
def value(cur): return row(cur)[0]
|
67
|
|
68
|
def values(cur): return iters.func_iter(lambda: next_value(cur))
|
69
|
|
70
|
def value_or_none(cur):
|
71
|
try: return value(cur)
|
72
|
except StopIteration: return None
|
73
|
|
74
|
##### Input validation
|
75
|
|
76
|
def clean_name(name): return re.sub(r'\W', r'', name)
|
77
|
|
78
|
def check_name(name):
|
79
|
if re.search(r'\W', name) != None: raise NameException('Name "'+name
|
80
|
+'" may contain only alphanumeric characters and _')
|
81
|
|
82
|
def esc_name_by_module(module, name, ignore_case=False):
|
83
|
if module == 'psycopg2':
|
84
|
if ignore_case:
|
85
|
# Don't enclose in quotes because this disables case-insensitivity
|
86
|
check_name(name)
|
87
|
return name
|
88
|
else: quote = '"'
|
89
|
elif module == 'MySQLdb': quote = '`'
|
90
|
else: raise NotImplementedError("Can't escape name for "+module+' database')
|
91
|
return quote + name.replace(quote, '') + quote
|
92
|
|
93
|
def esc_name_by_engine(engine, name, **kw_args):
|
94
|
return esc_name_by_module(db_engines[engine][0], name, **kw_args)
|
95
|
|
96
|
def esc_name(db, name, **kw_args):
|
97
|
return esc_name_by_module(util.root_module(db.db), name, **kw_args)
|
98
|
|
99
|
def qual_name(db, schema, table):
|
100
|
def esc_name_(name): return esc_name(db, name)
|
101
|
table = esc_name_(table)
|
102
|
if schema != None: return esc_name_(schema)+'.'+table
|
103
|
else: return table
|
104
|
|
105
|
##### Database connections
|
106
|
|
107
|
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
|
108
|
|
109
|
db_engines = {
|
110
|
'MySQL': ('MySQLdb', {'password': 'passwd', 'database': 'db'}),
|
111
|
'PostgreSQL': ('psycopg2', {}),
|
112
|
}
|
113
|
|
114
|
DatabaseErrors_set = set([DbException])
|
115
|
DatabaseErrors = tuple(DatabaseErrors_set)
|
116
|
|
117
|
def _add_module(module):
|
118
|
DatabaseErrors_set.add(module.DatabaseError)
|
119
|
global DatabaseErrors
|
120
|
DatabaseErrors = tuple(DatabaseErrors_set)
|
121
|
|
122
|
def db_config_str(db_config):
|
123
|
return db_config['engine']+' database '+db_config['database']
|
124
|
|
125
|
def _query_lookup(query, params): return (query, dicts.make_hashable(params))
|
126
|
|
127
|
log_debug_none = lambda msg: None
|
128
|
|
129
|
class DbConn:
|
130
|
def __init__(self, db_config, serializable=True, log_debug=log_debug_none,
|
131
|
caching=True):
|
132
|
self.db_config = db_config
|
133
|
self.serializable = serializable
|
134
|
self.log_debug = log_debug
|
135
|
self.caching = caching
|
136
|
|
137
|
self.__db = None
|
138
|
self.query_results = {}
|
139
|
|
140
|
def __getattr__(self, name):
|
141
|
if name == '__dict__': raise Exception('getting __dict__')
|
142
|
if name == 'db': return self._db()
|
143
|
else: raise AttributeError()
|
144
|
|
145
|
def __getstate__(self):
|
146
|
state = copy.copy(self.__dict__) # shallow copy
|
147
|
state['log_debug'] = None # don't pickle the debug callback
|
148
|
state['_DbConn__db'] = None # don't pickle the connection
|
149
|
return state
|
150
|
|
151
|
def _db(self):
|
152
|
if self.__db == None:
|
153
|
# Process db_config
|
154
|
db_config = self.db_config.copy() # don't modify input!
|
155
|
schemas = db_config.pop('schemas', None)
|
156
|
module_name, mappings = db_engines[db_config.pop('engine')]
|
157
|
module = __import__(module_name)
|
158
|
_add_module(module)
|
159
|
for orig, new in mappings.iteritems():
|
160
|
try: util.rename_key(db_config, orig, new)
|
161
|
except KeyError: pass
|
162
|
|
163
|
# Connect
|
164
|
self.__db = module.connect(**db_config)
|
165
|
|
166
|
# Configure connection
|
167
|
if self.serializable: run_raw_query(self,
|
168
|
'SET TRANSACTION ISOLATION LEVEL SERIALIZABLE')
|
169
|
if schemas != None:
|
170
|
schemas_ = ''.join((esc_name(self, s)+', '
|
171
|
for s in schemas.split(',')))
|
172
|
run_raw_query(self, "SELECT set_config('search_path', \
|
173
|
%s || current_setting('search_path'), false)", [schemas_])
|
174
|
|
175
|
return self.__db
|
176
|
|
177
|
class DbCursor(Proxy):
|
178
|
def __init__(self, outer):
|
179
|
Proxy.__init__(self, outer.db.cursor())
|
180
|
self.query_results = outer.query_results
|
181
|
self.query_lookup = None
|
182
|
self.result = []
|
183
|
|
184
|
def execute(self, query, params=None):
|
185
|
self._is_insert = query.upper().find('INSERT') >= 0
|
186
|
self.query_lookup = _query_lookup(query, params)
|
187
|
try: return_value = self.inner.execute(query, params)
|
188
|
except Exception, e:
|
189
|
self.result = e # cache the exception as the result
|
190
|
self._cache_result()
|
191
|
raise
|
192
|
finally: self.query = get_cur_query(self.inner)
|
193
|
# Fetch all rows so result will be cached
|
194
|
if self.rowcount == 0 and not self._is_insert: consume_rows(self)
|
195
|
return return_value
|
196
|
|
197
|
def fetchone(self):
|
198
|
row = self.inner.fetchone()
|
199
|
if row != None: self.result.append(row)
|
200
|
# otherwise, fetched all rows
|
201
|
else: self._cache_result()
|
202
|
return row
|
203
|
|
204
|
def _cache_result(self):
|
205
|
# For inserts, only cache exceptions since inserts are not
|
206
|
# idempotent, but an invalid insert will always be invalid
|
207
|
if self.query_results != None and (not self._is_insert
|
208
|
or isinstance(self.result, Exception)):
|
209
|
|
210
|
assert self.query_lookup != None
|
211
|
self.query_results[self.query_lookup] = self.CacheCursor(
|
212
|
util.dict_subset(dicts.AttrsDictView(self),
|
213
|
['query', 'result', 'rowcount', 'description']))
|
214
|
|
215
|
class CacheCursor:
|
216
|
def __init__(self, cached_result): self.__dict__ = cached_result
|
217
|
|
218
|
def execute(self, *args, **kw_args):
|
219
|
if isinstance(self.result, Exception): raise self.result
|
220
|
# otherwise, result is a rows list
|
221
|
self.iter = iter(self.result)
|
222
|
|
223
|
def fetchone(self):
|
224
|
try: return self.iter.next()
|
225
|
except StopIteration: return None
|
226
|
|
227
|
def run_query(self, query, params=None, cacheable=False):
|
228
|
if not self.caching: cacheable = False
|
229
|
used_cache = False
|
230
|
try:
|
231
|
# Get cursor
|
232
|
if cacheable:
|
233
|
query_lookup = _query_lookup(query, params)
|
234
|
try:
|
235
|
cur = self.query_results[query_lookup]
|
236
|
used_cache = True
|
237
|
except KeyError: cur = self.DbCursor(self)
|
238
|
else: cur = self.db.cursor()
|
239
|
|
240
|
# Run query
|
241
|
try: cur.execute(query, params)
|
242
|
except Exception, e:
|
243
|
_add_cursor_info(e, cur)
|
244
|
raise
|
245
|
finally:
|
246
|
if self.log_debug != log_debug_none: # only compute msg if needed
|
247
|
if used_cache: cache_status = 'Cache hit'
|
248
|
elif cacheable: cache_status = 'Cache miss'
|
249
|
else: cache_status = 'Non-cacheable'
|
250
|
self.log_debug(cache_status+': '
|
251
|
+strings.one_line(get_cur_query(cur)))
|
252
|
|
253
|
return cur
|
254
|
|
255
|
def is_cached(self, query, params=None):
|
256
|
return _query_lookup(query, params) in self.query_results
|
257
|
|
258
|
connect = DbConn
|
259
|
|
260
|
##### Querying
|
261
|
|
262
|
def run_raw_query(db, *args, **kw_args):
|
263
|
'''For params, see DbConn.run_query()'''
|
264
|
return db.run_query(*args, **kw_args)
|
265
|
|
266
|
def mogrify(db, query, params):
|
267
|
module = util.root_module(db.db)
|
268
|
if module == 'psycopg2': return db.db.cursor().mogrify(query, params)
|
269
|
else: raise NotImplementedError("Can't mogrify query for "+module+
|
270
|
' database')
|
271
|
|
272
|
##### Recoverable querying
|
273
|
|
274
|
def with_savepoint(db, func):
|
275
|
savepoint = 'savepoint_'+str(rand.rand_int()) # must be unique
|
276
|
run_raw_query(db, 'SAVEPOINT '+savepoint)
|
277
|
try: return_val = func()
|
278
|
except:
|
279
|
run_raw_query(db, 'ROLLBACK TO SAVEPOINT '+savepoint)
|
280
|
raise
|
281
|
else:
|
282
|
run_raw_query(db, 'RELEASE SAVEPOINT '+savepoint)
|
283
|
return return_val
|
284
|
|
285
|
def run_query(db, query, params=None, recover=None, cacheable=False):
|
286
|
if recover == None: recover = False
|
287
|
|
288
|
def run(): return run_raw_query(db, query, params, cacheable)
|
289
|
if recover and not db.is_cached(query, params):
|
290
|
return with_savepoint(db, run)
|
291
|
else: return run() # don't need savepoint if cached
|
292
|
|
293
|
##### Basic queries
|
294
|
|
295
|
def run_query_into(db, query, params, into=None, *args, **kw_args):
|
296
|
'''Outputs a query to a temp table.
|
297
|
For params, see run_query().
|
298
|
'''
|
299
|
if into == None: return run_query(db, query, params, *args, **kw_args)
|
300
|
else: # place rows in temp table
|
301
|
check_name(into)
|
302
|
|
303
|
run_query(db, 'DROP TABLE IF EXISTS '+into+' CASCADE', *args, **kw_args)
|
304
|
return run_query(db, 'CREATE TEMP TABLE '+into+' AS '+query, params,
|
305
|
*args, **kw_args) # CREATE TABLE sets rowcount to # rows in query
|
306
|
|
307
|
order_by_pkey = object() # tells mk_select() to order by the pkey
|
308
|
|
309
|
def mk_select(db, tables, fields=None, conds=None, limit=None, start=None,
|
310
|
order_by=order_by_pkey, table_is_esc=False):
|
311
|
'''
|
312
|
@param tables The single table to select from, or a list of tables to join
|
313
|
together, in the form: [table0, (table1, joins_dict), ...]
|
314
|
@param fields Use None to select all fields in the table
|
315
|
@param table_is_esc Whether the table name has already been escaped
|
316
|
@return tuple(query, params)
|
317
|
'''
|
318
|
def esc_name_(name): return esc_name(db, name)
|
319
|
|
320
|
if not lists.is_seq(tables): tables = [tables]
|
321
|
tables = tables[:] # don't modify input!
|
322
|
table0 = tables.pop(0) # first table is separate
|
323
|
|
324
|
if conds == None: conds = {}
|
325
|
assert limit == None or type(limit) == int
|
326
|
assert start == None or type(start) == int
|
327
|
if order_by == order_by_pkey:
|
328
|
order_by = pkey(db, table0, recover=True, table_is_esc=table_is_esc)
|
329
|
if not table_is_esc: table0 = esc_name_(table0)
|
330
|
|
331
|
params = []
|
332
|
|
333
|
def parse_col(field):
|
334
|
'''Parses fields'''
|
335
|
if isinstance(field, tuple): # field is literal value
|
336
|
value, col = field
|
337
|
sql_ = '%s'
|
338
|
params.append(value)
|
339
|
if col != None: sql_ += ' AS '+esc_name_(col)
|
340
|
else: sql_ = esc_name_(field) # field is col name
|
341
|
return sql_
|
342
|
def cond(entry):
|
343
|
'''Parses conditions'''
|
344
|
col, value = entry
|
345
|
cond_ = esc_name_(col)+' '
|
346
|
if value == None: cond_ += 'IS'
|
347
|
else: cond_ += '='
|
348
|
cond_ += ' %s'
|
349
|
return cond_
|
350
|
|
351
|
query = 'SELECT '
|
352
|
if fields == None: query += '*'
|
353
|
else: query += ', '.join(map(parse_col, fields))
|
354
|
query += ' FROM '+table0
|
355
|
|
356
|
# Add joins
|
357
|
left_table = table0
|
358
|
for table, joins in tables:
|
359
|
if not table_is_esc: table = esc_name_(table)
|
360
|
|
361
|
def join(entry):
|
362
|
'''Parses joins'''
|
363
|
left_col, right_col = entry
|
364
|
left_col = left_table+'.'+esc_name_(left_col)
|
365
|
right_col = table+'.'+esc_name_(right_col)
|
366
|
return (left_col+' = '+right_col
|
367
|
+' OR ('+left_col+' IS NULL AND '+right_col+' IS NULL)')
|
368
|
|
369
|
query += ' JOIN '+table+' ON '+(
|
370
|
' AND '.join(map(join, joins.iteritems())))
|
371
|
left_table = table
|
372
|
|
373
|
missing = True
|
374
|
if conds != {}:
|
375
|
query += ' WHERE '+(' AND '.join(map(cond, conds.iteritems())))
|
376
|
params += conds.values()
|
377
|
missing = False
|
378
|
if order_by != None: query += ' ORDER BY '+esc_name_(order_by)
|
379
|
if limit != None: query += ' LIMIT '+str(limit); missing = False
|
380
|
if start != None:
|
381
|
if start != 0: query += ' OFFSET '+str(start)
|
382
|
missing = False
|
383
|
if missing: warnings.warn(DbWarning(
|
384
|
'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
|
385
|
|
386
|
return (query, params)
|
387
|
|
388
|
def select(db, *args, **kw_args):
|
389
|
'''For params, see mk_select() and run_query()'''
|
390
|
recover = kw_args.pop('recover', None)
|
391
|
cacheable = kw_args.pop('cacheable', True)
|
392
|
|
393
|
query, params = mk_select(db, *args, **kw_args)
|
394
|
return run_query(db, query, params, recover, cacheable)
|
395
|
|
396
|
def mk_insert_select(db, table, cols=None, select_query=None, params=None,
|
397
|
returning=None, embeddable=False, table_is_esc=False):
|
398
|
'''
|
399
|
@param returning str|None An inserted column (such as pkey) to return
|
400
|
@param embeddable Whether the query should be embeddable as a nested SELECT.
|
401
|
Warning: If you set this and cacheable=True when the query is run, the
|
402
|
query will be fully cached, not just if it raises an exception.
|
403
|
@param table_is_esc Whether the table name has already been escaped
|
404
|
'''
|
405
|
if select_query == None: select_query = 'DEFAULT VALUES'
|
406
|
if cols == []: cols = None # no cols (all defaults) = unknown col names
|
407
|
if not table_is_esc: check_name(table)
|
408
|
|
409
|
# Build query
|
410
|
query = 'INSERT INTO '+table
|
411
|
if cols != None:
|
412
|
map(check_name, cols)
|
413
|
query += ' ('+', '.join(cols)+')'
|
414
|
query += ' '+select_query
|
415
|
|
416
|
if returning != None:
|
417
|
check_name(returning)
|
418
|
query += ' RETURNING '+returning
|
419
|
|
420
|
if embeddable:
|
421
|
# Create function
|
422
|
function = 'pg_temp.'+('_'.join(map(clean_name,
|
423
|
['insert', table] + cols)))
|
424
|
return_type = 'SETOF '+table+'.'+returning+'%TYPE'
|
425
|
function_query = '''\
|
426
|
CREATE OR REPLACE FUNCTION '''+function+'''() RETURNS '''+return_type+'''
|
427
|
LANGUAGE sql
|
428
|
AS $$'''+mogrify(db, query, params)+''';$$;
|
429
|
'''
|
430
|
run_query(db, function_query, cacheable=True)
|
431
|
|
432
|
# Return query that uses function
|
433
|
return mk_select(db, function+'() AS f ('+returning+')',
|
434
|
table_is_esc=True) # function alias is required in AS clause
|
435
|
|
436
|
return (query, params)
|
437
|
|
438
|
def insert_select(db, *args, **kw_args):
|
439
|
'''For params, see mk_insert_select() and run_query_into()
|
440
|
@param into Name of temp table to place RETURNING values in
|
441
|
'''
|
442
|
into = kw_args.pop('into', None)
|
443
|
if into != None: kw_args['embeddable'] = True
|
444
|
recover = kw_args.pop('recover', None)
|
445
|
cacheable = kw_args.pop('cacheable', True)
|
446
|
|
447
|
query, params = mk_insert_select(db, *args, **kw_args)
|
448
|
return run_query_into(db, query, params, into, recover, cacheable)
|
449
|
|
450
|
default = object() # tells insert() to use the default value for a column
|
451
|
|
452
|
def insert(db, table, row, *args, **kw_args):
|
453
|
'''For params, see insert_select()'''
|
454
|
if lists.is_seq(row): cols = None
|
455
|
else:
|
456
|
cols = row.keys()
|
457
|
row = row.values()
|
458
|
row = list(row) # ensure that "!= []" works
|
459
|
|
460
|
# Check for special values
|
461
|
labels = []
|
462
|
values = []
|
463
|
for value in row:
|
464
|
if value == default: labels.append('DEFAULT')
|
465
|
else:
|
466
|
labels.append('%s')
|
467
|
values.append(value)
|
468
|
|
469
|
# Build query
|
470
|
if values != []: query = ' VALUES ('+(', '.join(labels))+')'
|
471
|
else: query = None
|
472
|
|
473
|
return insert_select(db, table, cols, query, values, *args, **kw_args)
|
474
|
|
475
|
def last_insert_id(db):
|
476
|
module = util.root_module(db.db)
|
477
|
if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
|
478
|
elif module == 'MySQLdb': return db.insert_id()
|
479
|
else: return None
|
480
|
|
481
|
def truncate(db, table, schema='public'):
|
482
|
return run_query(db, 'TRUNCATE '+qual_name(db, schema, table)+' CASCADE')
|
483
|
|
484
|
##### Database structure queries
|
485
|
|
486
|
def pkey(db, table, recover=None, table_is_esc=False):
|
487
|
'''Assumed to be first column in table'''
|
488
|
return col_names(select(db, table, limit=0, order_by=None, recover=recover,
|
489
|
table_is_esc=table_is_esc)).next()
|
490
|
|
491
|
def index_cols(db, table, index):
|
492
|
'''Can also use this for UNIQUE constraints, because a UNIQUE index is
|
493
|
automatically created. When you don't know whether something is a UNIQUE
|
494
|
constraint or a UNIQUE index, use this function.'''
|
495
|
check_name(table)
|
496
|
check_name(index)
|
497
|
module = util.root_module(db.db)
|
498
|
if module == 'psycopg2':
|
499
|
return list(values(run_query(db, '''\
|
500
|
SELECT attname
|
501
|
FROM
|
502
|
(
|
503
|
SELECT attnum, attname
|
504
|
FROM pg_index
|
505
|
JOIN pg_class index ON index.oid = indexrelid
|
506
|
JOIN pg_class table_ ON table_.oid = indrelid
|
507
|
JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
|
508
|
WHERE
|
509
|
table_.relname = %(table)s
|
510
|
AND index.relname = %(index)s
|
511
|
UNION
|
512
|
SELECT attnum, attname
|
513
|
FROM
|
514
|
(
|
515
|
SELECT
|
516
|
indrelid
|
517
|
, (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
|
518
|
AS indkey
|
519
|
FROM pg_index
|
520
|
JOIN pg_class index ON index.oid = indexrelid
|
521
|
JOIN pg_class table_ ON table_.oid = indrelid
|
522
|
WHERE
|
523
|
table_.relname = %(table)s
|
524
|
AND index.relname = %(index)s
|
525
|
) s
|
526
|
JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
|
527
|
) s
|
528
|
ORDER BY attnum
|
529
|
''',
|
530
|
{'table': table, 'index': index}, cacheable=True)))
|
531
|
else: raise NotImplementedError("Can't list index columns for "+module+
|
532
|
' database')
|
533
|
|
534
|
def constraint_cols(db, table, constraint):
|
535
|
check_name(table)
|
536
|
check_name(constraint)
|
537
|
module = util.root_module(db.db)
|
538
|
if module == 'psycopg2':
|
539
|
return list(values(run_query(db, '''\
|
540
|
SELECT attname
|
541
|
FROM pg_constraint
|
542
|
JOIN pg_class ON pg_class.oid = conrelid
|
543
|
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
|
544
|
WHERE
|
545
|
relname = %(table)s
|
546
|
AND conname = %(constraint)s
|
547
|
ORDER BY attnum
|
548
|
''',
|
549
|
{'table': table, 'constraint': constraint})))
|
550
|
else: raise NotImplementedError("Can't list constraint columns for "+module+
|
551
|
' database')
|
552
|
|
553
|
row_num_col = '_row_num'
|
554
|
|
555
|
def add_row_num(db, table):
|
556
|
'''Adds a row number column to a table. Its name is in row_num_col. It will
|
557
|
be the primary key.'''
|
558
|
check_name(table)
|
559
|
run_query(db, 'ALTER TABLE '+table+' ADD COLUMN '+row_num_col
|
560
|
+' serial NOT NULL PRIMARY KEY')
|
561
|
|
562
|
def tables(db, schema='public', table_like='%'):
|
563
|
module = util.root_module(db.db)
|
564
|
params = {'schema': schema, 'table_like': table_like}
|
565
|
if module == 'psycopg2':
|
566
|
return values(run_query(db, '''\
|
567
|
SELECT tablename
|
568
|
FROM pg_tables
|
569
|
WHERE
|
570
|
schemaname = %(schema)s
|
571
|
AND tablename LIKE %(table_like)s
|
572
|
ORDER BY tablename
|
573
|
''',
|
574
|
params, cacheable=True))
|
575
|
elif module == 'MySQLdb':
|
576
|
return values(run_query(db, 'SHOW TABLES LIKE %(table_like)s', params,
|
577
|
cacheable=True))
|
578
|
else: raise NotImplementedError("Can't list tables for "+module+' database')
|
579
|
|
580
|
##### Database management
|
581
|
|
582
|
def empty_db(db, schema='public', **kw_args):
|
583
|
'''For kw_args, see tables()'''
|
584
|
for table in tables(db, schema, **kw_args): truncate(db, table, schema)
|
585
|
|
586
|
##### Heuristic queries
|
587
|
|
588
|
def with_parsed_errors(db, func):
|
589
|
'''Translates known DB errors to typed exceptions'''
|
590
|
try: return func()
|
591
|
except Exception, e:
|
592
|
msg = str(e)
|
593
|
match = re.search(r'duplicate key value violates unique constraint '
|
594
|
r'"(([^\W_]+)_[^"]+)"', msg)
|
595
|
if match:
|
596
|
constraint, table = match.groups()
|
597
|
try: cols = index_cols(db, table, constraint)
|
598
|
except NotImplementedError: raise e
|
599
|
else: raise DuplicateKeyException(cols, e)
|
600
|
match = re.search(r'null value in column "(\w+)" violates not-null '
|
601
|
'constraint', msg)
|
602
|
if match: raise NullValueException([match.group(1)], e)
|
603
|
raise # no specific exception raised
|
604
|
|
605
|
def try_insert(db, table, row, returning=None):
|
606
|
'''Recovers from errors'''
|
607
|
return with_parsed_errors(db, lambda: insert(db, table, row, returning,
|
608
|
recover=True))
|
609
|
|
610
|
def put(db, table, row, pkey_=None, row_ct_ref=None):
|
611
|
'''Recovers from errors.
|
612
|
Only works under PostgreSQL (uses INSERT RETURNING).
|
613
|
'''
|
614
|
if pkey_ == None: pkey_ = pkey(db, table, recover=True)
|
615
|
|
616
|
try:
|
617
|
cur = try_insert(db, table, row, pkey_)
|
618
|
if row_ct_ref != None and cur.rowcount >= 0:
|
619
|
row_ct_ref[0] += cur.rowcount
|
620
|
return value(cur)
|
621
|
except DuplicateKeyException, e:
|
622
|
return value(select(db, table, [pkey_],
|
623
|
util.dict_subset_right_join(row, e.cols), recover=True))
|
624
|
|
625
|
def get(db, table, row, pkey, row_ct_ref=None, create=False):
|
626
|
'''Recovers from errors'''
|
627
|
try: return value(select(db, table, [pkey], row, 1, recover=True))
|
628
|
except StopIteration:
|
629
|
if not create: raise
|
630
|
return put(db, table, row, pkey, row_ct_ref) # insert new row
|
631
|
|
632
|
def put_table(db, out_table, out_cols, in_tables, in_cols, pkey,
|
633
|
row_ct_ref=None, table_is_esc=False):
|
634
|
'''Recovers from errors.
|
635
|
Only works under PostgreSQL (uses INSERT RETURNING).
|
636
|
@return Name of the table where the pkeys (from INSERT RETURNING) are made
|
637
|
available
|
638
|
'''
|
639
|
pkeys_table = clean_name(out_table)+'_pkeys'
|
640
|
def insert_():
|
641
|
return insert_select(db, out_table, out_cols,
|
642
|
*mk_select(db, in_tables[0], in_cols, table_is_esc=table_is_esc),
|
643
|
returning=pkey, into=pkeys_table, recover=True,
|
644
|
table_is_esc=table_is_esc)
|
645
|
try:
|
646
|
cur = with_parsed_errors(db, insert_)
|
647
|
if row_ct_ref != None and cur.rowcount >= 0:
|
648
|
row_ct_ref[0] += cur.rowcount
|
649
|
|
650
|
# Add row_num to pkeys_table, so it can be joined with in_table's pkeys
|
651
|
add_row_num(db, pkeys_table)
|
652
|
|
653
|
return pkeys_table
|
654
|
except DuplicateKeyException, e: raise
|
655
|
|
656
|
##### Data cleanup
|
657
|
|
658
|
def cleanup_table(db, table, cols, table_is_esc=False):
|
659
|
def esc_name_(name): return esc_name(db, name)
|
660
|
|
661
|
if not table_is_esc: check_name(table)
|
662
|
cols = map(esc_name_, cols)
|
663
|
|
664
|
run_query(db, 'UPDATE '+table+' SET\n'+(',\n'.join(('\n'+col
|
665
|
+' = nullif(nullif(trim(both from '+col+"), %(null0)s), %(null1)s)"
|
666
|
for col in cols))),
|
667
|
dict(null0='', null1=r'\N'))
|