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