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):
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)
27

    
28
def _add_cursor_info(e, *args, **kw_args):
29
    '''For params, see get_cur_query()'''
30
    exc.add_msg(e, 'query: '+strings.ustr(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 ExceptionWithNameType(DbException):
50
    def __init__(self, type_, name, cause=None):
51
        DbException.__init__(self, 'for type: '+strings.as_tt(str(type_))
52
            +'; name: '+strings.as_tt(name), cause)
53
        self.type = type_
54
        self.name = name
55

    
56
class ConstraintException(DbException):
57
    def __init__(self, name, cols, cause=None):
58
        DbException.__init__(self, 'Violated '+strings.as_tt(name)
59
            +' constraint on columns: '+strings.as_tt(', '.join(cols)), cause)
60
        self.name = name
61
        self.cols = cols
62

    
63
class MissingCastException(DbException):
64
    def __init__(self, type_, col, cause=None):
65
        DbException.__init__(self, 'Missing cast to type '+strings.as_tt(type_)
66
            +' on column: '+strings.as_tt(col), cause)
67
        self.type = type_
68
        self.col = col
69

    
70
class NameException(DbException): pass
71

    
72
class DuplicateKeyException(ConstraintException): pass
73

    
74
class NullValueException(ConstraintException): pass
75

    
76
class FunctionValueException(ExceptionWithNameValue): pass
77

    
78
class DuplicateException(ExceptionWithNameType): pass
79

    
80
class EmptyRowException(DbException): pass
81

    
82
##### Warnings
83

    
84
class DbWarning(UserWarning): pass
85

    
86
##### Result retrieval
87

    
88
def col_names(cur): return (col[0] for col in cur.description)
89

    
90
def rows(cur): return iter(lambda: cur.fetchone(), None)
91

    
92
def consume_rows(cur):
93
    '''Used to fetch all rows so result will be cached'''
94
    iters.consume_iter(rows(cur))
95

    
96
def next_row(cur): return rows(cur).next()
97

    
98
def row(cur):
99
    row_ = next_row(cur)
100
    consume_rows(cur)
101
    return row_
102

    
103
def next_value(cur): return next_row(cur)[0]
104

    
105
def value(cur): return row(cur)[0]
106

    
107
def values(cur): return iters.func_iter(lambda: next_value(cur))
108

    
109
def value_or_none(cur):
110
    try: return value(cur)
111
    except StopIteration: return None
112

    
113
##### Escaping
114

    
115
def esc_name_by_module(module, name):
116
    if module == 'psycopg2' or module == None: quote = '"'
117
    elif module == 'MySQLdb': quote = '`'
118
    else: raise NotImplementedError("Can't escape name for "+module+' database')
119
    return sql_gen.esc_name(name, quote)
120

    
121
def esc_name_by_engine(engine, name, **kw_args):
122
    return esc_name_by_module(db_engines[engine][0], name, **kw_args)
123

    
124
def esc_name(db, name, **kw_args):
125
    return esc_name_by_module(util.root_module(db.db), name, **kw_args)
126

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

    
133
##### Database connections
134

    
135
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
136

    
137
db_engines = {
138
    'MySQL': ('MySQLdb', {'password': 'passwd', 'database': 'db'}),
139
    'PostgreSQL': ('psycopg2', {}),
140
}
141

    
142
DatabaseErrors_set = set([DbException])
143
DatabaseErrors = tuple(DatabaseErrors_set)
144

    
145
def _add_module(module):
146
    DatabaseErrors_set.add(module.DatabaseError)
147
    global DatabaseErrors
148
    DatabaseErrors = tuple(DatabaseErrors_set)
149

    
150
def db_config_str(db_config):
151
    return db_config['engine']+' database '+db_config['database']
152

    
153
log_debug_none = lambda msg, level=2: None
154

    
155
class DbConn:
156
    def __init__(self, db_config, autocommit=True, caching=True,
157
        log_debug=log_debug_none, debug_temp=False):
158
        '''
159
        @param debug_temp Whether temporary objects should instead be permanent.
160
            This assists in debugging the internal objects used by the program.
161
        '''
162
        self.db_config = db_config
163
        self.autocommit = autocommit
164
        self.caching = caching
165
        self.log_debug = log_debug
166
        self.debug = log_debug != log_debug_none
167
        self.debug_temp = debug_temp
168
        
169
        self.__db = None
170
        self.query_results = {}
171
        self._savepoint = 0
172
        self._notices_seen = set()
173
    
174
    def __getattr__(self, name):
175
        if name == '__dict__': raise Exception('getting __dict__')
176
        if name == 'db': return self._db()
177
        else: raise AttributeError()
178
    
179
    def __getstate__(self):
180
        state = copy.copy(self.__dict__) # shallow copy
181
        state['log_debug'] = None # don't pickle the debug callback
182
        state['_DbConn__db'] = None # don't pickle the connection
183
        return state
184
    
185
    def connected(self): return self.__db != None
186
    
187
    def _db(self):
188
        if self.__db == None:
189
            # Process db_config
190
            db_config = self.db_config.copy() # don't modify input!
191
            schemas = db_config.pop('schemas', None)
192
            module_name, mappings = db_engines[db_config.pop('engine')]
193
            module = __import__(module_name)
194
            _add_module(module)
195
            for orig, new in mappings.iteritems():
196
                try: util.rename_key(db_config, orig, new)
197
                except KeyError: pass
198
            
199
            # Connect
200
            self.__db = module.connect(**db_config)
201
            
202
            # Configure connection
203
            if hasattr(self.db, 'set_isolation_level'):
204
                import psycopg2.extensions
205
                self.db.set_isolation_level(
206
                    psycopg2.extensions.ISOLATION_LEVEL_READ_COMMITTED)
207
            if schemas != None:
208
                search_path = [self.esc_name(s) for s in schemas.split(',')]
209
                search_path.append(value(run_query(self, 'SHOW search_path',
210
                    log_level=4)))
211
                run_query(self, 'SET search_path TO '+(','.join(search_path)),
212
                    log_level=3)
213
        
214
        return self.__db
215
    
216
    class DbCursor(Proxy):
217
        def __init__(self, outer):
218
            Proxy.__init__(self, outer.db.cursor())
219
            self.outer = outer
220
            self.query_results = outer.query_results
221
            self.query_lookup = None
222
            self.result = []
223
        
224
        def execute(self, query):
225
            self._is_insert = query.startswith('INSERT')
226
            self.query_lookup = query
227
            try:
228
                try:
229
                    cur = self.inner.execute(query)
230
                    self.outer.do_autocommit()
231
                finally: self.query = get_cur_query(self.inner, query)
232
            except Exception, e:
233
                _add_cursor_info(e, self, query)
234
                self.result = e # cache the exception as the result
235
                self._cache_result()
236
                raise
237
            
238
            # Always cache certain queries
239
            if query.startswith('CREATE') or query.startswith('ALTER'):
240
                self._cache_result() # structural changes
241
            elif self.rowcount == 0 and query.startswith('SELECT'): # empty
242
                consume_rows(self) # fetch all rows so result will be cached
243
            
244
            return cur
245
        
246
        def fetchone(self):
247
            row = self.inner.fetchone()
248
            if row != None: self.result.append(row)
249
            # otherwise, fetched all rows
250
            else: self._cache_result()
251
            return row
252
        
253
        def _cache_result(self):
254
            # For inserts that return a result set, don't cache result set since
255
            # inserts are not idempotent. Other non-SELECT queries don't have
256
            # their result set read, so only exceptions will be cached (an
257
            # invalid query will always be invalid).
258
            if self.query_results != None and (not self._is_insert
259
                or isinstance(self.result, Exception)):
260
                
261
                assert self.query_lookup != None
262
                self.query_results[self.query_lookup] = self.CacheCursor(
263
                    util.dict_subset(dicts.AttrsDictView(self),
264
                    ['query', 'result', 'rowcount', 'description']))
265
        
266
        class CacheCursor:
267
            def __init__(self, cached_result): self.__dict__ = cached_result
268
            
269
            def execute(self, *args, **kw_args):
270
                if isinstance(self.result, Exception): raise self.result
271
                # otherwise, result is a rows list
272
                self.iter = iter(self.result)
273
            
274
            def fetchone(self):
275
                try: return self.iter.next()
276
                except StopIteration: return None
277
    
278
    def esc_value(self, value):
279
        try: str_ = self.mogrify('%s', [value])
280
        except NotImplementedError, e:
281
            module = util.root_module(self.db)
282
            if module == 'MySQLdb':
283
                import _mysql
284
                str_ = _mysql.escape_string(value)
285
            else: raise e
286
        return strings.to_unicode(str_)
287
    
288
    def esc_name(self, name): return esc_name(self, name) # calls global func
289
    
290
    def std_code(self, str_):
291
        '''Standardizes SQL code.
292
        * Ensures that string literals are prefixed by `E`
293
        '''
294
        if str_.startswith("'"): str_ = 'E'+str_
295
        return str_
296
    
297
    def can_mogrify(self):
298
        module = util.root_module(self.db)
299
        return module == 'psycopg2'
300
    
301
    def mogrify(self, query, params=None):
302
        if self.can_mogrify(): return self.db.cursor().mogrify(query, params)
303
        else: raise NotImplementedError("Can't mogrify query")
304
    
305
    def print_notices(self):
306
        if hasattr(self.db, 'notices'):
307
            for msg in self.db.notices:
308
                if msg not in self._notices_seen:
309
                    self._notices_seen.add(msg)
310
                    self.log_debug(msg, level=2)
311
    
312
    def run_query(self, query, cacheable=False, log_level=2,
313
        debug_msg_ref=None):
314
        '''
315
        @param log_ignore_excs The log_level will be increased by 2 if the query
316
            throws one of these exceptions.
317
        @param debug_msg_ref If specified, the log message will be returned in
318
            this instead of being output. This allows you to filter log messages
319
            depending on the result of the query.
320
        '''
321
        assert query != None
322
        
323
        if not self.caching: cacheable = False
324
        used_cache = False
325
        
326
        def log_msg(query):
327
            if used_cache: cache_status = 'cache hit'
328
            elif cacheable: cache_status = 'cache miss'
329
            else: cache_status = 'non-cacheable'
330
            return 'DB query: '+cache_status+':\n'+strings.as_code(query, 'SQL')
331
        
332
        try:
333
            # Get cursor
334
            if cacheable:
335
                try:
336
                    cur = self.query_results[query]
337
                    used_cache = True
338
                except KeyError: cur = self.DbCursor(self)
339
            else: cur = self.db.cursor()
340
            
341
            # Log query
342
            if self.debug and debug_msg_ref == None: # log before running
343
                self.log_debug(log_msg(query), log_level)
344
            
345
            # Run query
346
            cur.execute(query)
347
        finally:
348
            self.print_notices()
349
            if self.debug and debug_msg_ref != None: # return after running
350
                debug_msg_ref[0] = log_msg(str(get_cur_query(cur, query)))
351
        
352
        return cur
353
    
354
    def is_cached(self, query): return query in self.query_results
355
    
356
    def with_autocommit(self, func):
357
        import psycopg2.extensions
358
        
359
        prev_isolation_level = self.db.isolation_level
360
        self.db.set_isolation_level(
361
            psycopg2.extensions.ISOLATION_LEVEL_AUTOCOMMIT)
362
        try: return func()
363
        finally: self.db.set_isolation_level(prev_isolation_level)
364
    
365
    def with_savepoint(self, func):
366
        savepoint = 'level_'+str(self._savepoint)
367
        self.run_query('SAVEPOINT '+savepoint, log_level=4)
368
        self._savepoint += 1
369
        try: return func()
370
        except:
371
            self.run_query('ROLLBACK TO SAVEPOINT '+savepoint, log_level=4)
372
            raise
373
        finally:
374
            # Always release savepoint, because after ROLLBACK TO SAVEPOINT,
375
            # "The savepoint remains valid and can be rolled back to again"
376
            # (http://www.postgresql.org/docs/8.3/static/sql-rollback-to.html).
377
            self.run_query('RELEASE SAVEPOINT '+savepoint, log_level=4)
378
            
379
            self._savepoint -= 1
380
            assert self._savepoint >= 0
381
            
382
            self.do_autocommit() # OK to do this after ROLLBACK TO SAVEPOINT
383
    
384
    def do_autocommit(self):
385
        '''Autocommits if outside savepoint'''
386
        assert self._savepoint >= 0
387
        if self.autocommit and self._savepoint == 0:
388
            self.log_debug('Autocommitting', level=4)
389
            self.db.commit()
390
    
391
    def col_info(self, col):
392
        table = sql_gen.Table('columns', 'information_schema')
393
        cols = ['data_type', 'column_default',
394
            cast(self, 'boolean', 'is_nullable')]
395
        
396
        conds = [('table_name', col.table.name), ('column_name', col.name)]
397
        schema = col.table.schema
398
        if schema != None: conds.append(('table_schema', schema))
399
        
400
        type_, default, nullable = row(select(self, table, cols, conds,
401
            order_by='table_schema', limit=1, log_level=4))
402
            # TODO: order_by search_path schema order
403
        default = sql_gen.as_Code(default, self)
404
        
405
        return sql_gen.TypedCol(col.name, type_, default, nullable)
406
    
407
    def TempFunction(self, name):
408
        if self.debug_temp: schema = None
409
        else: schema = 'pg_temp'
410
        return sql_gen.Function(name, schema)
411

    
412
connect = DbConn
413

    
414
##### Recoverable querying
415

    
416
def with_savepoint(db, func): return db.with_savepoint(func)
417

    
418
def run_query(db, query, recover=None, cacheable=False, log_level=2,
419
    log_ignore_excs=None, **kw_args):
420
    '''For params, see DbConn.run_query()'''
421
    if recover == None: recover = False
422
    if log_ignore_excs == None: log_ignore_excs = ()
423
    log_ignore_excs = tuple(log_ignore_excs)
424
    
425
    debug_msg_ref = None # usually, db.run_query() logs query before running it
426
    # But if filtering with log_ignore_excs, wait until after exception parsing
427
    if log_ignore_excs != () or not db.can_mogrify(): debug_msg_ref = [None]
428
    
429
    try:
430
        try:
431
            def run(): return db.run_query(query, cacheable, log_level,
432
                debug_msg_ref, **kw_args)
433
            if recover and not db.is_cached(query):
434
                return with_savepoint(db, run)
435
            else: return run() # don't need savepoint if cached
436
        except Exception, e:
437
            if not recover: raise # need savepoint to run index_cols()
438
            msg = exc.str_(e)
439
            
440
            match = re.search(r'duplicate key value violates unique constraint '
441
                r'"((_?[^\W_]+)_.+?)"', msg)
442
            if match:
443
                constraint, table = match.groups()
444
                try: cols = index_cols(db, table, constraint)
445
                except NotImplementedError: raise e
446
                else: raise DuplicateKeyException(constraint, cols, e)
447
            
448
            match = re.search(r'null value in column "(.+?)" violates not-null'
449
                r' constraint', msg)
450
            if match: raise NullValueException('NOT NULL', [match.group(1)], e)
451
            
452
            match = re.search(r'\b(?:invalid input (?:syntax|value)\b.*?'
453
                r'|date/time field value out of range): "(.+?)"\n'
454
                r'(?:(?s).*?)\bfunction "(.+?)"', msg)
455
            if match:
456
                value, name = match.groups()
457
                raise FunctionValueException(name, strings.to_unicode(value), e)
458
            
459
            match = re.search(r'column "(.+?)" is of type (.+?) but expression '
460
                r'is of type', msg)
461
            if match:
462
                col, type_ = match.groups()
463
                raise MissingCastException(type_, col, e)
464
            
465
            match = re.search(r'\b(\S+) "(.+?)".*? already exists', msg)
466
            if match:
467
                type_, name = match.groups()
468
                raise DuplicateException(type_, name, e)
469
            
470
            raise # no specific exception raised
471
    except log_ignore_excs:
472
        log_level += 2
473
        raise
474
    finally:
475
        if debug_msg_ref != None and debug_msg_ref[0] != None:
476
            db.log_debug(debug_msg_ref[0], log_level)
477

    
478
##### Basic queries
479

    
480
def next_version(name):
481
    version = 1 # first existing name was version 0
482
    match = re.match(r'^(.*)#(\d+)$', name)
483
    if match:
484
        name, version = match.groups()
485
        version = int(version)+1
486
    return sql_gen.concat(name, '#'+str(version))
487

    
488
def lock_table(db, table, mode):
489
    table = sql_gen.as_Table(table)
490
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
491

    
492
def run_query_into(db, query, into=None, add_indexes_=False, **kw_args):
493
    '''Outputs a query to a temp table.
494
    For params, see run_query().
495
    '''
496
    if into == None: return run_query(db, query, **kw_args)
497
    
498
    assert isinstance(into, sql_gen.Table)
499
    
500
    into.is_temp = True
501
    
502
    kw_args['recover'] = True
503
    kw_args.setdefault('log_ignore_excs', (DuplicateException,))
504
    
505
    temp = not db.debug_temp # tables are permanent in debug_temp mode
506
    # "temporary tables cannot specify a schema name", so remove schema
507
    if temp: into.schema = None
508
    
509
    # Create table
510
    while True:
511
        create_query = 'CREATE'
512
        if temp: create_query += ' TEMP'
513
        create_query += ' TABLE '+into.to_str(db)+' AS\n'+query
514
        
515
        try:
516
            cur = run_query(db, create_query, **kw_args)
517
                # CREATE TABLE AS sets rowcount to # rows in query
518
            break
519
        except DuplicateException, e:
520
            into.name = next_version(into.name)
521
            # try again with next version of name
522
    
523
    if add_indexes_: add_indexes(db, into)
524
    
525
    return cur
526

    
527
order_by_pkey = object() # tells mk_select() to order by the pkey
528

    
529
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
530

    
531
def mk_select(db, tables, fields=None, conds=None, distinct_on=[], limit=None,
532
    start=None, order_by=order_by_pkey, default_table=None):
533
    '''
534
    @param tables The single table to select from, or a list of tables to join
535
        together, with tables after the first being sql_gen.Join objects
536
    @param fields Use None to select all fields in the table
537
    @param conds WHERE conditions: [(compare_left_side, compare_right_side),...]
538
        * container can be any iterable type
539
        * compare_left_side: sql_gen.Code|str (for col name)
540
        * compare_right_side: sql_gen.ValueCond|literal value
541
    @param distinct_on The columns to SELECT DISTINCT ON, or distinct_on_all to
542
        use all columns
543
    @return query
544
    '''
545
    # Parse tables param
546
    tables = lists.mk_seq(tables)
547
    tables = list(tables) # don't modify input! (list() copies input)
548
    table0 = sql_gen.as_Table(tables.pop(0)) # first table is separate
549
    
550
    # Parse other params
551
    if conds == None: conds = []
552
    elif dicts.is_dict(conds): conds = conds.items()
553
    conds = list(conds) # don't modify input! (list() copies input)
554
    assert limit == None or type(limit) == int
555
    assert start == None or type(start) == int
556
    if order_by is order_by_pkey:
557
        if distinct_on != []: order_by = None
558
        else: order_by = pkey(db, table0, recover=True)
559
    
560
    query = 'SELECT'
561
    
562
    def parse_col(col): return sql_gen.as_Col(col, default_table).to_str(db)
563
    
564
    # DISTINCT ON columns
565
    if distinct_on != []:
566
        query += '\nDISTINCT'
567
        if distinct_on is not distinct_on_all:
568
            query += ' ON ('+(', '.join(map(parse_col, distinct_on)))+')'
569
    
570
    # Columns
571
    query += '\n'
572
    if fields == None: query += '*'
573
    else:
574
        assert fields != []
575
        query += '\n, '.join(map(parse_col, fields))
576
    
577
    # Main table
578
    query += '\nFROM '+table0.to_str(db)
579
    
580
    # Add joins
581
    left_table = table0
582
    for join_ in tables:
583
        table = join_.table
584
        
585
        # Parse special values
586
        if join_.type_ is sql_gen.filter_out: # filter no match
587
            conds.append((sql_gen.Col(table_not_null_col(db, table), table),
588
                sql_gen.CompareCond(None, '~=')))
589
        
590
        query += '\n'+join_.to_str(db, left_table)
591
        
592
        left_table = table
593
    
594
    missing = True
595
    if conds != []:
596
        if len(conds) == 1: whitespace = ' '
597
        else: whitespace = '\n'
598
        query += '\n'+sql_gen.combine_conds([sql_gen.ColValueCond(l, r)
599
            .to_str(db) for l, r in conds], 'WHERE')
600
        missing = False
601
    if order_by != None:
602
        query += '\nORDER BY '+sql_gen.as_Col(order_by, table0).to_str(db)
603
    if limit != None: query += '\nLIMIT '+str(limit); missing = False
604
    if start != None:
605
        if start != 0: query += '\nOFFSET '+str(start)
606
        missing = False
607
    if missing: warnings.warn(DbWarning(
608
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
609
    
610
    return query
611

    
612
def select(db, *args, **kw_args):
613
    '''For params, see mk_select() and run_query()'''
614
    recover = kw_args.pop('recover', None)
615
    cacheable = kw_args.pop('cacheable', True)
616
    log_level = kw_args.pop('log_level', 2)
617
    
618
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
619
        log_level=log_level)
620

    
621
def mk_insert_select(db, table, cols=None, select_query=None, returning=None,
622
    embeddable=False):
623
    '''
624
    @param returning str|None An inserted column (such as pkey) to return
625
    @param embeddable Whether the query should be embeddable as a nested SELECT.
626
        Warning: If you set this and cacheable=True when the query is run, the
627
        query will be fully cached, not just if it raises an exception.
628
    '''
629
    table = sql_gen.remove_table_rename(sql_gen.as_Table(table))
630
    if cols == []: cols = None # no cols (all defaults) = unknown col names
631
    if cols != None:
632
        cols = [sql_gen.to_name_only_col(v, table).to_str(db) for v in cols]
633
    if select_query == None: select_query = 'DEFAULT VALUES'
634
    if returning != None: returning = sql_gen.as_Col(returning, table)
635
    
636
    # Build query
637
    first_line = 'INSERT INTO '+table.to_str(db)
638
    query = first_line
639
    if cols != None: query += '\n('+', '.join(cols)+')'
640
    query += '\n'+select_query
641
    
642
    if returning != None:
643
        query += '\nRETURNING '+sql_gen.to_name_only_col(returning).to_str(db)
644
    
645
    if embeddable:
646
        assert returning != None
647
        
648
        # Create function
649
        function_name = sql_gen.clean_name(first_line)
650
        return_type = 'SETOF '+returning.to_str(db)+'%TYPE'
651
        while True:
652
            try:
653
                function = db.TempFunction(function_name)
654
                
655
                function_query = '''\
656
CREATE FUNCTION '''+function.to_str(db)+'''()
657
RETURNS '''+return_type+'''
658
LANGUAGE sql
659
AS $$
660
'''+query+''';
661
$$;
662
'''
663
                run_query(db, function_query, recover=True, cacheable=True,
664
                    log_ignore_excs=(DuplicateException,))
665
                break # this version was successful
666
            except DuplicateException, e:
667
                function_name = next_version(function_name)
668
                # try again with next version of name
669
        
670
        # Return query that uses function
671
        func_table = sql_gen.NamedTable('f', sql_gen.FunctionCall(function),
672
            [returning]) # AS clause requires function alias
673
        return mk_select(db, func_table, start=0, order_by=None)
674
    
675
    return query
676

    
677
def insert_select(db, *args, **kw_args):
678
    '''For params, see mk_insert_select() and run_query_into()
679
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
680
        values in
681
    '''
682
    into = kw_args.pop('into', None)
683
    if into != None: kw_args['embeddable'] = True
684
    recover = kw_args.pop('recover', None)
685
    cacheable = kw_args.pop('cacheable', True)
686
    log_level = kw_args.pop('log_level', 2)
687
    
688
    return run_query_into(db, mk_insert_select(db, *args, **kw_args), into,
689
        recover=recover, cacheable=cacheable, log_level=log_level)
690

    
691
default = sql_gen.default # tells insert() to use the default value for a column
692

    
693
def insert(db, table, row, *args, **kw_args):
694
    '''For params, see insert_select()'''
695
    if lists.is_seq(row): cols = None
696
    else:
697
        cols = row.keys()
698
        row = row.values()
699
    row = list(row) # ensure that "== []" works
700
    
701
    if row == []: query = None
702
    else: query = sql_gen.Values(row).to_str(db)
703
    
704
    return insert_select(db, table, cols, query, *args, **kw_args)
705

    
706
def mk_update(db, table, changes=None, cond=None):
707
    '''
708
    @param changes [(col, new_value),...]
709
        * container can be any iterable type
710
        * col: sql_gen.Code|str (for col name)
711
        * new_value: sql_gen.Code|literal value
712
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
713
    @return str query
714
    '''
715
    query = 'UPDATE '+sql_gen.as_Table(table).to_str(db)+'\nSET\n'
716
    query += ',\n'.join((sql_gen.to_name_only_col(col, table).to_str(db)+' = '
717
        +sql_gen.as_Value(new_value).to_str(db) for col, new_value in changes))
718
    if cond != None: query += '\nWHERE\n'+cond.to_str(db)
719
    
720
    return query
721

    
722
def update(db, *args, **kw_args):
723
    '''For params, see mk_update() and run_query()'''
724
    recover = kw_args.pop('recover', None)
725
    
726
    return run_query(db, mk_update(db, *args, **kw_args), recover)
727

    
728
def last_insert_id(db):
729
    module = util.root_module(db.db)
730
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
731
    elif module == 'MySQLdb': return db.insert_id()
732
    else: return None
733

    
734
def mk_flatten_mapping(db, into, cols, preserve=[], as_items=False):
735
    '''Creates a mapping from original column names (which may have collisions)
736
    to names that will be distinct among the columns' tables.
737
    This is meant to be used for several tables that are being joined together.
738
    @param cols The columns to combine. Duplicates will be removed.
739
    @param into The table for the new columns.
740
    @param preserve [sql_gen.Col...] Columns not to rename. Note that these
741
        columns will be included in the mapping even if they are not in cols.
742
        The tables of the provided Col objects will be changed to into, so make
743
        copies of them if you want to keep the original tables.
744
    @param as_items Whether to return a list of dict items instead of a dict
745
    @return dict(orig_col=new_col, ...)
746
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
747
        * new_col: sql_gen.Col(orig_col_name, into)
748
        * All mappings use the into table so its name can easily be
749
          changed for all columns at once
750
    '''
751
    cols = lists.uniqify(cols)
752
    
753
    items = []
754
    for col in preserve:
755
        orig_col = copy.copy(col)
756
        col.table = into
757
        items.append((orig_col, col))
758
    preserve = set(preserve)
759
    for col in cols:
760
        if col not in preserve:
761
            items.append((col, sql_gen.Col(str(col), into, col.srcs)))
762
    
763
    if not as_items: items = dict(items)
764
    return items
765

    
766
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
767
    '''For params, see mk_flatten_mapping()
768
    @return See return value of mk_flatten_mapping()
769
    '''
770
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
771
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
772
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
773
        into=into, add_indexes_=True)
774
    return dict(items)
775

    
776
def mk_track_data_error(db, errors_table, cols, value, error_code, error):
777
    assert cols != ()
778
    
779
    cols = map(sql_gen.to_name_only_col, cols)
780
    
781
    columns_cols = ['column']
782
    columns = sql_gen.NamedValues('columns', columns_cols,
783
        [[c.name] for c in cols])
784
    values_cols = ['value', 'error_code', 'error']
785
    values = sql_gen.NamedValues('values', values_cols,
786
        [value, error_code, error])
787
    
788
    select_cols = columns_cols+values_cols
789
    name_only_cols = map(sql_gen.to_name_only_col, select_cols)
790
    errors_table = sql_gen.NamedTable('errors', errors_table)
791
    joins = [columns, sql_gen.Join(values, type_='CROSS'),
792
        sql_gen.Join(errors_table, dict(zip(name_only_cols, select_cols)),
793
        sql_gen.filter_out)]
794
    
795
    return mk_insert_select(db, errors_table, name_only_cols,
796
        mk_select(db, joins, select_cols, order_by=None))
797

    
798
def track_data_error(db, errors_table, cols, *args, **kw_args):
799
    '''
800
    @param errors_table If None, does nothing.
801
    '''
802
    if errors_table == None or cols == (): return
803
    run_query(db, mk_track_data_error(db, errors_table, cols, *args, **kw_args),
804
        cacheable=True, log_level=4)
805

    
806
def cast(db, type_, col, errors_table=None):
807
    '''Casts an (unrenamed) column or value.
808
    If errors_table set and col has srcs, saves errors in errors_table (using
809
    col's srcs attr as the source columns) and converts errors to warnings.
810
    @param col str|sql_gen.Col|sql_gen.Literal
811
    @param errors_table None|sql_gen.Table|str
812
    '''
813
    col = sql_gen.as_Col(col)
814
    save_errors = (errors_table != None and isinstance(col, sql_gen.Col)
815
        and col.srcs != ())
816
    if not save_errors: return sql_gen.Cast(type_, col) # can't save errors
817
    
818
    assert not isinstance(col, sql_gen.NamedCol)
819
    
820
    errors_table = sql_gen.as_Table(errors_table)
821
    srcs = map(sql_gen.to_name_only_col, col.srcs)
822
    function_name = str(sql_gen.FunctionCall(type_, *srcs))
823
    function = db.TempFunction(function_name)
824
    
825
    while True:
826
        # Create function definition
827
        query = '''\
828
CREATE FUNCTION '''+function.to_str(db)+'''(value text)
829
RETURNS '''+type_+'''
830
LANGUAGE plpgsql
831
STRICT
832
AS $$
833
BEGIN
834
    /* The explicit cast to the return type is needed to make the cast happen
835
    inside the try block. (Implicit casts to the return type happen at the end
836
    of the function, outside any block.) */
837
    RETURN value::'''+type_+''';
838
EXCEPTION
839
    WHEN data_exception THEN
840
        -- Save error in errors table.
841
        -- Insert the value and error for *each* source column.
842
'''+mk_track_data_error(db, errors_table, srcs,
843
    *map(sql_gen.CustomCode, ['value', 'SQLSTATE', 'SQLERRM']))+''';
844
        
845
        RAISE WARNING '%', SQLERRM;
846
        RETURN NULL;
847
END;
848
$$;
849
'''
850
        
851
        # Create function
852
        try:
853
            run_query(db, query, recover=True, cacheable=True,
854
                log_ignore_excs=(DuplicateException,))
855
            break # successful
856
        except DuplicateException:
857
            function.name = next_version(function.name)
858
            # try again with next version of name
859
    
860
    return sql_gen.FunctionCall(function, col)
861

    
862
##### Database structure queries
863

    
864
def table_row_count(db, table, recover=None):
865
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
866
        order_by=None, start=0), recover=recover, log_level=3))
