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 ConstraintException(DbException):
50
    def __init__(self, name, cols, cause=None):
51
        DbException.__init__(self, 'Violated '+strings.as_tt(name)
52
            +' constraint on columns: '+strings.as_tt(', '.join(cols)), cause)
53
        self.name = name
54
        self.cols = cols
55

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

    
63
class NameException(DbException): pass
64

    
65
class DuplicateKeyException(ConstraintException): pass
66

    
67
class NullValueException(ConstraintException): pass
68

    
69
class FunctionValueException(ExceptionWithNameValue): pass
70

    
71
class DuplicateTableException(ExceptionWithName): pass
72

    
73
class DuplicateFunctionException(ExceptionWithName): pass
74

    
75
class EmptyRowException(DbException): pass
76

    
77
##### Warnings
78

    
79
class DbWarning(UserWarning): pass
80

    
81
##### Result retrieval
82

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

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

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

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

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

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

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

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

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

    
108
##### Escaping
109

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

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

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

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

    
128
##### Database connections
129

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

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

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

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

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

    
148
log_debug_none = lambda msg, level=2: None
149

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

    
393
connect = DbConn
394

    
395
##### Recoverable querying
396

    
397
def with_savepoint(db, func): return db.with_savepoint(func)
398

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

    
460
##### Basic queries
461

    
462
def next_version(name):
463
    version = 1 # first existing name was version 0
464
    match = re.match(r'^(.*)#(\d+)$', name)
465
    if match:
466
        name, version = match.groups()
467
        version = int(version)+1
468
    return sql_gen.add_suffix(name, '#'+str(version))
469

    
470
def lock_table(db, table, mode):
471
    table = sql_gen.as_Table(table)
472
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
473

    
474
def run_query_into(db, query, into=None, add_indexes_=False, **kw_args):
475
    '''Outputs a query to a temp table.
476
    For params, see run_query().
477
    '''
478
    if into == None: return run_query(db, query, **kw_args)
479
    
480
    assert isinstance(into, sql_gen.Table)
481
    
482
    kw_args['recover'] = True
483
    kw_args.setdefault('log_ignore_excs', (DuplicateTableException,))
484
    
485
    temp = not db.autocommit # tables are permanent in autocommit mode
486
    # "temporary tables cannot specify a schema name", so remove schema
487
    if temp: into.schema = None
488
    
489
    # Create table
490
    while True:
491
        create_query = 'CREATE'
492
        if temp: create_query += ' TEMP'
493
        create_query += ' TABLE '+into.to_str(db)+' AS\n'+query
494
        
495
        try:
496
            cur = run_query(db, create_query, **kw_args)
497
                # CREATE TABLE AS sets rowcount to # rows in query
498
            break
499
        except DuplicateTableException, e:
500
            into.name = next_version(into.name)
501
            # try again with next version of name
502
    
503
    if add_indexes_: add_indexes(db, into)
504
    
505
    return cur
506

    
507
order_by_pkey = object() # tells mk_select() to order by the pkey
508

    
509
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
510

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

    
592
def select(db, *args, **kw_args):
593
    '''For params, see mk_select() and run_query()'''
594
    recover = kw_args.pop('recover', None)
595
    cacheable = kw_args.pop('cacheable', True)
596
    log_level = kw_args.pop('log_level', 2)
597
    
598
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
599
        log_level=log_level)
600

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

    
657
def insert_select(db, *args, **kw_args):
658
    '''For params, see mk_insert_select() and run_query_into()
659
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
660
        values in
661
    '''
662
    into = kw_args.pop('into', None)
663
    if into != None: kw_args['embeddable'] = True
664
    recover = kw_args.pop('recover', None)
665
    cacheable = kw_args.pop('cacheable', True)
666
    log_level = kw_args.pop('log_level', 2)
667
    
668
    return run_query_into(db, mk_insert_select(db, *args, **kw_args), into,
669
        recover=recover, cacheable=cacheable, log_level=log_level)
670

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

    
673
def insert(db, table, row, *args, **kw_args):
674
    '''For params, see insert_select()'''
675
    if lists.is_seq(row): cols = None
676
    else:
677
        cols = row.keys()
678
        row = row.values()
