Project

General

Profile

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 sql_gen
15
import strings
16
import util
17

    
18
##### Exceptions
19

    
20
def get_cur_query(cur, input_query=None, input_params=None):
21
    raw_query = None
22
    if hasattr(cur, 'query'): raw_query = cur.query
23
    elif hasattr(cur, '_last_executed'): raw_query = cur._last_executed
24
    
25
    if raw_query != None: return raw_query
26
    else: return '[input] '+strings.ustr(input_query)+' % '+repr(input_params)
27

    
28
def _add_cursor_info(e, *args, **kw_args):
29
    '''For params, see get_cur_query()'''
30
    exc.add_msg(e, 'query: '+str(get_cur_query(*args, **kw_args)))
31

    
32
class DbException(exc.ExceptionWithCause):
33
    def __init__(self, msg, cause=None, cur=None):
34
        exc.ExceptionWithCause.__init__(self, msg, cause, cause_newline=True)
35
        if cur != None: _add_cursor_info(self, cur)
36

    
37
class ExceptionWithName(DbException):
38
    def __init__(self, name, cause=None):
39
        DbException.__init__(self, 'for name: '+strings.as_tt(str(name)), cause)
40
        self.name = name
41

    
42
class ExceptionWithNameValue(DbException):
43
    def __init__(self, name, value, cause=None):
44
        DbException.__init__(self, 'for name: '+strings.as_tt(str(name))
45
            +'; value: '+strings.as_tt(repr(value)), cause)
46
        self.name = name
47
        self.value = value
48

    
49
class ConstraintException(DbException):
50
    def __init__(self, name, cols, cause=None):
51
        DbException.__init__(self, 'Violated '+strings.as_tt(name)
52
            +' constraint on columns: '+strings.as_tt(', '.join(cols)), cause)
53
        self.name = name
54
        self.cols = cols
55

    
56
class MissingCastException(DbException):
57
    def __init__(self, type_, col, cause=None):
58
        DbException.__init__(self, 'Missing cast to type '+strings.as_tt(type_)
59
            +' on column: '+strings.as_tt(col), cause)
60
        self.type = type_
61
        self.col = col
62

    
63
class NameException(DbException): pass
64

    
65
class DuplicateKeyException(ConstraintException): pass
66

    
67
class NullValueException(ConstraintException): pass
68

    
69
class FunctionValueException(ExceptionWithNameValue): pass
70

    
71
class DuplicateTableException(ExceptionWithName): pass
72

    
73
class DuplicateFunctionException(ExceptionWithName): pass
74

    
75
class EmptyRowException(DbException): pass
76

    
77
##### Warnings
78

    
79
class DbWarning(UserWarning): pass
80

    
81
##### Result retrieval
82

    
83
def col_names(cur): return (col[0] for col in cur.description)
84

    
85
def rows(cur): return iter(lambda: cur.fetchone(), None)
86

    
87
def consume_rows(cur):
88
    '''Used to fetch all rows so result will be cached'''
89
    iters.consume_iter(rows(cur))
90

    
91
def next_row(cur): return rows(cur).next()
92

    
93
def row(cur):
94
    row_ = next_row(cur)
95
    consume_rows(cur)
96
    return row_
97

    
98
def next_value(cur): return next_row(cur)[0]
99

    
100
def value(cur): return row(cur)[0]
101

    
102
def values(cur): return iters.func_iter(lambda: next_value(cur))
103

    
104
def value_or_none(cur):
105
    try: return value(cur)
106
    except StopIteration: return None
107

    
108
##### Input validation
109

    
110
def esc_name_by_module(module, name):
111
    if module == 'psycopg2' or module == None: quote = '"'
112
    elif module == 'MySQLdb': quote = '`'
113
    else: raise NotImplementedError("Can't escape name for "+module+' database')
114
    return sql_gen.esc_name(name, quote)
115

    
116
def esc_name_by_engine(engine, name, **kw_args):
117
    return esc_name_by_module(db_engines[engine][0], name, **kw_args)
118

    
119
def esc_name(db, name, **kw_args):
120
    return esc_name_by_module(util.root_module(db.db), name, **kw_args)
121

    
122
def qual_name(db, schema, table):
123
    def esc_name_(name): return esc_name(db, name)
124
    table = esc_name_(table)
125
    if schema != None: return esc_name_(schema)+'.'+table
126
    else: return table
127

    
128
##### Database connections
129

    
130
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
131

    
132
db_engines = {
133
    'MySQL': ('MySQLdb', {'password': 'passwd', 'database': 'db'}),
134
    'PostgreSQL': ('psycopg2', {}),
135
}
136

    
137
DatabaseErrors_set = set([DbException])
138
DatabaseErrors = tuple(DatabaseErrors_set)
139

    
140
def _add_module(module):
141
    DatabaseErrors_set.add(module.DatabaseError)
142
    global DatabaseErrors
143
    DatabaseErrors = tuple(DatabaseErrors_set)
144

    
145
def db_config_str(db_config):
146
    return db_config['engine']+' database '+db_config['database']
147

    
148
def _query_lookup(query, params): return (query, dicts.make_hashable(params))
149

    
150
log_debug_none = lambda msg, level=2: None
151

    
152
class DbConn:
153
    def __init__(self, db_config, serializable=True, autocommit=False,
154
        caching=True, log_debug=log_debug_none):
155
        self.db_config = db_config
156
        self.serializable = serializable
157
        self.autocommit = autocommit
158
        self.caching = caching
159
        self.log_debug = log_debug
160
        self.debug = log_debug != log_debug_none