867

    
868
def table_cols(db, table, recover=None):
869
    return list(col_names(select(db, table, limit=0, order_by=None,
870
        recover=recover, log_level=4)))
871

    
872
def pkey(db, table, recover=None):
873
    '''Assumed to be first column in table'''
874
    return table_cols(db, table, recover)[0]
875

    
876
not_null_col = 'not_null_col'
877

    
878
def table_not_null_col(db, table, recover=None):
879
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
880
    if not_null_col in table_cols(db, table, recover): return not_null_col
881
    else: return pkey(db, table, recover)
882

    
883
def index_cols(db, table, index):
884
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
885
    automatically created. When you don't know whether something is a UNIQUE
886
    constraint or a UNIQUE index, use this function.'''
887
    module = util.root_module(db.db)
888
    if module == 'psycopg2':
889
        return list(values(run_query(db, '''\
890
SELECT attname
891
FROM
892
(
893
        SELECT attnum, attname
894
        FROM pg_index
895
        JOIN pg_class index ON index.oid = indexrelid
896
        JOIN pg_class table_ ON table_.oid = indrelid
897
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
898
        WHERE
899
            table_.relname = '''+db.esc_value(table)+'''
900
            AND index.relname = '''+db.esc_value(index)+'''
901
    UNION
902
        SELECT attnum, attname
903
        FROM
904
        (
905
            SELECT
906
                indrelid
907
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
908
                    AS indkey
909
            FROM pg_index
910
            JOIN pg_class index ON index.oid = indexrelid
911
            JOIN pg_class table_ ON table_.oid = indrelid
912
            WHERE
913
                table_.relname = '''+db.esc_value(table)+'''
914
                AND index.relname = '''+db.esc_value(index)+'''
915
        ) s
916
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
917
) s
918
ORDER BY attnum
919
'''
920
            , cacheable=True, log_level=4)))
921
    else: raise NotImplementedError("Can't list index columns for "+module+
922
        ' database')
923

    
924
def constraint_cols(db, table, constraint):
925
    module = util.root_module(db.db)
926
    if module == 'psycopg2':
927
        return list(values(run_query(db, '''\