679
    row = list(row) # ensure that "== []" works
680
    
681
    if row == []: query = None
682
    else: query = sql_gen.Values(row).to_str(db)
683
    
684
    return insert_select(db, table, cols, query, *args, **kw_args)
685

    
686
def mk_update(db, table, changes=None, cond=None):
687
    '''
688
    @param changes [(col, new_value),...]
689
        * container can be any iterable type
690
        * col: sql_gen.Code|str (for col name)
691
        * new_value: sql_gen.Code|literal value
692
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
693
    @return str query
694
    '''
695
    query = 'UPDATE '+sql_gen.as_Table(table).to_str(db)+'\nSET\n'
696
    query += ',\n'.join((sql_gen.to_name_only_col(col, table).to_str(db)+' = '
697
        +sql_gen.as_Value(new_value).to_str(db) for col, new_value in changes))
698
    if cond != None: query += '\nWHERE\n'+cond.to_str(db)
699
    
700
    return query
701

    
702
def update(db, *args, **kw_args):
703
    '''For params, see mk_update() and run_query()'''
704
    recover = kw_args.pop('recover', None)
705
    
706
    return run_query(db, mk_update(db, *args, **kw_args), recover)
707

    
708
def last_insert_id(db):
709
    module = util.root_module(db.db)
710
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
711
    elif module == 'MySQLdb': return db.insert_id()
712
    else: return None
713

    
714
def mk_flatten_mapping(db, into, cols, preserve=[], as_items=False):
715
    '''Creates a mapping from original column names (which may have collisions)
716
    to names that will be distinct among the columns' tables.
717
    This is meant to be used for several tables that are being joined together.
718
    @param cols The columns to combine. Duplicates will be removed.
719
    @param into The table for the new columns.
720
    @param preserve [sql_gen.Col...] Columns not to rename. Note that these
721
        columns will be included in the mapping even if they are not in cols.
722
        The tables of the provided Col objects will be changed to into, so make
723
        copies of them if you want to keep the original tables.
724
    @param as_items Whether to return a list of dict items instead of a dict
725
    @return dict(orig_col=new_col, ...)
726
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
727
        * new_col: sql_gen.Col(orig_col_name, into)
728
        * All mappings use the into table so its name can easily be
729
          changed for all columns at once
730
    '''
731
    cols = lists.uniqify(cols)
732
    
733
    items = []
734
    for col in preserve:
735
        orig_col = copy.copy(col)
736
        col.table = into
737
        items.append((orig_col, col))
738
    preserve = set(preserve)
739
    for col in cols:
740
        if col not in preserve:
741
            items.append((col, sql_gen.Col(str(col), into, col.srcs)))
742
    
743
    if not as_items: items = dict(items)
744
    return items
745

    
746
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
747
    '''For params, see mk_flatten_mapping()
748
    @return See return value of mk_flatten_mapping()
749
    '''
750
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
751
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
752
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
753
        into=into, add_indexes_=True)
754
    return dict(items)
755

    
756
def mk_track_data_error(db, errors_table, cols, value, error_code, error):
757
    assert cols != ()
758
    
759
    cols = map(sql_gen.to_name_only_col, cols)
760
    
761
    columns_cols = ['column']
762
    columns = sql_gen.NamedValues('columns', columns_cols,
763
        [[c.name] for c in cols])
764
    values_cols = ['value', 'error_code', 'error']
765
    values = sql_gen.NamedValues('values', values_cols,
766
        [value, error_code, error])
767
    
768
    select_cols = columns_cols+values_cols
769
    name_only_cols = map(sql_gen.to_name_only_col, select_cols)
770
    errors_table = sql_gen.NamedTable('errors', errors_table)
771
    joins = [columns, sql_gen.Join(values, type_='CROSS'),
772
        sql_gen.Join(errors_table, dict(zip(name_only_cols, select_cols)),
773
        sql_gen.filter_out)]
774
    
775
    return mk_insert_select(db, errors_table, name_only_cols,
776
        mk_select(db, joins, select_cols, order_by=None))
777

    
778
def track_data_error(db, errors_table, cols, *args, **kw_args):
779
    '''
780
    @param errors_table If None, does nothing.
781
    '''