161
        
162
        self.__db = None
163
        self.query_results = {}
164
        self._savepoint = 0
165
    
166
    def __getattr__(self, name):
167
        if name == '__dict__': raise Exception('getting __dict__')
168
        if name == 'db': return self._db()
169
        else: raise AttributeError()
170
    
171
    def __getstate__(self):
172
        state = copy.copy(self.__dict__) # shallow copy
173
        state['log_debug'] = None # don't pickle the debug callback
174
        state['_DbConn__db'] = None # don't pickle the connection
175
        return state
176
    
177
    def connected(self): return self.__db != None
178
    
179
    def _db(self):
180
        if self.__db == None:
181
            # Process db_config
182
            db_config = self.db_config.copy() # don't modify input!
183
            schemas = db_config.pop('schemas', None)
184
            module_name, mappings = db_engines[db_config.pop('engine')]
185
            module = __import__(module_name)
186
            _add_module(module)
187
            for orig, new in mappings.iteritems():
188
                try: util.rename_key(db_config, orig, new)
189
                except KeyError: pass
190
            
191
            # Connect
192
            self.__db = module.connect(**db_config)
193
            
194
            # Configure connection
195
            if self.serializable and not self.autocommit: run_raw_query(self,
196
                'SET TRANSACTION ISOLATION LEVEL SERIALIZABLE')
197
            if schemas != None:
198
                schemas_ = ''.join((esc_name(self, s)+', '
199
                    for s in schemas.split(',')))
200
                run_raw_query(self, "SELECT set_config('search_path', \
201
%s || current_setting('search_path'), false)", [schemas_])
202
        
203
        return self.__db
204
    
205
    class DbCursor(Proxy):
206
        def __init__(self, outer):
207
            Proxy.__init__(self, outer.db.cursor())
208
            self.outer = outer
209
            self.query_results = outer.query_results
210
            self.query_lookup = None
211
            self.result = []
212
        
213
        def execute(self, query, params=None):
214
            self._is_insert = query.upper().find('INSERT') >= 0
215
            self.query_lookup = _query_lookup(query, params)
216
            try:
217
                try:
218
                    return_value = self.inner.execute(query, params)
219
                    self.outer.do_autocommit()
220
                finally: self.query = get_cur_query(self.inner)
221
            except Exception, e:
222
                _add_cursor_info(e, self, query, params)
223
                self.result = e # cache the exception as the result
224
                self._cache_result()
225
                raise
226
            # Fetch all rows so result will be cached
227
            if self.rowcount == 0 and not self._is_insert: consume_rows(self)
228
            return return_value
229
        
230
        def fetchone(self):
231
            row = self.inner.fetchone()
232
            if row != None: self.result.append(row)
233
            # otherwise, fetched all rows
234
            else: self._cache_result()
235
            return row
236
        
237
        def _cache_result(self):
238
            # For inserts, only cache exceptions since inserts are not
239
            # idempotent, but an invalid insert will always be invalid
240
            if self.query_results != None and (not self._is_insert
241
                or isinstance(self.result, Exception)):
242
                
243
                assert self.query_lookup != None
244
                self.query_results[self.query_lookup] = self.CacheCursor(
245
                    util.dict_subset(dicts.AttrsDictView(self),
246
                    ['query', 'result', 'rowcount', 'description']))
247
        
248
        class CacheCursor:
249
            def __init__(self, cached_result): self.__dict__ = cached_result
250
            
251
            def execute(self, *args, **kw_args):
252
                if isinstance(self.result, Exception): raise self.result
253
                # otherwise, result is a rows list
254
                self.iter = iter(self.result)
255
            
256
            def fetchone(self):
257
                try: return self.iter.next()
258
                except StopIteration: return None
259
    
260
    def esc_value(self, value):
261
        module = util.root_module(self.db)
262
        if module == 'psycopg2': str_ = self.db.cursor().mogrify('%s', [value])
263
        elif module == 'MySQLdb':
264
            import _mysql
265
            str_ = _mysql.escape_string(value)
266
        else: raise NotImplementedError("Can't escape value for "+module
267
            +' database')
268
        return strings.to_unicode(str_)
269
    
270
    def esc_name(self, name): return esc_name(self, name) # calls global func
271
    
272
    def run_query(self, query, params=None, cacheable=False, log_level=2,
273
        debug_msg_ref=None):
274
        '''
275
        @param log_ignore_excs The log_level will be increased by 2 if the query
276
            throws one of these exceptions.
277
        '''
278
        assert query != None
279
        
280
        if not self.caching: cacheable = False
281
        used_cache = False
282
        try:
283
            # Get cursor
284
            if cacheable:
285
                query_lookup = _query_lookup(query, params)
286
                try:
287
                    cur = self.query_results[query_lookup]
288
                    used_cache = True
289
                except KeyError: cur = self.DbCursor(self)
290
            else: cur = self.db.cursor()
291
            
292
            # Run query
293
            cur.execute(query, params)
294
        finally:
295
            if self.debug and debug_msg_ref != None:# only compute msg if needed
296
                if used_cache: cache_status = 'cache hit'
297
                elif cacheable: cache_status = 'cache miss'
298
                else: cache_status = 'non-cacheable'
299
                query_code = strings.as_code(str(get_cur_query(cur, query,
300
                    params)), 'SQL')
301
                debug_msg_ref[0] = 'DB query: '+cache_status+':\n'+query_code
302
        
303
        return cur
304
    
305
    def is_cached(self, query, params=None):
306
        return _query_lookup(query, params) in self.query_results
307
    