928
SELECT attname
929
FROM pg_constraint
930
JOIN pg_class ON pg_class.oid = conrelid
931
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
932
WHERE
933
    relname = '''+db.esc_value(table)+'''
934
    AND conname = '''+db.esc_value(constraint)+'''
935
ORDER BY attnum
936
'''
937
            )))
938
    else: raise NotImplementedError("Can't list constraint columns for "+module+
939
        ' database')
940

    
941
row_num_col = '_row_num'
942

    
943
def add_index(db, exprs, table=None, unique=False, ensure_not_null_=True):
944
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
945
    Currently, only function calls are supported as expressions.
946
    @param ensure_not_null_ If set, translates NULL values to sentinel values.
947
        This allows indexes to be used for comparisons where NULLs are equal.
948
    '''
949
    exprs = lists.mk_seq(exprs)
950
    
951
    # Parse exprs
952
    old_exprs = exprs[:]
953
    exprs = []
954
    cols = []
955
    for i, expr in enumerate(old_exprs):
956
        expr = sql_gen.as_Col(expr, table)
957
        
958
        # Handle nullable columns
959
        if ensure_not_null_:
960
            try: expr = ensure_not_null(db, expr)
961
            except KeyError: pass # unknown type, so just create plain index
962
        
963
        # Extract col
