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: '+str(name), cause)
40
        self.name = name
41

    
42
class ExceptionWithNameValue(DbException):
43
    def __init__(self, name, value, cause=None):
44
        DbException.__init__(self,
45
            'for name: '+str(name)+'; value: '+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 '+name+ ' constraint on columns: '
52
            +(', '.join(cols)), cause)
53
        self.name = name
54
        self.cols = cols
55

    
56
class NameException(DbException): pass
57

    
58
class DuplicateKeyException(ConstraintException): pass
59

    
60
class NullValueException(ConstraintException): pass
61

    
62
class FunctionValueException(ExceptionWithNameValue): pass
63

    
64
class DuplicateTableException(ExceptionWithName): pass
65

    
66
class DuplicateFunctionException(ExceptionWithName): pass
67

    
68
class EmptyRowException(DbException): pass
69

    
70
##### Warnings
71

    
72
class DbWarning(UserWarning): pass
73

    
74
##### Result retrieval
75

    
76
def col_names(cur): return (col[0] for col in cur.description)
77

    
78
def rows(cur): return iter(lambda: cur.fetchone(), None)
79

    
80
def consume_rows(cur):
81
    '''Used to fetch all rows so result will be cached'''
82
    iters.consume_iter(rows(cur))
83

    
84
def next_row(cur): return rows(cur).next()
85

    
86
def row(cur):
87
    row_ = next_row(cur)
88
    consume_rows(cur)
89
    return row_
90

    
91
def next_value(cur): return next_row(cur)[0]
92

    
93
def value(cur): return row(cur)[0]
94

    
95
def values(cur): return iters.func_iter(lambda: next_value(cur))
96

    
97
def value_or_none(cur):
98
    try: return value(cur)
99
    except StopIteration: return None
100

    
101
##### Input validation
102

    
103
def check_name(name):
104
    if re.search(r'\W', name) != None: raise NameException('Name "'+name
105
        +'" may contain only alphanumeric characters and _')
106

    
107
def esc_name_by_module(module, name, ignore_case=False):
108
    if module == 'psycopg2':
109
        if ignore_case:
110
            # Don't enclose in quotes because this disables case-insensitivity
111
            check_name(name)
112
            return name
113
        else: quote = '"'
114
    elif module == 'MySQLdb': quote = '`'
115
    else: raise NotImplementedError("Can't escape name for "+module+' database')
116
    return quote + name.replace(quote, '') + quote
117

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

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

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

    
130
##### Database connections
131

    
132
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
133

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

    
139
DatabaseErrors_set = set([DbException])
140
DatabaseErrors = tuple(DatabaseErrors_set)
141

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

    
147
def db_config_str(db_config):
148
    return db_config['engine']+' database '+db_config['database']
149

    
150
def _query_lookup(query, params): return (query, dicts.make_hashable(params))
151

    
152
log_debug_none = lambda msg: None
153

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

    
330
connect = DbConn
331

    
332
##### Querying
333

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

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

    
344
##### Recoverable querying
345

    
346
def with_savepoint(db, func): return db.with_savepoint(func)
347

    
348
def run_query(db, query, params=None, recover=None, cacheable=False):
349
    if recover == None: recover = False
350
    
351
    try:
352
        def run(): return run_raw_query(db, query, params, cacheable)
353
        if recover and not db.is_cached(query, params):
354
            return with_savepoint(db, run)
355
        else: return run() # don't need savepoint if cached
356
    except Exception, e:
357
        if not recover: raise # need savepoint to run index_cols()
358
        msg = exc.str_(e)
359
        
360
        match = re.search(r'duplicate key value violates unique constraint '
361
            r'"((_?[^\W_]+)_[^"]+?)"', msg)
362
        if match:
363
            constraint, table = match.groups()
364
            try: cols = index_cols(db, table, constraint)
365
            except NotImplementedError: raise e
366
            else: raise DuplicateKeyException(constraint, cols, e)
367
        
368
        match = re.search(r'null value in column "(\w+?)" violates not-null '
369
            r'constraint', msg)
370
        if match: raise NullValueException('NOT NULL', [match.group(1)], e)
371
        
372
        match = re.search(r'\b(?:invalid input (?:syntax|value)\b.*?'
373
            r'|date/time field value out of range): "(.+?)"\n'
374
            r'(?:(?s).*?)\bfunction "(\w+?)".*?\bat assignment', msg)