782
    if errors_table == None or cols == (): return
783
    run_query(db, mk_track_data_error(db, errors_table, cols, *args, **kw_args),
784
        cacheable=True, log_level=4)
785

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

    
843
##### Database structure queries
844

    
845
def table_row_count(db, table, recover=None):
846
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
847
        order_by=None, start=0), recover=recover, log_level=3))
848

    
849
def table_cols(db, table, recover=None):
850
    return list(col_names(select(db, table, limit=0, order_by=None,
851
        recover=recover, log_level=4)))
852

    
853
def pkey(db, table, recover=None):
854
    '''Assumed to be first column in table'''
855
    return table_cols(db, table, recover)[0]
856

    
857
not_null_col = 'not_null_col'
858

    
859
def table_not_null_col(db, table, recover=None):
860
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
861
    if not_null_col in table_cols(db, table, recover): return not_null_col
862
    else: return pkey(db, table, recover)
863

    
864
def index_cols(db, table, index):
865
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
866
    automatically created. When you don't know whether something is a UNIQUE
867
    constraint or a UNIQUE index, use this function.'''
868
    module = util.root_module(db.db)
869
    if module == 'psycopg2':
870
        return list(values(run_query(db, '''\
871
SELECT attname
872
FROM
873
(
874
        SELECT attnum, attname
875
        FROM pg_index
876
        JOIN pg_class index ON index.oid = indexrelid
877
        JOIN pg_class table_ ON table_.oid = indrelid
878
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
879
        WHERE
880
            table_.relname = '''+db.esc_value(table)+'''
881
            AND index.relname = '''+db.esc_value(index)+'''
882
    UNION
883
        SELECT attnum, attname
884
        FROM
885
        (
886
            SELECT
887
                indrelid
888
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
889
                    AS indkey
890
            FROM pg_index
891
            JOIN pg_class index ON index.oid = indexrelid
892
            JOIN pg_class table_ ON table_.oid = indrelid
893
            WHERE
894
                table_.relname = '''+db.esc_value(table)+'''
895
                AND index.relname = '''+db.esc_value(index)+'''
896
        ) s
897
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
898
) s
899
ORDER BY attnum
900
'''
901
            , cacheable=True, log_level=4)))
902
    else: raise NotImplementedError("Can't list index columns for "+module+
903
        ' database')
904

    
905
def constraint_cols(db, table, constraint):
906
    module = util.root_module(db.db)
907
    if module == 'psycopg2':
908
        return list(values(run_query(db, '''\
909
SELECT attname
910
FROM pg_constraint
911
JOIN pg_class ON pg_class.oid = conrelid
912
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
913
WHERE
914
    relname = '''+db.esc_value(table)+'''
915
    AND conname = '''+db.esc_value(constraint)+'''
916
ORDER BY attnum
917
'''
918
            )))
919
    else: raise NotImplementedError("Can't list constraint columns for "+module+
920
        ' database')
921

    
922
row_num_col = '_row_num'
923

    
924
def add_index(db, exprs, table=None, unique=False, ensure_not_null=True):
925
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
926
    Currently, only function calls are supported as expressions.
927
    @param ensure_not_null If set, translates NULL values to sentinel values.
928
        This allows indexes to be used for comparisons where NULLs are equal.
929
    '''
930
    if not lists.is_seq(exprs): exprs = [exprs]
931
    
932
    # Parse exprs
933
    old_exprs = exprs[:]
934
    exprs = []
935
    cols = []
936
    for i, expr in enumerate(old_exprs):
937
        expr = copy.deepcopy(expr) # don't modify input!
938
        expr = sql_gen.as_Col(expr, table)
939
        
940
        # Handle nullable columns
941
        if ensure_not_null:
942
            try: expr = sql_gen.ensure_not_null(db, expr)
943
            except KeyError: pass # unknown type, so just create plain index
944
        
945
        # Extract col
946
        if isinstance(expr, sql_gen.FunctionCall):
947
            col = expr.args[0]
948
            expr = sql_gen.Expr(expr)
949
        else: col = expr
950
        assert isinstance(col, sql_gen.Col)
951
        
952
        # Extract table
953
        if table == None:
954
            assert sql_gen.is_table_col(col)
955
            table = col.table
956
        
957
        col.table = None
958
        
959
        exprs.append(expr)
960
        cols.append(col)
961
    
962
    table = sql_gen.as_Table(table)
963
    index = sql_gen.Table(str(sql_gen.Col(','.join(map(str, cols)), table)))
964
    
965
    str_ = 'CREATE'
966
    if unique: str_ += ' UNIQUE'
967
    str_ += ' INDEX '+index.to_str(db)+' ON '+table.to_str(db)+' ('+(
968
        ', '.join((v.to_str(db) for v in exprs)))+')'
969
    
970
    try: run_query(db, str_, recover=True, cacheable=True, log_level=3)
971
    except DuplicateTableException: pass # index already existed
972

    
973
def add_pkey(db, table, cols=None, recover=None):
974
    '''Adds a primary key.
975
    @param cols [sql_gen.Col,...] The columns in the primary key.
976
        Defaults to the first column in the table.
977
    @pre The table must not already have a primary key.
978
    '''
979
    table = sql_gen.as_Table(table)
980
    if cols == None: cols = [pkey(db, table, recover)]
981
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
982
    
983
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
984
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
985
        log_ignore_excs=(DuplicateTableException,))
986

    
987
already_indexed = object() # tells add_indexes() the pkey has already been added
988

    
989
def add_indexes(db, table, has_pkey=True):
990
    '''Adds an index on all columns in a table.
991
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
992
        index should be added on the first column.
993
        * If already_indexed, the pkey is assumed to have already been added
994
    '''
995
    cols = table_cols(db, table)
996
    if has_pkey:
997
        if has_pkey is not already_indexed: add_pkey(db, table)
998
        cols = cols[1:]
999
    for col in cols: add_index(db, col, table)
1000

    
1001
def add_row_num(db, table):
1002
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1003
    be the primary key.'''
1004
    table = sql_gen.as_Table(table).to_str(db)
1005
    run_query(db, 'ALTER TABLE '+table+' ADD COLUMN '+row_num_col
1006
        +' serial NOT NULL PRIMARY KEY', log_level=3)
1007

    
1008
def drop_table(db, table):
1009
    table = sql_gen.as_Table(table)
1010
    return run_query(db, 'DROP TABLE IF EXISTS '+table.to_str(db)+' CASCADE')
1011

    
1012
def create_table(db, table, cols, has_pkey=True, col_indexes=True):
1013
    '''Creates a table.
1014
    @param cols [sql_gen.TypedCol,...] The column names and types
1015
    @param has_pkey If set, the first column becomes the primary key.
1016
    @param col_indexes bool|[ref]
1017
        * If True, indexes will be added on all non-pkey columns.
1018
        * If a list reference, [0] will be set to a function to do this.
1019
          This can be used to delay index creation until the table is populated.
1020
    '''
1021
    table = sql_gen.as_Table(table)
1022
    
1023
    if has_pkey:
1024
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1025
        pkey.constraints = 'PRIMARY KEY'
1026
    
1027
    str_ = 'CREATE TABLE '+table.to_str(db)+' (\n'
1028
    str_ += '\n, '.join(v.to_str(db) for v in cols)
1029
    str_ += '\n);\n'
1030
    run_query(db, str_, cacheable=True, log_level=2)
1031
    
1032
    # Add indexes
1033
    if has_pkey: has_pkey = already_indexed
1034
    def add_indexes_(): add_indexes(db, table, has_pkey)
1035
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1036
    elif col_indexes: add_indexes_() # add now
1037

    
1038
def vacuum(db, table):
1039
    table = sql_gen.as_Table(table)
1040
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1041
        log_level=3))
1042

    
1043
def truncate(db, table, schema='public'):
1044
    table = sql_gen.as_Table(table, schema)
1045
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE')
1046

    
1047
def tables(db, schema_like='public', table_like='%', exact=False):
1048
    if exact: compare = '='
1049
    else: compare = 'LIKE'
1050
    
1051
    module = util.root_module(db.db)
1052
    if module == 'psycopg2':
1053
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1054
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1055
        return values(select(db, 'pg_tables', ['tablename'], conds,
1056
            order_by='tablename', log_level=4))
1057
    elif module == 'MySQLdb':
1058
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1059
            , cacheable=True, log_level=4))
1060
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1061

    
1062
def table_exists(db, table):
1063
    table = sql_gen.as_Table(table)
1064
    return list(tables(db, table.schema, table.name, exact=True)) != []
1065

    
1066
def function_exists(db, function):
1067
    function = sql_gen.as_Function(function)
1068
    
1069
    info_table = sql_gen.Table('routines', 'information_schema')
1070
    conds = [('routine_name', function.name)]
1071
    schema = function.schema
1072
    if schema != None: conds.append(('routine_schema', schema))
1073
    # Exclude trigger functions, since they cannot be called directly
1074
    conds.append(('data_type', sql_gen.CompareCond('trigger', '!=')))
1075
    
1076
    return list(values(select(db, info_table, ['routine_name'], conds,
1077
        order_by='routine_schema', limit=1, log_level=4))) != []
1078
        # TODO: order_by search_path schema order
1079

    
1080
def errors_table(db, table, if_exists=True):
1081
    '''
