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
                # structural changes
241
                if query.find('ADD COLUMN') < 0: # rest of query must be unique
242
                    self._cache_result()
243
            elif self.rowcount == 0 and query.startswith('SELECT'): # empty
244
                consume_rows(self) # fetch all rows so result will be cached
245
            
246
            return cur
247
        
248
        def fetchone(self):
249
            row = self.inner.fetchone()
250
            if row != None: self.result.append(row)
251
            # otherwise, fetched all rows
252
            else: self._cache_result()
253
            return row
254
        
255
        def _cache_result(self):
256
            # For inserts that return a result set, don't cache result set since
257
            # inserts are not idempotent. Other non-SELECT queries don't have
258
            # their result set read, so only exceptions will be cached (an
259
            # invalid query will always be invalid).
260
            if self.query_results != None and (not self._is_insert
261
                or isinstance(self.result, Exception)):
262
                
263
                assert self.query_lookup != None
264
                self.query_results[self.query_lookup] = self.CacheCursor(
265
                    util.dict_subset(dicts.AttrsDictView(self),
266
                    ['query', 'result', 'rowcount', 'description']))
267
        
268
        class CacheCursor:
269
            def __init__(self, cached_result): self.__dict__ = cached_result
270
            
271
            def execute(self, *args, **kw_args):
272
                if isinstance(self.result, Exception): raise self.result
273
                # otherwise, result is a rows list
274
                self.iter = iter(self.result)
275
            
276
            def fetchone(self):
277
                try: return self.iter.next()
278
                except StopIteration: return None
279
    
280
    def esc_value(self, value):
281
        try: str_ = self.mogrify('%s', [value])
282
        except NotImplementedError, e:
283
            module = util.root_module(self.db)
284
            if module == 'MySQLdb':
285
                import _mysql
286
                str_ = _mysql.escape_string(value)
287
            else: raise e
288
        return strings.to_unicode(str_)
289
    
290
    def esc_name(self, name): return esc_name(self, name) # calls global func
291
    
292
    def std_code(self, str_):
293
        '''Standardizes SQL code.
294
        * Ensures that string literals are prefixed by `E`
295
        '''
296
        if str_.startswith("'"): str_ = 'E'+str_
297
        return str_
298
    
299
    def can_mogrify(self):
300
        module = util.root_module(self.db)
301
        return module == 'psycopg2'
302
    
303
    def mogrify(self, query, params=None):
304
        if self.can_mogrify(): return self.db.cursor().mogrify(query, params)
305
        else: raise NotImplementedError("Can't mogrify query")
306
    
307
    def print_notices(self):
308
        if hasattr(self.db, 'notices'):
309
            for msg in self.db.notices:
310
                if msg not in self._notices_seen:
311
                    self._notices_seen.add(msg)
312
                    self.log_debug(msg, level=2)
313
    
314
    def run_query(self, query, cacheable=False, log_level=2,
315
        debug_msg_ref=None):
316
        '''
317
        @param log_ignore_excs The log_level will be increased by 2 if the query
318
            throws one of these exceptions.
319
        @param debug_msg_ref If specified, the log message will be returned in
320
            this instead of being output. This allows you to filter log messages
321
            depending on the result of the query.
322
        '''
323
        assert query != None
324
        
325
        if not self.caching: cacheable = False
326
        used_cache = False
327
        
328
        def log_msg(query):
329
            if used_cache: cache_status = 'cache hit'
330
            elif cacheable: cache_status = 'cache miss'
331
            else: cache_status = 'non-cacheable'
332
            return 'DB query: '+cache_status+':\n'+strings.as_code(query, 'SQL')
333
        
334
        try:
335
            # Get cursor
336
            if cacheable:
337
                try:
338
                    cur = self.query_results[query]
339
                    used_cache = True
340
                except KeyError: cur = self.DbCursor(self)
341
            else: cur = self.db.cursor()
342
            
343
            # Log query
344
            if self.debug and debug_msg_ref == None: # log before running
345
                self.log_debug(log_msg(query), log_level)
346
            
347
            # Run query
348
            cur.execute(query)
349
        finally:
350
            self.print_notices()
351
            if self.debug and debug_msg_ref != None: # return after running
352
                debug_msg_ref[0] = log_msg(str(get_cur_query(cur, query)))
353
        
354
        return cur
355
    
356
    def is_cached(self, query): return query in self.query_results
357
    
358
    def with_autocommit(self, func):
359
        import psycopg2.extensions
360
        
361
        prev_isolation_level = self.db.isolation_level
362
        self.db.set_isolation_level(
363
            psycopg2.extensions.ISOLATION_LEVEL_AUTOCOMMIT)