308
    def with_savepoint(self, func):
309
        savepoint = 'level_'+str(self._savepoint)
310
        self.run_query('SAVEPOINT '+savepoint, log_level=4)
311
        self._savepoint += 1
312
        try: 
313
            try: return_val = func()
314
            finally:
315
                self._savepoint -= 1
316
                assert self._savepoint >= 0
317
        except:
318
            self.run_query('ROLLBACK TO SAVEPOINT '+savepoint, log_level=4)
319
            raise
320
        else:
321
            self.run_query('RELEASE SAVEPOINT '+savepoint, log_level=4)
322
            self.do_autocommit()
323
            return return_val
324
    
325
    def do_autocommit(self):
326
        '''Autocommits if outside savepoint'''
327
        assert self._savepoint >= 0
328
        if self.autocommit and self._savepoint == 0:
329
            self.log_debug('Autocommiting')
330
            self.db.commit()
331

    
332
connect = DbConn
333

    
334
##### Querying
335

    
336
def run_raw_query(db, *args, **kw_args):
337
    '''For params, see DbConn.run_query()'''
338
    return db.run_query(*args, **kw_args)
339

    
340
def mogrify(db, query, params):
341
    module = util.root_module(db.db)
342
    if module == 'psycopg2': return db.db.cursor().mogrify(query, params)
343
    else: raise NotImplementedError("Can't mogrify query for "+module+
344
        ' database')
345

    
346
##### Recoverable querying
347

    
348
def with_savepoint(db, func): return db.with_savepoint(func)
349

    
350
def run_query(db, query, params=None, recover=None, cacheable=False,
351
    log_level=2, log_ignore_excs=None, **kw_args):
352
    '''For params, see run_raw_query()'''
353
    if recover == None: recover = False
354
    if log_ignore_excs == None: log_ignore_excs = ()
355
    log_ignore_excs = tuple(log_ignore_excs)
356
    
357
    debug_msg_ref = [None]
358
    try:
359
        try:
360
            def run(): return run_raw_query(db, query, params, cacheable,
361
                log_level, debug_msg_ref, **kw_args)
362
            if recover and not db.is_cached(query, params):
363
                return with_savepoint(db, run)
364
            else: return run() # don't need savepoint if cached
365
        except Exception, e:
366
            if not recover: raise # need savepoint to run index_cols()
367
            msg = exc.str_(e)
368
            
369
            match = re.search(r'duplicate key value violates unique constraint '
370
                r'"((_?[^\W_]+)_.+?)"', msg)
371
            if match:
372
                constraint, table = match.groups()
373
                try: cols = index_cols(db, table, constraint)
374
                except NotImplementedError: raise e
375
                else: raise DuplicateKeyException(constraint, cols, e)
376
            
377
            match = re.search(r'null value in column "(.+?)" violates not-null'
378
                r' constraint', msg)
379
            if match: raise NullValueException('NOT NULL', [match.group(1)], e)
380
            
381
            match = re.search(r'\b(?:invalid input (?:syntax|value)\b.*?'
382
                r'|date/time field value out of range): "(.+?)"\n'
383
                r'(?:(?s).*?)\bfunction "(.+?)"', msg)
384
            if match:
385
                value, name = match.groups()
386
                raise FunctionValueException(name, strings.to_unicode(value), e)
387
            
388
            match = re.search(r'column "(.+?)" is of type (.+?) but expression '
389
                r'is of type', msg)
390
            if match:
391
                col, type_ = match.groups()
392
                raise MissingCastException(type_, col, e)
393
            
394
            match = re.search(r'relation "(.+?)" already exists', msg)
395
            if match: raise DuplicateTableException(match.group(1), e)
396
            
397
            match = re.search(r'function "(.+?)" already exists', msg)
398
            if match: raise DuplicateFunctionException(match.group(1), e)
399
            
400
            raise # no specific exception raised
401
    except log_ignore_excs:
402
        log_level += 2
403
        raise
404
    finally:
405
        if debug_msg_ref[0] != None: db.log_debug(debug_msg_ref[0], log_level)
406

    
407
##### Basic queries
408

    
409
def next_version(name):
410
    '''Prepends the version # so it won't be removed if the name is truncated'''
411
    version = 1 # first existing name was version 0
412
    match = re.match(r'^#(\d+)-(.*)$', name)
413
    if match:
414
        version = int(match.group(1))+1
415
        name = match.group(2)
416
    return '#'+str(version)+'-'+name
417

    
418
def run_query_into(db, query, params, into=None, *args, **kw_args):
419
    '''Outputs a query to a temp table.
420
    For params, see run_query().
421
    '''
422
    if into == None: return run_query(db, query, params, *args, **kw_args)
423
    else: # place rows in temp table
424
        assert isinstance(into, sql_gen.Table)
425
        
426
        kw_args['recover'] = True
427
        kw_args.setdefault('log_ignore_excs', (DuplicateTableException,))
428
        
429
        temp = not db.autocommit # tables are permanent in autocommit mode
430
        # "temporary tables cannot specify a schema name", so remove schema
431
        if temp: into.schema = None
432
        
433
        while True:
434
            try:
435
                create_query = 'CREATE'
436
                if temp: create_query += ' TEMP'
437
                create_query += ' TABLE '+into.to_str(db)+' AS\n'+query
438
                
439
                return run_query(db, create_query, params, *args, **kw_args)
440
                    # CREATE TABLE AS sets rowcount to # rows in query
441
            except DuplicateTableException, e:
442
                into.name = next_version(into.name)
443
                # try again with next version of name