1082
    @param if_exists If set, returns None if the errors table doesn't exist
1083
    @return None|sql_gen.Table
1084
    '''
1085
    table = sql_gen.as_Table(table)
1086
    if table.srcs != (): table = table.srcs[0]
1087
    
1088
    errors_table = sql_gen.suffixed_table(table, '.errors')
1089
    if if_exists and not table_exists(db, errors_table): return None
1090
    return errors_table
1091

    
1092
##### Database management
1093

    
1094
def empty_db(db, schema='public', **kw_args):
1095
    '''For kw_args, see tables()'''
1096
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1097

    
1098
##### Heuristic queries
1099

    
1100
def put(db, table, row, pkey_=None, row_ct_ref=None):
1101
    '''Recovers from errors.
1102
    Only works under PostgreSQL (uses INSERT RETURNING).
1103
    '''
1104
    row = sql_gen.ColDict(db, table, row)
1105
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
1106
    
1107
    try:
1108
        cur = insert(db, table, row, pkey_, recover=True)
1109
        if row_ct_ref != None and cur.rowcount >= 0:
1110
            row_ct_ref[0] += cur.rowcount
1111
        return value(cur)
1112
    except DuplicateKeyException, e:
1113
        row = sql_gen.ColDict(db, table,
1114
            util.dict_subset_right_join(row, e.cols))
1115
        return value(select(db, table, [pkey_], row, recover=True))
1116

    
1117
def get(db, table, row, pkey, row_ct_ref=None, create=False):
1118
    '''Recovers from errors'''
1119
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
1120
    except StopIteration:
1121
        if not create: raise
1122
        return put(db, table, row, pkey, row_ct_ref) # insert new row
1123

    
1124
def is_func_result(col):
1125
    return col.table.name.find('(') >= 0 and col.name == 'result'
1126

    
1127
def into_table_name(out_table, in_tables0, mapping, is_func):
1128
    def in_col_str(in_col):
1129
        in_col = sql_gen.remove_col_rename(in_col)
1130
        if isinstance(in_col, sql_gen.Col):
1131
            table = in_col.table
1132
            if table == in_tables0:
1133
                in_col = sql_gen.to_name_only_col(in_col)
1134
            elif is_func_result(in_col): in_col = table # omit col name
1135
        return str(in_col)
1136
    
1137
    str_ = str(out_table)
1138
    if is_func:
1139
        str_ += '('
1140
        
1141
        try: value_in_col = mapping['value']
1142
        except KeyError:
1143
            str_ += ', '.join((str(k)+'='+in_col_str(v)
1144
                for k, v in mapping.iteritems()))
1145
        else: str_ += in_col_str(value_in_col)
1146
        
1147
        str_ += ')'
1148
    else:
1149
        out_col = 'rank'
1150
        try: in_col = mapping[out_col]
1151
        except KeyError: str_ += '_pkeys'
1152
        else: # has a rank column, so hierarchical
1153
            str_ += '['+str(out_col)+'='+in_col_str(in_col)+']'
1154
    return str_
1155

    
1156
def put_table(db, out_table, in_tables, mapping, row_ct_ref=None, into=None,
1157
    default=None, is_func=False, on_error=exc.raise_):
1158
    '''Recovers from errors.