364
        try: return func()
365
        finally: self.db.set_isolation_level(prev_isolation_level)
366
    
367
    def with_savepoint(self, func):
368
        savepoint = 'level_'+str(self._savepoint)
369
        self.run_query('SAVEPOINT '+savepoint, log_level=4)
370
        self._savepoint += 1
371
        try: return func()
372
        except:
373
            self.run_query('ROLLBACK TO SAVEPOINT '+savepoint, log_level=4)
374
            raise
375
        finally:
376
            # Always release savepoint, because after ROLLBACK TO SAVEPOINT,
377
            # "The savepoint remains valid and can be rolled back to again"
378
            # (http://www.postgresql.org/docs/8.3/static/sql-rollback-to.html).
379
            self.run_query('RELEASE SAVEPOINT '+savepoint, log_level=4)
380
            
381
            self._savepoint -= 1
382
            assert self._savepoint >= 0
383
            
384
            self.do_autocommit() # OK to do this after ROLLBACK TO SAVEPOINT
385
    
386
    def do_autocommit(self):
387
        '''Autocommits if outside savepoint'''
388
        assert self._savepoint >= 0
389
        if self.autocommit and self._savepoint == 0:
390
            self.log_debug('Autocommitting', level=4)
391
            self.db.commit()
392
    
393
    def col_info(self, col):
394
        table = sql_gen.Table('columns', 'information_schema')
395
        cols = ['data_type', 'column_default',
396
            cast(self, 'boolean', 'is_nullable')]
397
        
398
        conds = [('table_name', col.table.name), ('column_name', col.name)]
399
        schema = col.table.schema
400
        if schema != None: conds.append(('table_schema', schema))
401
        
402
        type_, default, nullable = row(select(self, table, cols, conds,
403
            order_by='table_schema', limit=1, log_level=4))
404
            # TODO: order_by search_path schema order
405
        default = sql_gen.as_Code(default, self)
406
        
407
        return sql_gen.TypedCol(col.name, type_, default, nullable)
408
    
409
    def TempFunction(self, name):
410
        if self.debug_temp: schema = None
411
        else: schema = 'pg_temp'
412
        return sql_gen.Function(name, schema)
413

    
414
connect = DbConn
415

    
416
##### Recoverable querying
417

    
418
def with_savepoint(db, func): return db.with_savepoint(func)
419

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

    
480
##### Basic queries
481

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

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

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

    
529
order_by_pkey = object() # tells mk_select() to order by the pkey
530

    
531
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
532

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

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

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

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

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

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

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

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

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

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

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

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

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

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

    
864
##### Database structure queries
865

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

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

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

    
878
not_null_col = 'not_null_col'
879

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

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

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

    
943
row_num_col = '_row_num'
944

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

    
1001
def add_pkey(db, table, cols=None, recover=None):
1002
    '''Adds a primary key.
1003
    @param cols [sql_gen.Col,...] The columns in the primary key.
1004
        Defaults to the first column in the table.
1005
    @pre The table must not already have a primary key.
1006
    '''
1007
    table = sql_gen.as_Table(table)
1008
    if cols == None: cols = [pkey(db, table, recover)]
1009
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1010
    
1011
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1012
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1013
        log_ignore_excs=(DuplicateException,))
1014

    
1015
def add_not_null(db, col):
1016
    table = col.table
1017
    col = sql_gen.to_name_only_col(col)
1018
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1019
        +col.to_str(db)+' SET NOT NULL', cacheable=True)
1020

    
1021
def add_index_col(db, col, suffix, expr, nullable=True):
1022
    if sql_gen.index_col(col) != None: return # already has index col
1023
    
1024
    new_col = sql_gen.suffixed_col(col, suffix)
1025
    
1026
    # Add column
1027
    while True:
1028
        new_typed_col = sql_gen.TypedCol(new_col.name, db.col_info(col).type)
1029
        try:
1030
            add_col(db, col.table, new_typed_col,
1031
                log_ignore_excs=(DuplicateException,))
1032
            break
1033
        except DuplicateException:
1034
            new_col.name = next_version(new_col.name)
1035
            # try again with next version of name
1036
    
1037
    update(db, col.table, [(new_col, expr)])
1038
    if not nullable: add_not_null(db, new_col)
1039
    add_index(db, new_col)
1040
    
1041
    col.table.index_cols[col.name] = new_col
1042

    
1043
def ensure_not_null(db, col):
1044
    '''For params, see sql_gen.ensure_not_null()'''
1045
    expr = sql_gen.ensure_not_null(db, col)
1046
    