444

    
445
order_by_pkey = object() # tells mk_select() to order by the pkey
446

    
447
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
448

    
449
def mk_select(db, tables, fields=None, conds=None, distinct_on=[], limit=None,
450
    start=None, order_by=order_by_pkey, default_table=None):
451
    '''
452
    @param tables The single table to select from, or a list of tables to join
453
        together, with tables after the first being sql_gen.Join objects
454
    @param fields Use None to select all fields in the table
455
    @param conds WHERE conditions: [(compare_left_side, compare_right_side),...]
456
        * container can be any iterable type
457
        * compare_left_side: sql_gen.Code|str (for col name)
458
        * compare_right_side: sql_gen.ValueCond|literal value
459
    @param distinct_on The columns to SELECT DISTINCT ON, or distinct_on_all to
460
        use all columns
461
    @return tuple(query, params)
462
    '''
463
    # Parse tables param
464
    if not lists.is_seq(tables): tables = [tables]
465
    tables = list(tables) # don't modify input! (list() copies input)
466
    table0 = sql_gen.as_Table(tables.pop(0)) # first table is separate
467
    
468
    # Parse other params
469
    if conds == None: conds = []
470
    elif isinstance(conds, dict): conds = conds.items()
471
    conds = list(conds) # don't modify input! (list() copies input)
472
    assert limit == None or type(limit) == int
473
    assert start == None or type(start) == int
474
    if order_by is order_by_pkey:
475
        if distinct_on != []: order_by = None
476
        else: order_by = pkey(db, table0, recover=True)
477
    
478
    query = 'SELECT'
479
    
480
    def parse_col(col): return sql_gen.as_Col(col, default_table).to_str(db)
481
    
482
    # DISTINCT ON columns
483
    if distinct_on != []:
484
        query += '\nDISTINCT'
485
        if distinct_on is not distinct_on_all:
486
            query += ' ON ('+(', '.join(map(parse_col, distinct_on)))+')'
487
    
488
    # Columns
489
    query += '\n'
490
    if fields == None: query += '*'
491
    else: query += '\n, '.join(map(parse_col, fields))
492
    
493
    # Main table
494
    query += '\nFROM '+table0.to_str(db)
495
    
496
    # Add joins
497
    left_table = table0
498
    for join_ in tables:
499
        table = join_.table
500
        
501
        # Parse special values
502
        if join_.type_ is sql_gen.filter_out: # filter no match
503
            conds.append((sql_gen.Col(table_not_null_col(db, table), table),
504
                None))
505
        
506
        query += '\n'+join_.to_str(db, left_table)
507
        
508
        left_table = table
509
    
510
    missing = True
511
    if conds != []:
512
        if len(conds) == 1: whitespace = ' '
513
        else: whitespace = '\n'
514
        query += '\n'+sql_gen.combine_conds(['('+sql_gen.ColValueCond(l, r)
515
            .to_str(db)+')' for l, r in conds], 'WHERE')
516
        missing = False
517
    if order_by != None:
518
        query += '\nORDER BY '+sql_gen.as_Col(order_by, table0).to_str(db)
519
    if limit != None: query += '\nLIMIT '+str(limit); missing = False
520
    if start != None:
521
        if start != 0: query += '\nOFFSET '+str(start)
522
        missing = False