964
        expr = copy.deepcopy(expr) # don't modify input!
965
        if isinstance(expr, sql_gen.FunctionCall):
966
            col = expr.args[0]
967
            expr = sql_gen.Expr(expr)
968
        else: col = expr
969
        assert isinstance(col, sql_gen.Col)
970
        
971
        # Extract table
972
        if table == None:
973
            assert sql_gen.is_table_col(col)
974
            table = col.table
975
        
976
        col.table = None
977
        
978
        exprs.append(expr)
979
        cols.append(col)
980
    
981
    table = sql_gen.as_Table(table)
982
    index = sql_gen.Table(str(sql_gen.Col(','.join(map(str, cols)), table)))
983
    
984
    str_ = 'CREATE'
985
    if unique: str_ += ' UNIQUE'
986
    str_ += ' INDEX '+index.to_str(db)+' ON '+table.to_str(db)+' ('+(
987
        ', '.join((v.to_str(db) for v in exprs)))+')'
988
    
989
    try: run_query(db, str_, recover=True, cacheable=True, log_level=3)
990
    except DuplicateException: pass # index already existed
991

    
992
def add_pkey(db, table, cols=None, recover=None):
993
    '''Adds a primary key.
994
    @param cols [sql_gen.Col,...] The columns in the primary key.
995
        Defaults to the first column in the table.
996
    @pre The table must not already have a primary key.
997
    '''
