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

    
388
connect = DbConn
389

    
390
##### Recoverable querying
391

    
392
def with_savepoint(db, func): return db.with_savepoint(func)
393

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

    
455
##### Basic queries
456

    
457
def next_version(name):
458
    version = 1 # first existing name was version 0
459
    match = re.match(r'^(.*)#(\d+)$', name)
460
    if match:
461
        name, version = match.groups()
462
        version = int(version)+1
463
    return sql_gen.add_suffix(name, '#'+str(version))
464

    
465
def lock_table(db, table, mode):
466
    table = sql_gen.as_Table(table)
467
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
468

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

    
502
order_by_pkey = object() # tells mk_select() to order by the pkey
503

    
504
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
505

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

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

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

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

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

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

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

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

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

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

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

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

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

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

    
840
##### Database structure queries
841

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

    
846
def table_cols(db, table, recover=None):
847
    return list(col_names(select(db, table, limit=0, order_by=None,
848
        recover=recover, log_level=4)))
849

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

    
854
not_null_col = 'not_null_col'
855

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

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

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

    
919
row_num_col = '_row_num'
920

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

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

    
984
already_indexed = object() # tells add_indexes() the pkey has already been added
985

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

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

    
1005
def drop_table(db, table):
1006
    table = sql_gen.as_Table(table)
1007
    return run_query(db, 'DROP TABLE IF EXISTS '+table.to_str(db)+' CASCADE')
1008

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

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

    
1040
def truncate(db, table, schema='public'):
1041
    table = sql_gen.as_Table(table, schema)
1042
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE')
1043

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

    
1059
def table_exists(db, table):
1060
    table = sql_gen.as_Table(table)
1061
    return list(tables(db, table.schema, table.name, exact=True)) != []
1062

    
1063
def errors_table(db, table, if_exists=True):
1064
    '''
1065
    @param if_exists If set, returns None if the errors table doesn't exist
1066
    @return None|sql_gen.Table
1067
    '''
1068
    table = sql_gen.as_Table(table)
1069
    if table.srcs != (): table = table.srcs[0]
1070
    
1071
    errors_table = sql_gen.suffixed_table(table, '.errors')
1072
    if if_exists and not table_exists(db, errors_table): return None
1073
    return errors_table
1074

    
1075
##### Database management
1076

    
1077
def empty_db(db, schema='public', **kw_args):
1078
    '''For kw_args, see tables()'''
1079
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1080

    
1081
##### Heuristic queries
1082

    
1083
def put(db, table, row, pkey_=None, row_ct_ref=None):
1084
    '''Recovers from errors.
1085
    Only works under PostgreSQL (uses INSERT RETURNING).
1086
    '''
1087
    row = sql_gen.ColDict(db, table, row)
1088
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
1089
    
1090
    try:
1091
        cur = insert(db, table, row, pkey_, recover=True)
1092
        if row_ct_ref != None and cur.rowcount >= 0:
1093
            row_ct_ref[0] += cur.rowcount
1094
        return value(cur)
1095
    except DuplicateKeyException, e:
1096
        row = sql_gen.ColDict(db, table,
1097
            util.dict_subset_right_join(row, e.cols))
1098
        return value(select(db, table, [pkey_], row, recover=True))
1099

    
1100
def get(db, table, row, pkey, row_ct_ref=None, create=False):
1101
    '''Recovers from errors'''
1102
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
1103
    except StopIteration:
1104
        if not create: raise
1105
        return put(db, table, row, pkey, row_ct_ref) # insert new row
1106

    
1107
def is_func_result(col):
1108
    return col.table.name.find('(') >= 0 and col.name == 'result'
1109

    
1110
def into_table_name(out_table, in_tables0, mapping, is_func):
1111
    def in_col_str(in_col):
1112
        in_col = sql_gen.remove_col_rename(in_col)
1113
        if isinstance(in_col, sql_gen.Col):
1114
            table = in_col.table
1115
            if table == in_tables0:
1116
                in_col = sql_gen.to_name_only_col(in_col)
1117
            elif is_func_result(in_col): in_col = table # omit col name
1118
        return str(in_col)
1119
    
1120
    str_ = str(out_table)
1121
    if is_func:
1122
        str_ += '('
1123
        
1124
        try: value_in_col = mapping['value']
1125
        except KeyError:
1126
            str_ += ', '.join((str(k)+'='+in_col_str(v)
1127
                for k, v in mapping.iteritems()))
1128
        else: str_ += in_col_str(value_in_col)
1129
        
1130
        str_ += ')'
1131
    else:
1132
        out_col = 'rank'
1133
        try: in_col = mapping[out_col]
1134
        except KeyError: str_ += '_pkeys'
1135
        else: # has a rank column, so hierarchical
1136
            str_ += '['+str(out_col)+'='+in_col_str(in_col)+']'
1137
    return str_
1138

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

    
1373
##### Data cleanup
1374

    
1375
def cleanup_table(db, table, cols):
1376
    table = sql_gen.as_Table(table)
1377
    cols = map(sql_gen.as_Col, cols)
1378
    
1379
    expr = ('nullif(nullif(trim(both from %s), '+db.esc_value('')+'), '
1380
        +db.esc_value(r'\N')+')')
1381
    changes = [(v, sql_gen.CustomCode(expr % v.to_str(db)))
1382
        for v in cols]
1383
    
1384
    update(db, table, changes)
(24-24/36)