1159
    Only works under PostgreSQL (uses INSERT RETURNING).
1160
    IMPORTANT: Must be run at the *beginning* of a transaction.
1161
    @param in_tables The main input table to select from, followed by a list of
1162
        tables to join with it using the main input table's pkey
1163
    @param mapping dict(out_table_col=in_table_col, ...)
1164
        * out_table_col: str (*not* sql_gen.Col)
1165
        * in_table_col: sql_gen.Col|literal-value
1166
    @param into The table to contain the output and input pkeys.
1167
        Defaults to `out_table.name+'_pkeys'`.
1168
    @param default The *output* column to use as the pkey for missing rows.
1169
        If this output column does not exist in the mapping, uses None.
1170
    @param is_func Whether out_table is the name of a SQL function, not a table
1171
    @return sql_gen.Col Where the output pkeys are made available
1172
    '''
1173
    out_table = sql_gen.as_Table(out_table)
1174
    
1175
    def log_debug(msg): db.log_debug(msg, level=1.5)
1176
    def col_ustr(str_):
1177
        return strings.repr_no_u(sql_gen.remove_col_rename(str_))
1178
    
1179
    log_debug('********** New iteration **********')
1180
    log_debug('Inserting these input columns into '+strings.as_tt(
1181
        out_table.to_str(db))+':\n'+strings.as_table(mapping, ustr=col_ustr))
1182
    
1183
    log_debug('Locking output table to prevent concurrent duplicate keys')
1184
    # Must happen before any SELECT query on the table to avoid lock upgrades
1185
    lock_table(db, out_table, 'EXCLUSIVE')
1186
    
1187
    out_pkey = pkey(db, out_table, recover=True)
1188
    out_pkey_col = sql_gen.as_Col(out_pkey, out_table)
1189
    
1190
    if mapping == {}: # need at least one column for INSERT SELECT
1191
        mapping = {out_pkey: None} # ColDict will replace with default value
1192
    
1193
    # Create input joins from list of input tables
1194
    in_tables_ = in_tables[:] # don't modify input!
1195
    in_tables0 = in_tables_.pop(0) # first table is separate
1196
    errors_table_ = errors_table(db, in_tables0)
1197
    in_pkey = pkey(db, in_tables0, recover=True)
1198
    in_pkey_col = sql_gen.as_Col(in_pkey, in_tables0)
1199
    input_joins = [in_tables0]+[sql_gen.Join(v,
1200
        {in_pkey: sql_gen.join_same_not_null}) for v in in_tables_]
1201
    
1202
    if into == None:
1203
        into = into_table_name(out_table, in_tables0, mapping, is_func)
1204
    into = sql_gen.as_Table(into)
1205
    
1206
    # Set column sources
1207
    in_cols = filter(sql_gen.is_table_col, mapping.values())
1208
    for col in in_cols:
1209
        if col.table == in_tables0: col.set_srcs(sql_gen.src_self)
1210
    
1211
    log_debug('Joining together input tables into temp table')
1212
    # Place in new table for speed and so don't modify input if values edited
1213
    in_table = sql_gen.Table('in')
1214
    mapping = dicts.join(mapping, flatten(db, in_table, input_joins, in_cols,
1215
        preserve=[in_pkey_col], start=0))
1216
    input_joins = [in_table]
1217
    db.log_debug('Temp table: '+strings.as_tt(in_table.to_str(db)), level=2)
1218
    
1219
    mapping = sql_gen.ColDict(db, out_table, mapping)
1220
        # after applying dicts.join() because that returns a plain dict
1221
    
1222
    # Resolve default value column
1223
    if default != None:
1224
        try: default = mapping[default]
1225
        except KeyError:
1226
            db.log_debug('Default value column '
1227
                +strings.as_tt(strings.repr_no_u(default))
1228
                +' does not exist in mapping, falling back to None', level=2.1)
1229
            default = None
1230
    
1231
    pkeys_names = [in_pkey, out_pkey]
1232
    pkeys_cols = [in_pkey_col, out_pkey_col]
1233
    
1234
    pkeys_table_exists_ref = [False]
1235
    def insert_into_pkeys(joins, cols):
1236
        query = mk_select(db, joins, cols, order_by=None, start=0)
1237
        if pkeys_table_exists_ref[0]:
1238
            insert_select(db, into, pkeys_names, query)
1239
        else:
1240
            run_query_into(db, query, into=into)
1241
            pkeys_table_exists_ref[0] = True
1242
    
1243
    limit_ref = [None]
1244
    conds = set()
1245
    distinct_on = sql_gen.ColDict(db, out_table)
1246
    def mk_main_select(joins, cols):
1247
        distinct_on_cols = [c.to_Col() for c in distinct_on.values()]
1248
        return mk_select(db, joins, cols, conds, distinct_on_cols,
1249
            limit=limit_ref[0], start=0)
1250
    
1251
    exc_strs = set()
1252
    def log_exc(e):
1253
        e_str = exc.str_(e, first_line_only=True)
1254
        log_debug('Caught exception: '+e_str)
1255
        assert e_str not in exc_strs # avoid infinite loops
1256
        exc_strs.add(e_str)
1257
    
1258
    def remove_all_rows():
1259
        log_debug('Ignoring all rows')
1260
        limit_ref[0] = 0 # just create an empty pkeys table
1261
    
1262
    def ignore(in_col, value, e):
1263
        track_data_error(db, errors_table_, in_col.srcs, value, e.cause.pgcode,
1264
            e.cause.pgerror)
1265
        log_debug('Ignoring rows with '+strings.as_tt(repr(in_col))+' = '
1266
            +strings.as_tt(repr(value)))
1267
    
1268
    def remove_rows(in_col, value, e):
1269
        ignore(in_col, value, e)
1270
        cond = (in_col, sql_gen.CompareCond(value, '!='))
1271
        assert cond not in conds # avoid infinite loops
1272
        conds.add(cond)
1273
    
1274
    def invalid2null(in_col, value, e):
1275
        ignore(in_col, value, e)
1276
        update(db, in_table, [(in_col, None)],
1277
            sql_gen.ColValueCond(in_col, value))
1278
    
1279
    def insert_pkeys_table(which):
1280
        return sql_gen.Table(sql_gen.add_suffix(in_table.name,
1281
            '_insert_'+which+'_pkeys'))
1282
    insert_out_pkeys = insert_pkeys_table('out')
1283
    insert_in_pkeys = insert_pkeys_table('in')
1284
    
1285
    # Do inserts and selects
1286
    join_cols = sql_gen.ColDict(db, out_table)
1287
    while True:
1288
        if limit_ref[0] == 0: # special case
1289
            log_debug('Creating an empty pkeys table')
1290
            cur = run_query_into(db, mk_select(db, out_table, [out_pkey],
1291
                limit=limit_ref[0]), into=insert_out_pkeys)
1292
            break # don't do main case
1293
        
1294
        has_joins = join_cols != {}
1295
        
1296
        log_debug('Trying to insert new rows')
1297
        
1298
        # Prepare to insert new rows
1299
        insert_joins = input_joins[:] # don't modify original!
1300
        insert_args = dict(recover=True, cacheable=False)
1301
        if has_joins:
1302
            insert_joins.append(sql_gen.Join(out_table, join_cols,
1303
                sql_gen.filter_out))
1304
        else:
1305
            insert_args.update(dict(returning=out_pkey, into=insert_out_pkeys))
1306
        main_select = mk_main_select(insert_joins, mapping.values())
1307
        
1308
        try:
1309
            cur = insert_select(db, out_table, mapping.keys(), main_select,
1310
                **insert_args)
1311
            break # insert successful
1312
        except DuplicateKeyException, e:
1313
            log_exc(e)
1314
            
1315
            old_join_cols = join_cols.copy()
1316
            distinct_on.update(util.dict_subset(mapping, e.cols))
1317
            join_cols.update(util.dict_subset_right_join(mapping, e.cols))
1318
            log_debug('Ignoring existing rows, comparing on these columns:\n'
1319
                +strings.as_inline_table(join_cols, ustr=col_ustr))
1320
            assert join_cols != old_join_cols # avoid infinite loops
1321
        except NullValueException, e:
1322
            log_exc(e)
1323
            
1324
            out_col, = e.cols
1325
            try: in_col = mapping[out_col]
1326
            except KeyError:
1327
                log_debug('Missing mapping for NOT NULL column '+out_col)
1328
                remove_all_rows()
1329
            else: remove_rows(in_col, None, e)
1330
        except FunctionValueException, e:
1331
            log_exc(e)
1332
            
1333
            func_name = e.name
1334
            value = e.value
1335
            for out_col, in_col in mapping.iteritems():
1336
                in_col = sql_gen.unwrap_func_call(in_col, func_name)
1337
                invalid2null(in_col, value, e)
1338
        except MissingCastException, e:
1339
            log_exc(e)
1340
            
1341
            out_col = e.col
1342
            type_ = e.type
1343
            
1344
            log_debug('Casting '+strings.as_tt(out_col)+' input to '
1345
                +strings.as_tt(type_))
1346
            def wrap_func(col): return cast(db, type_, col, errors_table_)
1347
            mapping[out_col] = sql_gen.wrap(wrap_func, mapping[out_col])
1348
        except DatabaseErrors, e:
1349
            log_exc(e)
1350
            
1351
            log_debug('No handler for exception')
1352
            on_error(e)
1353
            remove_all_rows()
1354
        # after exception handled, rerun loop with additional constraints
1355
    
1356
    if row_ct_ref != None and cur.rowcount >= 0:
1357
        row_ct_ref[0] += cur.rowcount
1358
    
1359
    if has_joins:
1360
        select_joins = input_joins+[sql_gen.Join(out_table, join_cols)]
1361
        log_debug('Getting output table pkeys of existing/inserted rows')
1362
        insert_into_pkeys(select_joins, pkeys_cols)
1363
    else:
1364
        add_row_num(db, insert_out_pkeys) # for joining with input pkeys
1365
        
1366
        log_debug('Getting input table pkeys of inserted rows')
1367
        run_query_into(db, mk_main_select(input_joins, [in_pkey]),
1368
            into=insert_in_pkeys)
1369
        add_row_num(db, insert_in_pkeys) # for joining with output pkeys
1370
        
1371
        assert table_row_count(db, insert_out_pkeys) == table_row_count(db,
1372
            insert_in_pkeys)
1373
        
1374
        log_debug('Combining output and input pkeys in inserted order')
1375
        pkey_joins = [insert_in_pkeys, sql_gen.Join(insert_out_pkeys,
1376
            {row_num_col: sql_gen.join_same_not_null})]
1377
        insert_into_pkeys(pkey_joins, pkeys_names)
1378
    
1379
    db.log_debug('Adding pkey on pkeys table to enable fast joins', level=2.5)
1380
    add_pkey(db, into)
1381
    
1382
    log_debug('Setting pkeys of missing rows to '+strings.as_tt(repr(default)))
1383
    missing_rows_joins = input_joins+[sql_gen.Join(into,
1384
        {in_pkey: sql_gen.join_same_not_null}, sql_gen.filter_out)]
1385
        # must use join_same_not_null or query will take forever
1386
    insert_into_pkeys(missing_rows_joins,
1387
        [in_pkey_col, sql_gen.NamedCol(out_pkey, default)])
1388
    
1389
    assert table_row_count(db, into) == table_row_count(db, in_table)
1390
    
1391
    srcs = []
1392
    if is_func: srcs = sql_gen.cols_srcs(in_cols)
1393
    return sql_gen.Col(out_pkey, into, srcs)
1394

    
1395
##### Data cleanup
1396

    
1397
def cleanup_table(db, table, cols):
1398
    table = sql_gen.as_Table(table)
1399
    cols = map(sql_gen.as_Col, cols)
1400
    
1401
    expr = ('nullif(nullif(trim(both from %s), '+db.esc_value('')+'), '
1402
        +db.esc_value(r'\N')+')')
1403
    changes = [(v, sql_gen.CustomCode(expr % v.to_str(db)))
1404
        for v in cols]
1405
    
1406
    update(db, table, changes)
(24-24/36)