998
    table = sql_gen.as_Table(table)
999
    if cols == None: cols = [pkey(db, table, recover)]
1000
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1001
    
1002
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1003
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1004
        log_ignore_excs=(DuplicateException,))
1005

    
1006
def add_not_null(db, col):
1007
    table = col.table
1008
    col = sql_gen.to_name_only_col(col)
1009
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1010
        +col.to_str(db)+' SET NOT NULL', cacheable=True)
1011

    
1012
def add_index_col(db, col, suffix, expr, nullable=True):
1013
    if sql_gen.index_col(col) != None: return # already has index col
1014
    
1015
    new_col = sql_gen.suffixed_col(col, suffix)
1016
    new_typed_col = sql_gen.TypedCol(new_col.name, db.col_info(col).type)
1017
    
1018
    add_col(db, col.table, new_typed_col)
1019
    update(db, col.table, [(new_col, expr)])
1020
    if not nullable: add_not_null(db, new_col)
1021
    add_index(db, new_col)
1022
    
1023
    col.table.index_cols[col.name] = new_col
1024

    
1025
def ensure_not_null(db, col):
1026
    '''For params, see sql_gen.ensure_not_null()'''
1027
    expr = sql_gen.ensure_not_null(db, col)
1028
    
1029
    # If nullable column in a temp table, add separate column instead