375
        if match:
376
            value, name = match.groups()
377
            raise FunctionValueException(name, strings.to_unicode(value), e)
378
        
379
        match = re.search(r'relation "(\w+?)" already exists', msg)
380
        if match: raise DuplicateTableException(match.group(1), e)
381
        
382
        match = re.search(r'function "(\w+?)" already exists', msg)
383
        if match: raise DuplicateFunctionException(match.group(1), e)
384
        
385
        raise # no specific exception raised
386

    
387
##### Basic queries
388

    
389
def next_version(name):
390
    '''Prepends the version # so it won't be removed if the name is truncated'''
391
    version = 1 # first existing name was version 0
392
    match = re.match(r'^v(\d+)_(.*)$', name)
393
    if match:
394
        version = int(match.group(1))+1
395
        name = match.group(2)
396
    return 'v'+str(version)+'_'+name
397

    
398
def run_query_into(db, query, params, into_ref=None, *args, **kw_args):
399
    '''Outputs a query to a temp table.
400
    For params, see run_query().
401
    '''
402
    if into_ref == None: return run_query(db, query, params, *args, **kw_args)
403
    else: # place rows in temp table
404
        kw_args['recover'] = True
405
        while True:
406
            try:
407
                create_query = 'CREATE'
408
                if not db.debug: create_query += ' TEMP'
409
                into = sql_gen.as_Table(into_ref[0]).to_str(db)
410
                create_query += ' TABLE '+into+' AS '+query
411
                
412
                return run_query(db, create_query, params, *args, **kw_args)
413
                    # CREATE TABLE AS sets rowcount to # rows in query
414
            except DuplicateTableException, e:
415
                into_ref[0] = next_version(into_ref[0])
416
                # try again with next version of name
417

    
418
order_by_pkey = object() # tells mk_select() to order by the pkey
419

    
420
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
421

    
422
def mk_select(db, tables, fields=None, conds=None, distinct_on=[], limit=None,
423
    start=None, order_by=order_by_pkey, default_table=None):
424
    '''
425
    @param tables The single table to select from, or a list of tables to join
426
        together, with tables after the first being sql_gen.Join objects
427
    @param fields Use None to select all fields in the table
428
    @param conds WHERE conditions: [(compare_left_side, compare_right_side),...]
429
        * container can be any iterable type
430
        * compare_left_side: Code|str (for col name)
431
        * compare_right_side: ValueCond|literal value
432
    @param distinct_on The columns to SELECT DISTINCT ON, or distinct_on_all to
433
        use all columns
434
    @return tuple(query, params)
435
    '''
436
    # Parse tables param
437
    if not lists.is_seq(tables): tables = [tables]
438
    tables = list(tables) # don't modify input! (list() copies input)
439
    table0 = sql_gen.as_Table(tables.pop(0)) # first table is separate
440
    
441
    # Parse other params
442
    if conds == None: conds = []
443
    elif isinstance(conds, dict): conds = conds.items()
444
    conds = list(conds) # don't modify input! (list() copies input)
445
    assert limit == None or type(limit) == int
446
    assert start == None or type(start) == int
447
    if order_by is order_by_pkey:
448
        if distinct_on != []: order_by = None
449
        else: order_by = pkey(db, table0, recover=True)
450
    
451
    query = 'SELECT'
452
    
453
    def parse_col(col): return sql_gen.as_Col(col, default_table).to_str(db)
454
    
455
    # DISTINCT ON columns
456
    if distinct_on != []:
457
        query += ' DISTINCT'
458
        if distinct_on is not distinct_on_all:
459
            query += ' ON ('+(', '.join(map(parse_col, distinct_on)))+')'
460
    
461
    # Columns
462
    query += ' '
463
    if fields == None: query += '*'
464
    else: query += ', '.join(map(parse_col, fields))
465
    
466
    # Main table
467
    query += ' FROM '+table0.to_str(db)
468
    
469
    # Add joins
470
    left_table = table0
471
    for join_ in tables:
472
        table = join_.table
473
        
474
        # Parse special values
475
        if join_.type_ is sql_gen.filter_out: # filter no match
476
            conds.append((sql_gen.Col(table_not_null_col(db, table), table),
477
                None))
478
        
479
        query += ' '+join_.to_str(db, left_table)
480
        
481
        left_table = table
482
    
483
    missing = True
484
    if conds != []:
485
        query += ' WHERE '+(' AND '.join((sql_gen.as_ValueCond(r).to_str(db, l)
486
            for l, r in conds)))
487
        missing = False
488
    if order_by != None:
489
        query += ' ORDER BY '+sql_gen.as_Col(order_by, table0).to_str(db)
490
    if limit != None: query += ' LIMIT '+str(limit); missing = False
491
    if start != None:
492
        if start != 0: query += ' OFFSET '+str(start)
493
        missing = False
494
    if missing: warnings.warn(DbWarning(
495
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
496
    
497
    return (query, [])
498

    
499
def select(db, *args, **kw_args):
500
    '''For params, see mk_select() and run_query()'''
501
    recover = kw_args.pop('recover', None)
502
    cacheable = kw_args.pop('cacheable', True)
503
    
504
    query, params = mk_select(db, *args, **kw_args)
505
    return run_query(db, query, params, recover, cacheable)
506

    
507
def mk_insert_select(db, table, cols=None, select_query=None, params=None,
508
    returning=None, embeddable=False):
509
    '''
510
    @param returning str|None An inserted column (such as pkey) to return
511
    @param embeddable Whether the query should be embeddable as a nested SELECT.
512
        Warning: If you set this and cacheable=True when the query is run, the
513
        query will be fully cached, not just if it raises an exception.
514
    '''
515
    table = sql_gen.as_Table(table)
516
    if cols == []: cols = None # no cols (all defaults) = unknown col names
517
    if cols != None: cols = [sql_gen.as_Col(v).to_str(db) for v in cols]
518
    if select_query == None: select_query = 'DEFAULT VALUES'
519
    if returning != None: returning = sql_gen.as_Col(returning, table)
520
    
521
    # Build query
522
    query = 'INSERT INTO '+table.to_str(db)
523
    if cols != None: query += ' ('+', '.join(cols)+')'
524
    query += ' '+select_query
525
    
526
    if returning != None:
527
        returning_name = copy.copy(returning)
528
        returning_name.table = None
529
        returning_name = returning_name.to_str(db)
530
        query += ' RETURNING '+returning_name
531
    
532
    if embeddable:
533
        assert returning != None
534
        
535
        # Create function
536
        function_name = '_'.join(['insert', table.name] + cols)
537
        return_type = 'SETOF '+returning.to_str(db)+'%TYPE'
538
        while True:
539
            try:
540
                func_schema = None
541
                if not db.debug: func_schema = 'pg_temp'
542
                function = sql_gen.Table(function_name, func_schema).to_str(db)
543
                
544
                function_query = '''\
545
CREATE FUNCTION '''+function+'''() RETURNS '''+return_type+'''
546
    LANGUAGE sql
547
    AS $$'''+mogrify(db, query, params)+''';$$;
548
'''
549
                run_query(db, function_query, recover=True, cacheable=True)
550
                break # this version was successful
551
            except DuplicateFunctionException, e:
552
                function_name = next_version(function_name)
553
                # try again with next version of name
554
        
555
        # Return query that uses function
556
        func_table = sql_gen.NamedTable('f', sql_gen.CustomCode(function+'()'),
557
            [returning_name]) # AS clause requires function alias
558
        return mk_select(db, func_table, start=0, order_by=None)
559
    
560
    return (query, params)
561

    
562
def insert_select(db, *args, **kw_args):
563
    '''For params, see mk_insert_select() and run_query_into()
564
    @param into_ref List with name of temp table to place RETURNING values in
565
    '''
566
    into_ref = kw_args.pop('into_ref', None)
567
    if into_ref != None: kw_args['embeddable'] = True
568
    recover = kw_args.pop('recover', None)
569
    cacheable = kw_args.pop('cacheable', True)
570
    
571
    query, params = mk_insert_select(db, *args, **kw_args)
572
    return run_query_into(db, query, params, into_ref, recover=recover,
573
        cacheable=cacheable)
574

    
575
default = object() # tells insert() to use the default value for a column
576

    
577
def insert(db, table, row, *args, **kw_args):
578
    '''For params, see insert_select()'''
579
    if lists.is_seq(row): cols = None
580
    else:
581
        cols = row.keys()
582
        row = row.values()
583
    row = list(row) # ensure that "!= []" works
584
    
585
    # Check for special values
586
    labels = []
587
    values = []
588
    for value in row:
589
        if value is default: labels.append('DEFAULT')
590
        else:
591
            labels.append('%s')
592
            values.append(value)
593
    
594
    # Build query
595
    if values != []: query = ' VALUES ('+(', '.join(labels))+')'
596
    else: query = None
597
    
598
    return insert_select(db, table, cols, query, values, *args, **kw_args)
599

    
600
def last_insert_id(db):
601
    module = util.root_module(db.db)
602
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
603
    elif module == 'MySQLdb': return db.insert_id()
604
    else: return None
605

    
606
def truncate(db, table, schema='public'):
607
    return run_query(db, 'TRUNCATE '+qual_name(db, schema, table)+' CASCADE')
608

    
609
##### Database structure queries
610

    
611
def table_cols(db, table, recover=None):
612
    return list(col_names(select(db, table, limit=0, order_by=None,
613
        recover=recover)))
614

    
615
def mk_flatten_mapping(db, tables, flat_table):
616
    '''Creates a mapping from original column names (which may have collisions)
617
    to names that will be distinct among the given tables.
618
    This is meant to be used for several tables that are being joined together.
619
    @param flat_table The table for the new columns
620
    @return dict(orig_col=new_col, ...)
621
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
622
        * new_col: sql_gen.Col(orig_col_name, flat_table)
623
        * All mappings use the flat_table table so its name can easily be
624
          changed for all columns at once
625
    '''
626
    flatten_mapping = {}
627
    for table in tables:
628
        for col in table_cols(db, table):
629
            col = sql_gen.as_Col(col, table)
630
            flatten_mapping[col] = sql_gen.Col(str(col), flat_table)
631
    return flatten_mapping
632

    
633
def pkey(db, table, recover=None):
634
    '''Assumed to be first column in table'''
635
    return table_cols(db, table, recover)[0]
636

    
637
not_null_col = 'not_null'
638

    
639
def table_not_null_col(db, table, recover=None):
640
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
641
    if not_null_col in table_cols(db, table, recover): return not_null_col
642
    else: return pkey(db, table, recover)
643

    
644
def index_cols(db, table, index):
645
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
646
    automatically created. When you don't know whether something is a UNIQUE
647
    constraint or a UNIQUE index, use this function.'''
648
    module = util.root_module(db.db)
649
    if module == 'psycopg2':
650
        return list(values(run_query(db, '''\
651
SELECT attname
652
FROM
653
(
654
        SELECT attnum, attname
655
        FROM pg_index
656
        JOIN pg_class index ON index.oid = indexrelid
657
        JOIN pg_class table_ ON table_.oid = indrelid
658
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
659
        WHERE
660
            table_.relname = %(table)s
661
            AND index.relname = %(index)s
662
    UNION
663
        SELECT attnum, attname
664
        FROM
665
        (
666
            SELECT
667
                indrelid
668
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
669
                    AS indkey
670
            FROM pg_index
671
            JOIN pg_class index ON index.oid = indexrelid
672
            JOIN pg_class table_ ON table_.oid = indrelid
673
            WHERE
674
                table_.relname = %(table)s
675
                AND index.relname = %(index)s
676
        ) s
677
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
678
) s
679
ORDER BY attnum
680
''',
681
            {'table': table, 'index': index}, cacheable=True)))
682
    else: raise NotImplementedError("Can't list index columns for "+module+
683
        ' database')
684

    
685
def constraint_cols(db, table, constraint):
686
    module = util.root_module(db.db)
687
    if module == 'psycopg2':
688
        return list(values(run_query(db, '''\
689
SELECT attname
690
FROM pg_constraint
691
JOIN pg_class ON pg_class.oid = conrelid
692
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
693
WHERE
694
    relname = %(table)s
695
    AND conname = %(constraint)s
696
ORDER BY attnum
697
''',
698
            {'table': table, 'constraint': constraint})))
699
    else: raise NotImplementedError("Can't list constraint columns for "+module+
700
        ' database')
701

    
702
row_num_col = '_row_num'
703

    
704
def add_row_num(db, table):
705
    '''Adds a row number column to a table. Its name is in row_num_col. It will
706
    be the primary key.'''
707
    table = sql_gen.as_Table(table).to_str(db)
708
    run_query(db, 'ALTER TABLE '+table+' ADD COLUMN '+row_num_col
709
        +' serial NOT NULL PRIMARY KEY')
710

    
711
def tables(db, schema='public', table_like='%'):
712
    module = util.root_module(db.db)
713
    params = {'schema': schema, 'table_like': table_like}
714
    if module == 'psycopg2':
715
        return values(run_query(db, '''\
716
SELECT tablename
717
FROM pg_tables
718
WHERE
719
    schemaname = %(schema)s
720
    AND tablename LIKE %(table_like)s
721
ORDER BY tablename
722
''',
723
            params, cacheable=True))
724
    elif module == 'MySQLdb':
725
        return values(run_query(db, 'SHOW TABLES LIKE %(table_like)s', params,
726
            cacheable=True))
727
    else: raise NotImplementedError("Can't list tables for "+module+' database')
728

    
729
##### Database management
730

    
731
def empty_db(db, schema='public', **kw_args):
732
    '''For kw_args, see tables()'''
733
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
734

    
735
##### Heuristic queries
736

    
737
def put(db, table, row, pkey_=None, row_ct_ref=None):
738
    '''Recovers from errors.
739
    Only works under PostgreSQL (uses INSERT RETURNING).
740
    '''
741
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
742
    
743
    try:
744
        cur = insert(db, table, row, pkey_, recover=True)
745
        if row_ct_ref != None and cur.rowcount >= 0:
746
            row_ct_ref[0] += cur.rowcount
747
        return value(cur)
748
    except DuplicateKeyException, e:
749
        return value(select(db, table, [pkey_],
750
            util.dict_subset_right_join(row, e.cols), recover=True))
751

    
752
def get(db, table, row, pkey, row_ct_ref=None, create=False):
753
    '''Recovers from errors'''
754
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
755
    except StopIteration:
756
        if not create: raise
757
        return put(db, table, row, pkey, row_ct_ref) # insert new row
758

    
759
def put_table(db, out_table, in_tables, mapping, limit=None, start=0,
760
    row_ct_ref=None):
761
    '''Recovers from errors.
762
    Only works under PostgreSQL (uses INSERT RETURNING).
763
    @param in_tables The main input table to select from, followed by a list of
764
        tables to join with it using the main input table's pkey
765
    @param mapping dict(out_table_col=in_table_col, ...)
766
        * out_table_col: sql_gen.Col|str
767
        * in_table_col: sql_gen.Col Wrap literal values in a sql_gen.NamedCol
768
    @return sql_gen.Col Where the output pkeys are made available
769
    '''
770
    out_table = sql_gen.as_Table(out_table)
771
    for in_table_col in mapping.itervalues():
772
        assert isinstance(in_table_col, sql_gen.Col)
773
    
774
    temp_prefix = out_table.name
775
    pkeys_ref = [temp_prefix+'_pkeys']
776
    
777
    # Create input joins from list of input tables
778
    in_tables_ = in_tables[:] # don't modify input!
779
    in_tables0 = in_tables_.pop(0) # first table is separate
780
    in_pkey = pkey(db, in_tables0, recover=True)
781
    in_pkey_col = sql_gen.as_Col(in_pkey, in_tables0)
782
    input_joins = [in_tables0]+[sql_gen.Join(v, {in_pkey: sql_gen.join_same})
783
        for v in in_tables_]
784
    
785
    out_pkey = pkey(db, out_table, recover=True)
786
    out_pkey_col = sql_gen.as_Col(out_pkey, out_table)
787
    
788
    pkeys = [in_pkey, out_pkey]
789
    pkeys_cols = [in_pkey_col, out_pkey_col]
790
    
791
    pkeys_table_exists_ref = [False]
792
    def run_query_into_pkeys(query, params):
793
        if pkeys_table_exists_ref[0]:
794
            insert_select(db, pkeys_ref[0], pkeys, query, params)
795
        else:
796
            run_query_into(db, query, params, into_ref=pkeys_ref)
797
            pkeys_table_exists_ref[0] = True
798
    
799
    conds = set()
800
    distinct_on = []
801
    def mk_main_select(joins, cols):
802
        return mk_select(db, joins, cols, conds, distinct_on, limit=limit,
803
            start=start, default_table=in_tables0)
804
    
805
    def log_exc(e):
806
        db.log_debug('Caught exception: '+exc.str_(e, first_line_only=True))
807
    def ignore(in_col, value):
808
        db.log_debug('Ignoring rows with '+str(in_col)+' = '+repr(value))
809
        cond = (in_col, sql_gen.CompareCond(value, '!='))
810
        assert cond not in conds # avoid infinite loops
811
        conds.add(cond)
812
    
813
    # Do inserts and selects
814
    join_cols = {}
815
    out_pkeys_ref = [temp_prefix+'_out_pkeys']
816
    in_pkeys_ref = [temp_prefix+'_in_pkeys']
817
    while True:
818
        has_joins = join_cols != {}
819
        
820
        # Prepare to insert new rows
821
        insert_joins = input_joins[:] # don't modify original!
822
        insert_args = dict(recover=True)
823
        if has_joins:
824
            distinct_on = [v.to_Col() for v in join_cols.values()]
825
            insert_joins.append(sql_gen.Join(out_table, join_cols,
826
                sql_gen.filter_out))
827
        else:
828
            insert_args.update(dict(returning=out_pkey, into_ref=out_pkeys_ref))
829
        
830
        db.log_debug('Inserting new rows')
831
        try:
832
            cur = insert_select(db, out_table, mapping.keys(),
833
                *mk_main_select(insert_joins, mapping.values()), **insert_args)
834
            break # insert successful
835
        except DuplicateKeyException, e:
836
            log_exc(e)
837
            
838
            old_join_cols = join_cols.copy()
839
            join_cols.update(util.dict_subset(mapping, e.cols))
840
            db.log_debug('Ignoring existing rows, comparing on '+str(join_cols))
841
            assert join_cols != old_join_cols # avoid infinite loops
842
        except NullValueException, e:
843
            log_exc(e)
844
            
845
            out_col, = e.cols
846
            try: in_col = mapping[out_col]
847
            except KeyError:
848
                db.log_debug('Missing mapping for NOT NULL '+out_col)
849
                limit = 0 # just create an empty pkeys table
850
            else: ignore(in_col, None)
851
        except FunctionValueException, e:
852
            log_exc(e)
853
            
854
            assert e.name == out_table.name
855
            out_col = 'value' # assume function param was named "value"
856
            ignore(mapping[out_col], e.value)
857
        # after exception handled, rerun loop with additional constraints
858
    
859
    if row_ct_ref != None and cur.rowcount >= 0:
860
        row_ct_ref[0] += cur.rowcount
861
    
862
    if has_joins:
863
        select_joins = input_joins+[sql_gen.Join(out_table, join_cols)]
864
        db.log_debug('Getting output pkeys of existing/inserted rows')
865
        run_query_into_pkeys(*mk_select(db, select_joins, pkeys_cols,
866
            start=0))
867
    else:
868
        add_row_num(db, out_pkeys_ref[0]) # for joining with input pkeys
869
        
870
        db.log_debug('Getting input pkeys for rows in insert')
871
        run_query_into(db, *mk_main_select(input_joins, [in_pkey]),
872
            into_ref=in_pkeys_ref)
873
        add_row_num(db, in_pkeys_ref[0]) # for joining with output pkeys
874
        
875
        db.log_debug('Joining together output and input pkeys')
876
        pkey_joins = [in_pkeys_ref[0], sql_gen.Join(out_pkeys_ref[0],
877
            {row_num_col: sql_gen.join_same_not_null})]
878
        run_query_into_pkeys(*mk_select(db, pkey_joins, pkeys, start=0))
879
    
880
    db.log_debug("Setting missing rows' pkeys to NULL")
881
    missing_rows_joins = input_joins+[sql_gen.Join(pkeys_ref[0],
882
        {in_pkey: sql_gen.join_same_not_null}, sql_gen.filter_out)]
883
        # must use join_same_not_null or query will take forever
884
    run_query_into_pkeys(*mk_select(db, missing_rows_joins,
885
        [in_pkey_col, sql_gen.NamedCol(out_pkey, None)], start=0))
886
    
887
    return sql_gen.Col(out_pkey, pkeys_ref[0])
888

    
889
##### Data cleanup
890

    
891
def cleanup_table(db, table, cols):
892
    def esc_name_(name): return esc_name(db, name)
893
    
894
    table = sql_gen.as_Table(table).to_str(db)
895
    cols = map(esc_name_, cols)
896
    
897
    run_query(db, 'UPDATE '+table+' SET\n'+(',\n'.join(('\n'+col
898
        +' = nullif(nullif(trim(both from '+col+"), %(null0)s), %(null1)s)"
899
            for col in cols))),
900
        dict(null0='', null1=r'\N'))
(23-23/35)