1047
    # If nullable column in a temp table, add separate column instead
1048
    if sql_gen.is_temp_col(col) and isinstance(expr, sql_gen.EnsureNotNull):
1049
        add_index_col(db, col, '::NOT NULL', expr, nullable=False)
1050
        expr = sql_gen.index_col(col)
1051
    
1052
    return expr
1053

    
1054
already_indexed = object() # tells add_indexes() the pkey has already been added
1055

    
1056
def add_indexes(db, table, has_pkey=True):
1057
    '''Adds an index on all columns in a table.
1058
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1059
        index should be added on the first column.
1060
        * If already_indexed, the pkey is assumed to have already been added
1061
    '''
1062
    cols = table_cols(db, table)
1063
    if has_pkey:
1064
        if has_pkey is not already_indexed: add_pkey(db, table)
1065
        cols = cols[1:]
1066
    for col in cols: add_index(db, col, table)
1067

    
1068
def add_col(db, table, col, **kw_args):
1069
    assert isinstance(col, sql_gen.TypedCol)
1070
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '
1071
        +col.to_str(db), recover=True, cacheable=True, **kw_args)
1072

    
1073
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1074
    constraints='PRIMARY KEY')
1075

    
1076
def add_row_num(db, table):
1077
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1078
    be the primary key.'''
1079
    add_col(db, table, row_num_typed_col, log_level=3)
1080

    
1081
def cast_temp_col(db, type_, col, errors_table=None):
1082
    '''Like cast(), but creates a new column with the cast values if the input
1083
    is a column.
1084
    @return The new column or cast value
1085
    '''
1086
    def cast_(col): return cast(db, type_, col, errors_table)
1087
    
1088
    try: col = sql_gen.underlying_col(col)
1089
    except sql_gen.NoUnderlyingTableException: return sql_gen.wrap(cast_, col)
1090
    
1091
    table = col.table
1092
    new_col = sql_gen.Col(sql_gen.concat(col.name, '::'+type_), table, col.srcs)
1093
    expr = cast_(col)
1094
    add_col(db, table, sql_gen.TypedCol(new_col.name, type_))
1095
    update(db, table, [(new_col, expr)])
1096
    add_index(db, new_col)
1097
    
1098
    return new_col
1099

    
1100
def drop_table(db, table):
1101
    table = sql_gen.as_Table(table)
1102
    return run_query(db, 'DROP TABLE IF EXISTS '+table.to_str(db)+' CASCADE')
1103

    
1104
def create_table(db, table, cols, has_pkey=True, col_indexes=True):
1105
    '''Creates a table.
1106
    @param cols [sql_gen.TypedCol,...] The column names and types
1107
    @param has_pkey If set, the first column becomes the primary key.
1108
    @param col_indexes bool|[ref]
1109
        * If True, indexes will be added on all non-pkey columns.
1110
        * If a list reference, [0] will be set to a function to do this.
1111
          This can be used to delay index creation until the table is populated.
1112
    '''
1113
    table = sql_gen.as_Table(table)
1114
    
1115
    if has_pkey:
1116
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1117
        pkey.constraints = 'PRIMARY KEY'
1118
    
1119
    str_ = 'CREATE TABLE '+table.to_str(db)+' (\n'
1120
    str_ += '\n, '.join(v.to_str(db) for v in cols)
1121
    str_ += '\n);\n'
1122
    run_query(db, str_, cacheable=True, log_level=2)
1123
    
1124
    # Add indexes
1125
    if has_pkey: has_pkey = already_indexed
1126
    def add_indexes_(): add_indexes(db, table, has_pkey)
1127
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1128
    elif col_indexes: add_indexes_() # add now
1129

    
1130
def vacuum(db, table):
1131
    table = sql_gen.as_Table(table)
1132
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1133
        log_level=3))
1134

    
1135
def truncate(db, table, schema='public', **kw_args):
1136
    '''For params, see run_query()'''
1137
    table = sql_gen.as_Table(table, schema)
1138
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1139

    
1140
def empty_temp(db, tables):
1141
    if db.debug_temp: return # leave temp tables there for debugging
1142
    tables = lists.mk_seq(tables)
1143
    for table in tables: truncate(db, table, log_level=3)
1144

    
1145
def tables(db, schema_like='public', table_like='%', exact=False):
1146
    if exact: compare = '='
1147
    else: compare = 'LIKE'
1148
    
1149
    module = util.root_module(db.db)
1150
    if module == 'psycopg2':
1151
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1152
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1153
        return values(select(db, 'pg_tables', ['tablename'], conds,
1154
            order_by='tablename', log_level=4))
1155
    elif module == 'MySQLdb':
1156
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1157
            , cacheable=True, log_level=4))
1158
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1159

    
1160
def table_exists(db, table):
1161
    table = sql_gen.as_Table(table)
1162
    return list(tables(db, table.schema, table.name, exact=True)) != []
1163

    
1164
def function_exists(db, function):
1165
    function = sql_gen.as_Function(function)
1166
    
1167
    info_table = sql_gen.Table('routines', 'information_schema')
1168
    conds = [('routine_name', function.name)]
1169
    schema = function.schema
1170
    if schema != None: conds.append(('routine_schema', schema))
1171
    # Exclude trigger functions, since they cannot be called directly
1172
    conds.append(('data_type', sql_gen.CompareCond('trigger', '!=')))
1173
    
1174
    return list(values(select(db, info_table, ['routine_name'], conds,
1175
        order_by='routine_schema', limit=1, log_level=4))) != []
1176
        # TODO: order_by search_path schema order
1177

    
1178
def errors_table(db, table, if_exists=True):
1179
    '''