1030
    if sql_gen.is_temp_col(col) and isinstance(expr, sql_gen.EnsureNotNull):
1031
        add_index_col(db, col, '::NOT NULL', expr, nullable=False)
1032
        expr = sql_gen.index_col(col)
1033
    
1034
    return expr
1035

    
1036
already_indexed = object() # tells add_indexes() the pkey has already been added
1037

    
1038
def add_indexes(db, table, has_pkey=True):
1039
    '''Adds an index on all columns in a table.
1040
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1041
        index should be added on the first column.
1042
        * If already_indexed, the pkey is assumed to have already been added
1043
    '''
1044
    cols = table_cols(db, table)
1045
    if has_pkey:
1046
        if has_pkey is not already_indexed: add_pkey(db, table)
1047
        cols = cols[1:]
1048
    for col in cols: add_index(db, col, table)
1049

    
1050
def add_col(db, table, col, **kw_args):
1051
    assert isinstance(col, sql_gen.TypedCol)
1052
    try: run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '
1053
        +col.to_str(db), recover=True, cacheable=True, **kw_args)
1054
    except DuplicateException: pass # column already existed
1055

    
1056
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1057
    constraints='PRIMARY KEY')
1058

    
1059
def add_row_num(db, table):
1060
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1061
    be the primary key.'''
1062
    add_col(db, table, row_num_typed_col, log_level=3)
1063

    
1064
def cast_temp_col(db, type_, col, errors_table=None):
1065
    '''Like cast(), but creates a new column with the cast values if the input
1066
    is a column.
1067
    @return The new column or cast value
1068
    '''
1069
    def cast_(col): return cast(db, type_, col, errors_table)
1070
    
1071
    try: col = sql_gen.underlying_col(col)
1072
    except sql_gen.NoUnderlyingTableException: return sql_gen.wrap(cast_, col)
1073
    
1074
    table = col.table
1075
    new_col = sql_gen.Col(sql_gen.concat(col.name, '::'+type_), table, col.srcs)
1076
    expr = cast_(col)
1077
    add_col(db, table, sql_gen.TypedCol(new_col.name, type_))
1078
    update(db, table, [(new_col, expr)])
1079
    add_index(db, new_col)
1080
    
1081
    return new_col
1082

    
1083
def drop_table(db, table):
1084
    table = sql_gen.as_Table(table)
1085
    return run_query(db, 'DROP TABLE IF EXISTS '+table.to_str(db)+' CASCADE')
1086

    
1087
def create_table(db, table, cols, has_pkey=True, col_indexes=True):
1088
    '''Creates a table.
1089
    @param cols [sql_gen.TypedCol,...] The column names and types
1090
    @param has_pkey If set, the first column becomes the primary key.
1091
    @param col_indexes bool|[ref]
1092
        * If True, indexes will be added on all non-pkey columns.
1093
        * If a list reference, [0] will be set to a function to do this.
1094
          This can be used to delay index creation until the table is populated.
1095
    '''
1096
    table = sql_gen.as_Table(table)
1097
    
1098
    if has_pkey:
1099
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1100
        pkey.constraints = 'PRIMARY KEY'
1101
    
1102
    str_ = 'CREATE TABLE '+table.to_str(db)+' (\n'
1103
    str_ += '\n, '.join(v.to_str(db) for v in cols)
1104
    str_ += '\n);\n'
1105
    run_query(db, str_, cacheable=True, log_level=2)
1106
    
1107
    # Add indexes
1108
    if has_pkey: has_pkey = already_indexed
1109
    def add_indexes_(): add_indexes(db, table, has_pkey)
1110
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1111
    elif col_indexes: add_indexes_() # add now
1112

    
1113
def vacuum(db, table):
1114
    table = sql_gen.as_Table(table)
1115
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1116
        log_level=3))
1117

    
1118
def truncate(db, table, schema='public', **kw_args):
1119
    '''For params, see run_query()'''
1120
    table = sql_gen.as_Table(table, schema)
1121
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1122

    
1123
def empty_temp(db, tables):
1124
    if db.debug_temp: return # leave temp tables there for debugging
1125
    tables = lists.mk_seq(tables)
1126
    for table in tables: truncate(db, table, log_level=3)
1127

    
1128
def tables(db, schema_like='public', table_like='%', exact=False):
1129
    if exact: compare = '='
1130
    else: compare = 'LIKE'
1131
    
1132
    module = util.root_module(db.db)
1133
    if module == 'psycopg2':
1134
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1135
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1136
        return values(select(db, 'pg_tables', ['tablename'], conds,
1137
            order_by='tablename', log_level=4))
1138
    elif module == 'MySQLdb':
1139
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1140
            , cacheable=True, log_level=4))
1141
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1142

    
1143
def table_exists(db, table):
1144
    table = sql_gen.as_Table(table)
1145
    return list(tables(db, table.schema, table.name, exact=True)) != []
1146

    
1147
def function_exists(db, function):
1148
    function = sql_gen.as_Function(function)
1149
    
1150
    info_table = sql_gen.Table('routines', 'information_schema')
1151
    conds = [('routine_name', function.name)]
1152
    schema = function.schema
1153
    if schema != None: conds.append(('routine_schema', schema))
1154
    # Exclude trigger functions, since they cannot be called directly
1155
    conds.append(('data_type', sql_gen.CompareCond('trigger', '!=')))
1156
    
1157
    return list(values(select(db, info_table, ['routine_name'], conds,
1158
        order_by='routine_schema', limit=1, log_level=4))) != []
1159
        # TODO: order_by search_path schema order
1160

    
1161
def errors_table(db, table, if_exists=True):
1162
    '''
1163
    @param if_exists If set, returns None if the errors table doesn't exist
1164
    @return None|sql_gen.Table
1165
    '''
1166
    table = sql_gen.as_Table(table)
1167
    if table.srcs != (): table = table.srcs[0]
1168
    
1169
    errors_table = sql_gen.suffixed_table(table, '.errors')
1170
    if if_exists and not table_exists(db, errors_table): return None
1171
    return errors_table
1172

    
1173
##### Database management
1174

    
1175
def empty_db(db, schema='public', **kw_args):
1176
    '''For kw_args, see tables()'''
1177
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1178

    
1179
##### Heuristic queries
1180

    
1181
def put(db, table, row, pkey_=None, row_ct_ref=None):
1182
    '''Recovers from errors.
1183
    Only works under PostgreSQL (uses INSERT RETURNING).