523
    if missing: warnings.warn(DbWarning(
524
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
525
    
526
    return (query, [])
527

    
528
def select(db, *args, **kw_args):
529
    '''For params, see mk_select() and run_query()'''
530
    recover = kw_args.pop('recover', None)
531
    cacheable = kw_args.pop('cacheable', True)
532
    log_level = kw_args.pop('log_level', 2)
533
    
534
    query, params = mk_select(db, *args, **kw_args)
535
    return run_query(db, query, params, recover, cacheable, log_level=log_level)
536

    
537
def mk_insert_select(db, table, cols=None, select_query=None, params=None,
538
    returning=None, embeddable=False):
539
    '''
540
    @param returning str|None An inserted column (such as pkey) to return
541
    @param embeddable Whether the query should be embeddable as a nested SELECT.
542
        Warning: If you set this and cacheable=True when the query is run, the
543
        query will be fully cached, not just if it raises an exception.
544
    '''
545
    table = sql_gen.as_Table(table)
546
    if cols == []: cols = None # no cols (all defaults) = unknown col names
547
    if cols != None: cols = [sql_gen.as_Col(v).to_str(db) for v in cols]
548
    if select_query == None: select_query = 'DEFAULT VALUES'
549
    if returning != None: returning = sql_gen.as_Col(returning, table)
550
    
551
    # Build query
552
    first_line = 'INSERT INTO '+table.to_str(db)
553
    query = first_line
554
    if cols != None: query += '\n('+', '.join(cols)+')'
555
    query += '\n'+select_query
556
    
557
    if returning != None:
558
        returning_name = copy.copy(returning)
559
        returning_name.table = None
560
        returning_name = returning_name.to_str(db)
561
        query += '\nRETURNING '+returning_name
562
    
563
    if embeddable:
564
        assert returning != None
565
        
566
        # Create function
567
        function_name = sql_gen.clean_name(first_line)
568
        return_type = 'SETOF '+returning.to_str(db)+'%TYPE'
569
        while True:
570
            try:
571
                func_schema = None
572
                if not db.autocommit: func_schema = 'pg_temp'
573
                function = sql_gen.Table(function_name, func_schema).to_str(db)
574
                
575
                function_query = '''\
576
CREATE FUNCTION '''+function+'''()
577
RETURNS '''+return_type+'''
578
LANGUAGE sql
579
AS $$
580
'''+mogrify(db, query, params)+''';
581
$$;
582
'''
583
                run_query(db, function_query, recover=True, cacheable=True,
584
                    log_ignore_excs=(DuplicateFunctionException,))
585
                break # this version was successful
586
            except DuplicateFunctionException, e:
587
                function_name = next_version(function_name)
588
                # try again with next version of name
589
        
590
        # Return query that uses function
591
        func_table = sql_gen.NamedTable('f', sql_gen.CustomCode(function+'()'),
592
            [returning_name]) # AS clause requires function alias
593
        return mk_select(db, func_table, start=0, order_by=None)
594
    
595
    return (query, params)
596

    
597
def insert_select(db, *args, **kw_args):
598
    '''For params, see mk_insert_select() and run_query_into()
599
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
600
        values in
601
    '''
602
    into = kw_args.pop('into', None)
603
    if into != None: kw_args['embeddable'] = True
604
    recover = kw_args.pop('recover', None)
605
    cacheable = kw_args.pop('cacheable', True)
606
    
607
    query, params = mk_insert_select(db, *args, **kw_args)
608
    return run_query_into(db, query, params, into, recover=recover,
609
        cacheable=cacheable)
610

    
611
default = object() # tells insert() to use the default value for a column
612

    
613
def insert(db, table, row, *args, **kw_args):
614
    '''For params, see insert_select()'''
615
    if lists.is_seq(row): cols = None
616
    else:
617
        cols = row.keys()
618
        row = row.values()
619
    row = list(row) # ensure that "!= []" works
620
    
621
    # Check for special values
622
    labels = []
623
    values = []
624
    for value in row:
625
        if value is default: labels.append('DEFAULT')
626
        else:
627
            labels.append('%s')
628
            values.append(value)
629
    
630
    # Build query
631
    if values != []: query = 'VALUES ('+(', '.join(labels))+')'
632
    else: query = None
633
    
634
    return insert_select(db, table, cols, query, values, *args, **kw_args)
635

    
636
def mk_update(db, table, changes=None, cond=None):
637
    '''
638
    @param changes [(col, new_value),...]
639
        * container can be any iterable type
640
        * col: sql_gen.Code|str (for col name)
641
        * new_value: sql_gen.Code|literal value
642
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
643
    @return str query
644
    '''
645
    query = 'UPDATE '+sql_gen.as_Table(table).to_str(db)+'\nSET\n'
646
    query += ',\n'.join((sql_gen.to_name_only_col(col, table).to_str(db)+' = '
647
        +sql_gen.as_Value(new_value).to_str(db) for col, new_value in changes))
648
    if cond != None: query += '\nWHERE\n'+cond.to_str(db)
649
    
650
    return query
651

    
652
def update(db, *args, **kw_args):
653
    '''For params, see mk_update() and run_query()'''
654
    recover = kw_args.pop('recover', None)
655
    
656
    return run_query(db, mk_update(db, *args, **kw_args), [], recover)
657

    
658
def last_insert_id(db):
659
    module = util.root_module(db.db)
660
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
661
    elif module == 'MySQLdb': return db.insert_id()
662
    else: return None
663

    
664
def truncate(db, table, schema='public'):
665
    return run_query(db, 'TRUNCATE '+qual_name(db, schema, table)+' CASCADE')
666

    
667
def mk_flatten_mapping(db, into, cols, preserve=[], as_items=False):
668
    '''Creates a mapping from original column names (which may have collisions)
669
    to names that will be distinct among the columns' tables.
670
    This is meant to be used for several tables that are being joined together.
671
    @param cols The columns to combine. Duplicates will be removed.
672
    @param into The table for the new columns.
673
    @param preserve [sql_gen.Col...] Columns not to rename. Note that these
674
        columns will be included in the mapping even if they are not in cols.
675
        The tables of the provided Col objects will be changed to into, so make
676
        copies of them if you want to keep the original tables.
677
    @param as_items Whether to return a list of dict items instead of a dict
678
    @return dict(orig_col=new_col, ...)
679
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
680
        * new_col: sql_gen.Col(orig_col_name, into)
681
        * All mappings use the into table so its name can easily be
682
          changed for all columns at once
683
    '''
684
    cols = lists.uniqify(cols)
685
    
686
    items = []
687
    for col in preserve:
688
        orig_col = copy.copy(col)
689
        col.table = into
690
        items.append((orig_col, col))
691
    preserve = set(preserve)
692
    for col in cols:
693
        if col not in preserve: items.append((col, sql_gen.Col(str(col), into)))
694
    
695
    if not as_items: items = dict(items)
696
    return items
697

    
698
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
699
    '''For params, see mk_flatten_mapping()
700
    @return See return value of mk_flatten_mapping()
701
    '''
702
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
703
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
704
    run_query_into(db, *mk_select(db, joins, cols, limit=limit, start=start),
705
        into=into)
706
    return dict(items)
707

    
708
##### Database structure queries
709

    
710
def table_row_count(db, table, recover=None):
711
    return value(run_query(db, *mk_select(db, table, [sql_gen.row_count],
712
        order_by=None, start=0), recover=recover, log_level=3))
713

    
714
def table_cols(db, table, recover=None):
715
    return list(col_names(select(db, table, limit=0, order_by=None,
716
        recover=recover, log_level=4)))
717

    
718
def pkey(db, table, recover=None):
719
    '''Assumed to be first column in table'''
720
    return table_cols(db, table, recover)[0]
721

    
722
not_null_col = 'not_null_col'
723

    
724
def table_not_null_col(db, table, recover=None):
725
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
726
    if not_null_col in table_cols(db, table, recover): return not_null_col
727
    else: return pkey(db, table, recover)
728

    
729
def index_cols(db, table, index):
730
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
731
    automatically created. When you don't know whether something is a UNIQUE
732
    constraint or a UNIQUE index, use this function.'''
733
    module = util.root_module(db.db)
734
    if module == 'psycopg2':
735
        return list(values(run_query(db, '''\
736
SELECT attname
737
FROM
738
(
739
        SELECT attnum, attname
740
        FROM pg_index
741
        JOIN pg_class index ON index.oid = indexrelid
742
        JOIN pg_class table_ ON table_.oid = indrelid
743
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
744
        WHERE
745
            table_.relname = %(table)s
746
            AND index.relname = %(index)s
747
    UNION
748
        SELECT attnum, attname
749
        FROM
750
        (
751
            SELECT
752
                indrelid
753
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
754
                    AS indkey
755
            FROM pg_index
756
            JOIN pg_class index ON index.oid = indexrelid
757
            JOIN pg_class table_ ON table_.oid = indrelid
758
            WHERE
759
                table_.relname = %(table)s
760
                AND index.relname = %(index)s
761
        ) s
762
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
763
) s
764
ORDER BY attnum
765
''',
766
            {'table': table, 'index': index}, cacheable=True, log_level=4)))
767
    else: raise NotImplementedError("Can't list index columns for "+module+
768
        ' database')
769

    
770
def constraint_cols(db, table, constraint):
771
    module = util.root_module(db.db)
772
    if module == 'psycopg2':
773
        return list(values(run_query(db, '''\
774
SELECT attname
775
FROM pg_constraint
776
JOIN pg_class ON pg_class.oid = conrelid
777
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
778
WHERE
779
    relname = %(table)s
780
    AND conname = %(constraint)s
781
ORDER BY attnum
782
''',
783
            {'table': table, 'constraint': constraint})))
784
    else: raise NotImplementedError("Can't list constraint columns for "+module+
785
        ' database')
786

    
787
row_num_col = '_row_num'
788

    
789
def add_index(db, expr):
790
    '''Adds an index on a column or expression if it doesn't already exist.
791
    Currently, only function calls are supported as expressions.
792
    '''
793
    expr = copy.copy(expr) # don't modify input!
794
    
795
    # Extract col
796
    if isinstance(expr, sql_gen.FunctionCall):
797
        col = expr.args[0]
798
        expr = sql_gen.Expr(expr)
799
    else: col = expr
800
    assert sql_gen.is_table_col(col)
801
    
802
    index = sql_gen.as_Table(str(expr))
803
    table = col.table
804
    col.table = None
805
    try: run_query(db, 'CREATE INDEX '+index.to_str(db)+' ON '+table.to_str(db)
806
        +' ('+expr.to_str(db)+')', recover=True, cacheable=True, log_level=3)
807
    except DuplicateTableException: pass # index already existed
808

    
809
def index_pkey(db, table, recover=None):
810
    '''Makes the first column in a table the primary key.
811
    @pre The table must not already have a primary key.
812
    '''
813
    table = sql_gen.as_Table(table)
814
    
815
    index = sql_gen.as_Table(table.name+'_pkey')
816
    col = sql_gen.to_name_only_col(pkey(db, table, recover))
817
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD CONSTRAINT '
818
        +index.to_str(db)+' PRIMARY KEY('+col.to_str(db)+')', recover=recover,
819
        log_level=3)
820

    
821
def add_row_num(db, table):
822
    '''Adds a row number column to a table. Its name is in row_num_col. It will
823
    be the primary key.'''
824
    table = sql_gen.as_Table(table).to_str(db)
825
    run_query(db, 'ALTER TABLE '+table+' ADD COLUMN '+row_num_col
826
        +' serial NOT NULL PRIMARY KEY', log_level=3)
827

    
828
def tables(db, schema_like='public', table_like='%'):
829
    module = util.root_module(db.db)
830
    params = {'schema_like': schema_like, 'table_like': table_like}
831
    if module == 'psycopg2':
832
        return values(run_query(db, '''\
833
SELECT tablename
834
FROM pg_tables
835
WHERE
836
    schemaname LIKE %(schema_like)s
837
    AND tablename LIKE %(table_like)s
838
ORDER BY tablename
839
''',
840
            params, cacheable=True))
841
    elif module == 'MySQLdb':
842
        return values(run_query(db, 'SHOW TABLES LIKE %(table_like)s', params,
843
            cacheable=True))
844
    else: raise NotImplementedError("Can't list tables for "+module+' database')
845

    
846
##### Database management
847

    
848
def empty_db(db, schema='public', **kw_args):
849
    '''For kw_args, see tables()'''
850
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
851

    
852
##### Heuristic queries
853

    
854
def put(db, table, row, pkey_=None, row_ct_ref=None):
855
    '''Recovers from errors.
856
    Only works under PostgreSQL (uses INSERT RETURNING).
857
    '''
858
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
859
    
860
    try:
861
        cur = insert(db, table, row, pkey_, recover=True)
862
        if row_ct_ref != None and cur.rowcount >= 0:
863
            row_ct_ref[0] += cur.rowcount
864
        return value(cur)
865
    except DuplicateKeyException, e:
866
        return value(select(db, table, [pkey_],
867
            util.dict_subset_right_join(row, e.cols), recover=True))
868

    
869
def get(db, table, row, pkey, row_ct_ref=None, create=False):
870
    '''Recovers from errors'''
871
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
872
    except StopIteration:
873
        if not create: raise
874
        return put(db, table, row, pkey, row_ct_ref) # insert new row
875

    
876
def put_table(db, out_table, in_tables, mapping, row_ct_ref=None, into=None,
877
    default=None, is_func=False):
878
    '''Recovers from errors.
879
    Only works under PostgreSQL (uses INSERT RETURNING).
880
    @param in_tables The main input table to select from, followed by a list of
881
        tables to join with it using the main input table's pkey
882
    @param mapping dict(out_table_col=in_table_col, ...)
883
        * out_table_col: sql_gen.Col|str
884
        * in_table_col: sql_gen.Col Wrap literal values in a sql_gen.NamedCol
885
    @param into The table to contain the output and input pkeys.
886
        Defaults to `out_table.name+'_pkeys'`.
887
    @param default The *output* column to use as the pkey for missing rows.
888
        If this output column does not exist in the mapping, uses None.
889
    @param is_func Whether out_table is the name of a SQL function, not a table
890
    @return sql_gen.Col Where the output pkeys are made available
891
    '''
892
    out_table = sql_gen.as_Table(out_table)
893
    mapping = sql_gen.ColDict(mapping)
894
    if into == None:
895
        into = out_table.name
896
        if is_func: into += '()'
897
        else: into += '_pkeys'
898
    into = sql_gen.as_Table(into)
899
    
900
    def log_debug(msg): db.log_debug(msg, level=1.5)
901
    def col_ustr(str_):
902
        return strings.repr_no_u(sql_gen.remove_col_rename(str_))
903
    
904
    log_debug('********** New iteration **********')
905
    log_debug('Inserting these input columns into '+strings.as_tt(
906
        out_table.to_str(db))+':\n'+strings.as_table(mapping, ustr=col_ustr))
907
    
908
    # Create input joins from list of input tables
909
    in_tables_ = in_tables[:] # don't modify input!
910
    in_tables0 = in_tables_.pop(0) # first table is separate
911
    in_pkey = pkey(db, in_tables0, recover=True)
912
    in_pkey_col = sql_gen.as_Col(in_pkey, in_tables0)
913
    input_joins = [in_tables0]+[sql_gen.Join(v,
914
        {in_pkey: sql_gen.join_same_not_null}) for v in in_tables_]
915
    
916
    log_debug('Joining together input tables into temp table')
917
    # Place in new table for speed and so don't modify input if values edited
918
    in_table = sql_gen.Table(into.name.replace('_pkeys', '')+'_input')
919
    flatten_cols = filter(sql_gen.is_table_col, mapping.values())
920
    mapping = dicts.join(mapping, flatten(db, in_table, input_joins,
921
        flatten_cols, preserve=[in_pkey_col], start=0))
922
    input_joins = [in_table]
923
    db.log_debug('Temp table: '+strings.as_tt(in_table.to_str(db)), level=2)
924
    
925
    # Resolve default value column
926
    try: default = mapping[default]
927
    except KeyError:
928
        if default != None:
929
            db.log_debug('Default value column '
930
                +strings.as_tt(strings.repr_no_u(default))
931
                +' does not exist in mapping, falling back to None', level=2.1)
932
            default = None
933
    
934
    out_pkey = pkey(db, out_table, recover=True)
935
    out_pkey_col = sql_gen.as_Col(out_pkey, out_table)
936
    
937
    pkeys_names = [in_pkey, out_pkey]
938
    pkeys_cols = [in_pkey_col, out_pkey_col]
939
    
940
    pkeys_table_exists_ref = [False]
941
    def insert_into_pkeys(joins, cols):
942
        query, params = mk_select(db, joins, cols, order_by=None, start=0)
943
        if pkeys_table_exists_ref[0]:
944
            insert_select(db, into, pkeys_names, query, params)
945
        else:
946
            run_query_into(db, query, params, into=into)
947
            pkeys_table_exists_ref[0] = True
948
    
949
    limit_ref = [None]
950
    conds = set()
951
    distinct_on = []
952
    def mk_main_select(joins, cols):
953
        return mk_select(db, joins, cols, conds, distinct_on,
954
            limit=limit_ref[0], start=0)
955
    
956
    exc_strs = set()
957
    def log_exc(e):
958
        e_str = exc.str_(e, first_line_only=True)
959
        log_debug('Caught exception: '+e_str)
960
        assert e_str not in exc_strs # avoid infinite loops
961
        exc_strs.add(e_str)
962
    def remove_all_rows():
963
        log_debug('Returning NULL for all rows')
964
        limit_ref[0] = 0 # just create an empty pkeys table
965
    def ignore(in_col, value):
966
        in_col_str = strings.as_tt(repr(in_col))
967
        db.log_debug('Adding index on '+in_col_str+' to enable fast filtering',
968
            level=2.5)
969
        add_index(db, in_col)
970
        log_debug('Ignoring rows with '+in_col_str+' = '
971
            +strings.as_tt(repr(value)))
972
    def remove_rows(in_col, value):
973
        ignore(in_col, value)
974
        cond = (in_col, sql_gen.CompareCond(value, '!='))
975
        assert cond not in conds # avoid infinite loops
976
        conds.add(cond)
977
    def invalid2null(in_col, value):
978
        ignore(in_col, value)
979
        update(db, in_table, [(in_col, None)],
980
            sql_gen.ColValueCond(in_col, value))
981
    
982
    # Do inserts and selects
983
    join_cols = sql_gen.ColDict()
984
    insert_out_pkeys = sql_gen.Table(into.name+'_insert_out_pkeys')
985
    insert_in_pkeys = sql_gen.Table(into.name+'_insert_in_pkeys')
986
    while True:
987
        if limit_ref[0] == 0: # special case
988
            log_debug('Creating an empty pkeys table')
989
            cur = run_query_into(db, *mk_select(db, out_table, [out_pkey],
990
                limit=limit_ref[0]), into=insert_out_pkeys)
991
            break # don't do main case
992
        
993
        has_joins = join_cols != {}
994
        
995
        # Prepare to insert new rows
996
        insert_joins = input_joins[:] # don't modify original!
997
        insert_args = dict(recover=True, cacheable=False)
998
        if has_joins:
999
            distinct_on = [v.to_Col() for v in join_cols.values()]
1000
            insert_joins.append(sql_gen.Join(out_table, join_cols,
1001
                sql_gen.filter_out))
1002
        else:
1003
            insert_args.update(dict(returning=out_pkey, into=insert_out_pkeys))
1004
        main_select = mk_main_select(insert_joins, mapping.values())[0]
1005
        
1006
        log_debug('Trying to insert new rows')
1007
        try:
1008
            cur = insert_select(db, out_table, mapping.keys(), main_select,
1009
                **insert_args)
1010
            break # insert successful
1011
        except DuplicateKeyException, e:
1012
            log_exc(e)
1013
            
1014
            old_join_cols = join_cols.copy()
1015
            join_cols.update(util.dict_subset_right_join(mapping, e.cols))
1016
            log_debug('Ignoring existing rows, comparing on these columns:\n'
1017
                +strings.as_inline_table(join_cols, ustr=col_ustr))
1018
            assert join_cols != old_join_cols # avoid infinite loops
1019
        except NullValueException, e:
1020
            log_exc(e)
1021
            
1022
            out_col, = e.cols
1023
            try: in_col = mapping[out_col]
1024
            except KeyError:
1025
                log_debug('Missing mapping for NOT NULL column '+out_col)
1026
                remove_all_rows()
1027
            else: remove_rows(in_col, None)
1028
        except FunctionValueException, e:
1029
            log_exc(e)
1030
            
1031
            func_name = e.name
1032
            value = e.value
1033
            for out_col, in_col in mapping.iteritems():
1034
                invalid2null(sql_gen.unwrap_func_call(in_col, func_name), value)
1035
        except MissingCastException, e:
1036
            log_exc(e)
1037
            
1038
            out_col = e.col
1039
            mapping[out_col] = sql_gen.wrap_in_func(e.type, mapping[out_col])
1040
        except DatabaseErrors, e:
1041
            log_exc(e)
1042
            
1043
            msg = 'No handler for exception: '+exc.str_(e)
1044
            warnings.warn(DbWarning(msg))
1045
            log_debug(msg)
1046
            remove_all_rows()
1047
        # after exception handled, rerun loop with additional constraints
1048
    
1049
    if row_ct_ref != None and cur.rowcount >= 0:
1050
        row_ct_ref[0] += cur.rowcount
1051
    
1052
    if has_joins:
1053
        select_joins = input_joins+[sql_gen.Join(out_table, join_cols)]
1054
        log_debug('Getting output table pkeys of existing/inserted rows')
1055
        insert_into_pkeys(select_joins, pkeys_cols)
1056
    else:
1057
        add_row_num(db, insert_out_pkeys) # for joining with input pkeys
1058
        
1059
        log_debug('Getting input table pkeys of inserted rows')
1060
        run_query_into(db, *mk_main_select(input_joins, [in_pkey]),
1061
            into=insert_in_pkeys)
1062
        add_row_num(db, insert_in_pkeys) # for joining with output pkeys
1063
        
1064
        assert table_row_count(db, insert_out_pkeys) == table_row_count(db,
1065
            insert_in_pkeys)
1066
        
1067
        log_debug('Combining output and input pkeys in inserted order')
1068
        pkey_joins = [insert_in_pkeys, sql_gen.Join(insert_out_pkeys,
1069
            {row_num_col: sql_gen.join_same_not_null})]
1070
        insert_into_pkeys(pkey_joins, pkeys_names)
1071
    
1072
    db.log_debug('Adding pkey on pkeys table to enable fast joins', level=2.5)
1073
    index_pkey(db, into)
1074
    
1075
    log_debug('Setting pkeys of missing rows to '+strings.as_tt(repr(default)))
1076
    missing_rows_joins = input_joins+[sql_gen.Join(into,
1077
        {in_pkey: sql_gen.join_same_not_null}, sql_gen.filter_out)]
1078
        # must use join_same_not_null or query will take forever
1079
    insert_into_pkeys(missing_rows_joins,
1080
        [in_pkey_col, sql_gen.NamedCol(out_pkey, default)])
1081
    
1082
    assert table_row_count(db, into) == table_row_count(db, in_table)
1083
    
1084
    return sql_gen.Col(out_pkey, into)
1085

    
1086
##### Data cleanup
1087

    
1088
def cleanup_table(db, table, cols):
1089
    def esc_name_(name): return esc_name(db, name)
1090
    
1091
    table = sql_gen.as_Table(table).to_str(db)
1092
    cols = map(esc_name_, cols)
1093
    
1094
    run_query(db, 'UPDATE '+table+' SET\n'+(',\n'.join(('\n'+col
1095
        +' = nullif(nullif(trim(both from '+col+"), %(null0)s), %(null1)s)"
1096
            for col in cols))),
1097
        dict(null0='', null1=r'\N'))
(24-24/36)