1180
    @param if_exists If set, returns None if the errors table doesn't exist
1181
    @return None|sql_gen.Table
1182
    '''
1183
    table = sql_gen.as_Table(table)
1184
    if table.srcs != (): table = table.srcs[0]
1185
    
1186
    errors_table = sql_gen.suffixed_table(table, '.errors')
1187
    if if_exists and not table_exists(db, errors_table): return None
1188
    return errors_table
1189

    
1190
##### Database management
1191

    
1192
def empty_db(db, schema='public', **kw_args):
1193
    '''For kw_args, see tables()'''
1194
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1195

    
1196
##### Heuristic queries
1197

    
1198
def put(db, table, row, pkey_=None, row_ct_ref=None):
1199
    '''Recovers from errors.
1200
    Only works under PostgreSQL (uses INSERT RETURNING).
1201
    '''
1202
    row = sql_gen.ColDict(db, table, row)
1203
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
1204
    
1205
    try:
1206
        cur = insert(db, table, row, pkey_, recover=True)
1207
        if row_ct_ref != None and cur.rowcount >= 0:
1208
            row_ct_ref[0] += cur.rowcount
1209
        return value(cur)
1210
    except DuplicateKeyException, e:
1211
        row = sql_gen.ColDict(db, table,
1212
            util.dict_subset_right_join(row, e.cols))
1213
        return value(select(db, table, [pkey_], row, recover=True))
1214

    
1215
def get(db, table, row, pkey, row_ct_ref=None, create=False):
1216
    '''Recovers from errors'''
1217
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
1218
    except StopIteration:
1219
        if not create: raise
1220
        return put(db, table, row, pkey, row_ct_ref) # insert new row
1221

    
1222
def is_func_result(col):
1223
    return col.table.name.find('(') >= 0 and col.name == 'result'
1224

    
1225
def into_table_name(out_table, in_tables0, mapping, is_func):
1226
    def in_col_str(in_col):
1227
        in_col = sql_gen.remove_col_rename(in_col)
1228
        if isinstance(in_col, sql_gen.Col):
1229
            table = in_col.table
1230
            if table == in_tables0:
1231
                in_col = sql_gen.to_name_only_col(in_col)
1232
            elif is_func_result(in_col): in_col = table # omit col name
1233
        return str(in_col)
1234
    
1235
    str_ = str(out_table)
1236
    if is_func:
1237
        str_ += '('
1238
        
1239
        try: value_in_col = mapping['value']
1240
        except KeyError:
1241
            str_ += ', '.join((str(k)+'='+in_col_str(v)
1242
                for k, v in mapping.iteritems()))
1243
        else: str_ += in_col_str(value_in_col)
1244
        
1245
        str_ += ')'
1246
    else:
1247
        out_col = 'rank'
1248
        try: in_col = mapping[out_col]
1249
        except KeyError: str_ += '_pkeys'
1250
        else: # has a rank column, so hierarchical
1251
            str_ += '['+str(out_col)+'='+in_col_str(in_col)+']'
1252
    return str_
1253

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

    
1512
##### Data cleanup
1513

    
1514
def cleanup_table(db, table, cols):
1515
    table = sql_gen.as_Table(table)
1516
    cols = map(sql_gen.as_Col, cols)
1517
    
1518
    expr = ('nullif(nullif(trim(both from %s), '+db.esc_value('')+'), '
1519
        +db.esc_value(r'\N')+')')
1520
    changes = [(v, sql_gen.CustomCode(expr % v.to_str(db)))
1521
        for v in cols]
1522
    
1523
    update(db, table, changes)
(24-24/36)