1184
    '''
1185
    row = sql_gen.ColDict(db, table, row)
1186
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
1187
    
1188
    try:
1189
        cur = insert(db, table, row, pkey_, recover=True)
1190
        if row_ct_ref != None and cur.rowcount >= 0:
1191
            row_ct_ref[0] += cur.rowcount
1192
        return value(cur)
1193
    except DuplicateKeyException, e:
1194
        row = sql_gen.ColDict(db, table,
1195
            util.dict_subset_right_join(row, e.cols))
1196
        return value(select(db, table, [pkey_], row, recover=True))
1197

    
1198
def get(db, table, row, pkey, row_ct_ref=None, create=False):
1199
    '''Recovers from errors'''
1200
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
1201
    except StopIteration:
1202
        if not create: raise
1203
        return put(db, table, row, pkey, row_ct_ref) # insert new row
1204

    
1205
def is_func_result(col):
1206
    return col.table.name.find('(') >= 0 and col.name == 'result'
1207

    
1208
def into_table_name(out_table, in_tables0, mapping, is_func):
1209
    def in_col_str(in_col):
1210
        in_col = sql_gen.remove_col_rename(in_col)
1211
        if isinstance(in_col, sql_gen.Col):
1212
            table = in_col.table
1213
            if table == in_tables0:
1214
                in_col = sql_gen.to_name_only_col(in_col)
1215
            elif is_func_result(in_col): in_col = table # omit col name
1216
        return str(in_col)
1217
    
1218
    str_ = str(out_table)
1219
    if is_func:
1220
        str_ += '('
1221
        
1222
        try: value_in_col = mapping['value']
1223
        except KeyError:
1224
            str_ += ', '.join((str(k)+'='+in_col_str(v)
1225
                for k, v in mapping.iteritems()))
1226
        else: str_ += in_col_str(value_in_col)
1227
        
1228
        str_ += ')'
1229
    else:
1230
        out_col = 'rank'
1231
        try: in_col = mapping[out_col]
1232
        except KeyError: str_ += '_pkeys'
1233
        else: # has a rank column, so hierarchical
1234
            str_ += '['+str(out_col)+'='+in_col_str(in_col)+']'
1235
    return str_
1236

    
1237
def put_table(db, out_table, in_tables, mapping, row_ct_ref=None, into=None,
1238
    default=None, is_func=False, on_error=exc.raise_):
1239
    '''Recovers from errors.
1240
    Only works under PostgreSQL (uses INSERT RETURNING).
1241
    IMPORTANT: Must be run at the *beginning* of a transaction.
1242
    @param in_tables The main input table to select from, followed by a list of
1243
        tables to join with it using the main input table's pkey
1244
    @param mapping dict(out_table_col=in_table_col, ...)
1245
        * out_table_col: str (*not* sql_gen.Col)
1246
        * in_table_col: sql_gen.Col|literal-value
1247
    @param into The table to contain the output and input pkeys.
1248
        Defaults to `out_table.name+'_pkeys'`.
1249
    @param default The *output* column to use as the pkey for missing rows.
1250
        If this output column does not exist in the mapping, uses None.
1251
    @param is_func Whether out_table is the name of a SQL function, not a table
1252
    @return sql_gen.Col Where the output pkeys are made available
1253
    '''
1254
    out_table = sql_gen.as_Table(out_table)
1255
    
1256
    def log_debug(msg): db.log_debug(msg, level=1.5)
1257
    def col_ustr(str_):
1258
        return strings.repr_no_u(sql_gen.remove_col_rename(str_))
1259
    
1260
    log_debug('********** New iteration **********')
1261
    log_debug('Inserting these input columns into '+strings.as_tt(
1262
        out_table.to_str(db))+':\n'+strings.as_table(mapping, ustr=col_ustr))
1263
    
1264
    is_function = function_exists(db, out_table)
1265
    
1266
    if is_function: out_pkey = 'result'
1267
    else: out_pkey = pkey(db, out_table, recover=True)
1268
    out_pkey_col = sql_gen.as_Col(out_pkey, out_table)
1269
    
1270
    if mapping == {}: # need at least one column for INSERT SELECT
1271
        mapping = {out_pkey: None} # ColDict will replace with default value
1272
    
1273
    # Create input joins from list of input tables
1274
    in_tables_ = in_tables[:] # don't modify input!
1275
    in_tables0 = in_tables_.pop(0) # first table is separate
1276
    errors_table_ = errors_table(db, in_tables0)
1277
    in_pkey = pkey(db, in_tables0, recover=True)
1278
    in_pkey_col = sql_gen.as_Col(in_pkey, in_tables0)
1279
    input_joins = [in_tables0]+[sql_gen.Join(v,
1280
        {in_pkey: sql_gen.join_same_not_null}) for v in in_tables_]
1281
    
1282
    if into == None:
1283
        into = into_table_name(out_table, in_tables0, mapping, is_func)
1284
    into = sql_gen.as_Table(into)
1285
    
1286
    # Set column sources
1287
    in_cols = filter(sql_gen.is_table_col, mapping.values())
1288
    for col in in_cols:
1289
        if col.table == in_tables0: col.set_srcs(sql_gen.src_self)
1290
    
1291
    log_debug('Joining together input tables into temp table')
1292
    # Place in new table for speed and so don't modify input if values edited
1293
    in_table = sql_gen.Table('in')
1294
    mapping = dicts.join(mapping, flatten(db, in_table, input_joins, in_cols,
1295
        preserve=[in_pkey_col], start=0))
1296
    input_joins = [in_table]
1297
    db.log_debug('Temp table: '+strings.as_tt(in_table.to_str(db)), level=2)
1298
    
1299
    mapping = sql_gen.ColDict(db, out_table, mapping)
1300
        # after applying dicts.join() because that returns a plain dict
1301
    
1302
    # Resolve default value column
1303
    if default != None:
1304
        try: default = mapping[default]
1305
        except KeyError:
1306
            db.log_debug('Default value column '
1307
                +strings.as_tt(strings.repr_no_u(default))
1308
                +' does not exist in mapping, falling back to None', level=2.1)
1309
            default = None
1310
    
1311
    pkeys_names = [in_pkey, out_pkey]
1312
    pkeys_cols = [in_pkey_col, out_pkey_col]
1313
    
1314
    pkeys_table_exists_ref = [False]
1315
    def insert_into_pkeys(joins, cols, distinct=False):
1316
        kw_args = {}
1317
        if distinct: kw_args.update(dict(distinct_on=[in_pkey_col]))
1318
        query = mk_select(db, joins, cols, order_by=None, start=0, **kw_args)
1319
        
1320
        if pkeys_table_exists_ref[0]:
1321
            insert_select(db, into, pkeys_names, query)
1322
        else:
1323
            run_query_into(db, query, into=into)
1324
            pkeys_table_exists_ref[0] = True
1325
    
1326
    limit_ref = [None]
1327
    conds = set()
1328
    distinct_on = sql_gen.ColDict(db, out_table)
1329
    def mk_main_select(joins, cols):
1330
        distinct_on_cols = [c.to_Col() for c in distinct_on.values()]
1331
        return mk_select(db, joins, cols, conds, distinct_on_cols,
1332
            limit=limit_ref[0], start=0)
1333
    
1334
    exc_strs = set()
1335
    def log_exc(e):
1336
        e_str = exc.str_(e, first_line_only=True)
1337
        log_debug('Caught exception: '+e_str)
1338
        assert e_str not in exc_strs # avoid infinite loops
1339
        exc_strs.add(e_str)
1340
    
1341
    def remove_all_rows():
1342
        log_debug('Ignoring all rows')
1343
        limit_ref[0] = 0 # just create an empty pkeys table
1344
    
1345
    def ignore(in_col, value, e):
1346
        track_data_error(db, errors_table_, in_col.srcs, value, e.cause.pgcode,
1347
            e.cause.pgerror)
1348
        log_debug('Ignoring rows with '+strings.as_tt(repr(in_col))+' = '
1349
            +strings.as_tt(repr(value)))
1350
    
1351
    def remove_rows(in_col, value, e):
1352
        ignore(in_col, value, e)
1353
        cond = (in_col, sql_gen.CompareCond(value, '!='))
1354
        assert cond not in conds # avoid infinite loops
1355
        conds.add(cond)
1356
    
1357
    def invalid2null(in_col, value, e):
1358
        ignore(in_col, value, e)
1359
        update(db, in_table, [(in_col, None)],
1360
            sql_gen.ColValueCond(in_col, value))
1361
    
1362
    def insert_pkeys_table(which):
1363
        return sql_gen.Table(sql_gen.concat(in_table.name,
1364
            '_insert_'+which+'_pkeys'))
1365
    insert_out_pkeys = insert_pkeys_table('out')
1366
    insert_in_pkeys = insert_pkeys_table('in')
1367
    
1368
    # Do inserts and selects
1369
    join_cols = sql_gen.ColDict(db, out_table)
1370
    while True:
1371
        if limit_ref[0] == 0: # special case
1372
            log_debug('Creating an empty pkeys table')
1373
            cur = run_query_into(db, mk_select(db, out_table, [out_pkey],
1374
                limit=limit_ref[0]), into=insert_out_pkeys)
1375
            break # don't do main case
1376
        
1377
        has_joins = join_cols != {}
1378
        
1379
        log_debug('Trying to insert new rows')
1380
        
1381
        # Prepare to insert new rows
1382
        insert_joins = input_joins[:] # don't modify original!
1383
        insert_args = dict(recover=True, cacheable=False)
1384
        if has_joins:
1385
            insert_joins.append(sql_gen.Join(out_table, join_cols,
1386
                sql_gen.filter_out))
1387
        else:
1388
            insert_args.update(dict(returning=out_pkey, into=insert_out_pkeys))
1389
        main_select = mk_main_select(insert_joins, mapping.values())
1390
        
1391
        def main_insert():
1392
            if is_function:
1393
                log_debug('Calling function on input rows')
1394
                args = dict(((k.name, v) for k, v in mapping.iteritems()))
1395
                func_call = sql_gen.NamedCol(out_pkey,
1396
                    sql_gen.FunctionCall(out_table, **args))
1397
                insert_into_pkeys(input_joins, [in_pkey_col, func_call])
1398
                return None
1399
            else:
1400
                lock_table(db, out_table, 'EXCLUSIVE')
1401
                return insert_select(db, out_table, mapping.keys(), main_select,
1402
                    **insert_args)
1403
        
1404
        try:
1405
            cur = with_savepoint(db, main_insert)
1406
            break # insert successful
1407
        except MissingCastException, e:
1408
            log_exc(e)
1409
            
1410
            out_col = e.col
1411
            type_ = e.type
1412
            
1413
            log_debug('Casting '+strings.as_tt(out_col)+' input to '
1414
                +strings.as_tt(type_))
1415
            mapping[out_col] = cast_temp_col(db, type_, mapping[out_col],
1416
                errors_table_)
1417
        except DuplicateKeyException, e:
1418
            log_exc(e)
1419
            
1420
            old_join_cols = join_cols.copy()
1421
            distinct_on.update(util.dict_subset(mapping, e.cols))
1422
            join_cols.update(util.dict_subset_right_join(mapping, e.cols))
1423
            log_debug('Ignoring existing rows, comparing on these columns:\n'
1424
                +strings.as_inline_table(join_cols, ustr=col_ustr))
1425
            assert join_cols != old_join_cols # avoid infinite loops
1426
        except NullValueException, e:
1427
            log_exc(e)
1428
            
1429
            out_col, = e.cols
1430
            try: in_col = mapping[out_col]
1431
            except KeyError:
1432
                log_debug('Missing mapping for NOT NULL column '+out_col)
1433
                remove_all_rows()
1434
            else: remove_rows(in_col, None, e)
1435
        except FunctionValueException, e:
1436
            log_exc(e)
1437
            
1438
            func_name = e.name
1439
            value = e.value
1440
            for out_col, in_col in mapping.iteritems():
1441
                in_col = sql_gen.unwrap_func_call(in_col, func_name)
1442
                invalid2null(in_col, value, e)
1443
        except DatabaseErrors, e:
1444
            log_exc(e)
1445
            
1446
            log_debug('No handler for exception')
1447
            on_error(e)
1448
            remove_all_rows()
1449
        # after exception handled, rerun loop with additional constraints
1450
    
1451
    if cur != None and row_ct_ref != None and cur.rowcount >= 0:
1452
        row_ct_ref[0] += cur.rowcount
1453
    
1454
    if is_function: pass # pkeys table already created
1455
    elif has_joins:
1456
        select_joins = input_joins+[sql_gen.Join(out_table, join_cols)]
1457
        log_debug('Getting output table pkeys of existing/inserted rows')
1458
        insert_into_pkeys(select_joins, pkeys_cols, distinct=True)
1459
    else:
1460
        add_row_num(db, insert_out_pkeys) # for joining with input pkeys
1461
        
1462
        log_debug('Getting input table pkeys of inserted rows')
1463
        run_query_into(db, mk_main_select(input_joins, [in_pkey]),
1464
            into=insert_in_pkeys)
1465
        add_row_num(db, insert_in_pkeys) # for joining with output pkeys
1466
        
1467
        assert table_row_count(db, insert_out_pkeys) == table_row_count(db,
1468
            insert_in_pkeys)
1469
        
1470
        log_debug('Combining output and input pkeys in inserted order')
1471
        pkey_joins = [insert_in_pkeys, sql_gen.Join(insert_out_pkeys,
1472
            {row_num_col: sql_gen.join_same_not_null})]
1473
        insert_into_pkeys(pkey_joins, pkeys_names)
1474
        
1475
        empty_temp(db, [insert_out_pkeys, insert_in_pkeys])
1476
    
1477
    db.log_debug('Adding pkey on pkeys table to enable fast joins', level=2.5)
1478
    add_pkey(db, into)
1479
    
1480
    log_debug('Setting pkeys of missing rows to '+strings.as_tt(repr(default)))
1481
    missing_rows_joins = input_joins+[sql_gen.Join(into,
1482
        {in_pkey: sql_gen.join_same_not_null}, sql_gen.filter_out)]
1483
        # must use join_same_not_null or query will take forever
1484
    insert_into_pkeys(missing_rows_joins,
1485
        [in_pkey_col, sql_gen.NamedCol(out_pkey, default)])
1486
    
1487
    assert table_row_count(db, into) == table_row_count(db, in_table)
1488
    
1489
    empty_temp(db, in_table)
1490
    
1491
    srcs = []
1492
    if is_func: srcs = sql_gen.cols_srcs(in_cols)
1493
    return sql_gen.Col(out_pkey, into, srcs)
1494

    
1495
##### Data cleanup
1496

    
1497
def cleanup_table(db, table, cols):
1498
    table = sql_gen.as_Table(table)
1499
    cols = map(sql_gen.as_Col, cols)
1500
    
1501
    expr = ('nullif(nullif(trim(both from %s), '+db.esc_value('')+'), '
1502
        +db.esc_value(r'\N')+')')
1503
    changes = [(v, sql_gen.CustomCode(expr % v.to_str(db)))
1504
        for v in cols]
1505
    
1506
    update(db, table, changes)
(24-24/36)