Project

General

Profile

1
# Database access
2

    
3
import copy
4
import operator
5
import re
6
import warnings
7

    
8
import exc
9
import dicts
10
import iters
11
import lists
12
from Proxy import Proxy
13
import rand
14
import sql_gen
15
import strings
16
import util
17

    
18
##### Exceptions
19

    
20
def get_cur_query(cur, input_query=None, input_params=None):
21
    raw_query = None
22
    if hasattr(cur, 'query'): raw_query = cur.query
23
    elif hasattr(cur, '_last_executed'): raw_query = cur._last_executed
24
    
25
    if raw_query != None: return raw_query
26
    else: return '[input] '+strings.ustr(input_query)+' % '+repr(input_params)
27

    
28
def _add_cursor_info(e, *args, **kw_args):
29
    '''For params, see get_cur_query()'''
30
    exc.add_msg(e, 'query: '+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
def _query_lookup(query, params): return (query, dicts.make_hashable(params))
149

    
150
log_debug_none = lambda msg, level=2: None
151

    
152
class DbConn:
153
    def __init__(self, db_config, serializable=True, autocommit=False,
154
        caching=True, log_debug=log_debug_none):
155
        self.db_config = db_config
156
        self.serializable = serializable
157
        self.autocommit = autocommit
158
        self.caching = caching
159
        self.log_debug = log_debug
160
        self.debug = log_debug != log_debug_none
161
        
162
        self.__db = None
163
        self.query_results = {}
164
        self._savepoint = 0
165
        self._notices_seen = set()
166
    
167
    def __getattr__(self, name):
168
        if name == '__dict__': raise Exception('getting __dict__')
169
        if name == 'db': return self._db()
170
        else: raise AttributeError()
171
    
172
    def __getstate__(self):
173
        state = copy.copy(self.__dict__) # shallow copy
174
        state['log_debug'] = None # don't pickle the debug callback
175
        state['_DbConn__db'] = None # don't pickle the connection
176
        return state
177
    
178
    def connected(self): return self.__db != None
179
    
180
    def _db(self):
181
        if self.__db == None:
182
            # Process db_config
183
            db_config = self.db_config.copy() # don't modify input!
184
            schemas = db_config.pop('schemas', None)
185
            module_name, mappings = db_engines[db_config.pop('engine')]
186
            module = __import__(module_name)
187
            _add_module(module)
188
            for orig, new in mappings.iteritems():
189
                try: util.rename_key(db_config, orig, new)
190
                except KeyError: pass
191
            
192
            # Connect
193
            self.__db = module.connect(**db_config)
194
            
195
            # Configure connection
196
            if self.serializable and not self.autocommit: self.run_query(
197
                'SET TRANSACTION ISOLATION LEVEL SERIALIZABLE', log_level=4)
198
            if schemas != None:
199
                schemas_ = ''.join((esc_name(self, s)+', '
200
                    for s in schemas.split(',')))
201
                self.run_query("SELECT set_config('search_path', "
202
                    +self.esc_value(schemas_)
203
                    +" || current_setting('search_path'), false)", log_level=3)
204
        
205
        return self.__db
206
    
207
    class DbCursor(Proxy):
208
        def __init__(self, outer):
209
            Proxy.__init__(self, outer.db.cursor())
210
            self.outer = outer
211
            self.query_results = outer.query_results
212
            self.query_lookup = None
213
            self.result = []
214
        
215
        def execute(self, query, params=None):
216
            assert params == None or params == [] or params == ()
217
            if params == [] or params == (): params = None
218
                # None turns off the mogrifier
219
            
220
            self._is_insert = query.startswith('INSERT')
221
            self.query_lookup = _query_lookup(query, params)
222
            try:
223
                try:
224
                    cur = self.inner.execute(query, params)
225
                    self.outer.do_autocommit()
226
                finally: self.query = get_cur_query(self.inner, query, params)
227
            except Exception, e:
228
                _add_cursor_info(e, self, query, params)
229
                self.result = e # cache the exception as the result
230
                self._cache_result()
231
                raise
232
            # Fetch all rows so result will be cached
233
            if self.rowcount == 0 and not self._is_insert: consume_rows(self)
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 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
                query_lookup = _query_lookup(query, [])
317
                try:
318
                    cur = self.query_results[query_lookup]
319
                    used_cache = True
320
                except KeyError: cur = self.DbCursor(self)
321
            else: cur = self.db.cursor()
322
            
323
            # Log query
324
            if self.debug and debug_msg_ref == None: # log before running
325
                self.log_debug(log_msg(query), log_level)
326
            
327
            # Run query
328
            cur.execute(query)
329
        finally:
330
            self.print_notices()
331
            if self.debug and debug_msg_ref != None: # return after running
332
                debug_msg_ref[0] = log_msg(str(get_cur_query(cur, query)))
333
        
334
        return cur
335
    
336
    def is_cached(self, query, params=None):
337
        return _query_lookup(query, params) in self.query_results
338
    
339
    def with_autocommit(self, func, autocommit=True):
340
        prev_autocommit = self.db.autocommit
341
        self.db.autocommit = autocommit
342
        try: return func()
343
        finally: self.db.autocommit = prev_autocommit
344
    
345
    def with_savepoint(self, func):
346
        savepoint = 'level_'+str(self._savepoint)
347
        self.run_query('SAVEPOINT '+savepoint, log_level=4)
348
        self._savepoint += 1
349
        try:
350
            try: return_val = func()
351
            finally:
352
                self._savepoint -= 1
353
                assert self._savepoint >= 0
354
        except:
355
            self.run_query('ROLLBACK TO SAVEPOINT '+savepoint, log_level=4)
356
            raise
357
        else:
358
            self.run_query('RELEASE SAVEPOINT '+savepoint, log_level=4)
359
            self.do_autocommit()
360
            return return_val
361
    
362
    def do_autocommit(self):
363
        '''Autocommits if outside savepoint'''
364
        assert self._savepoint >= 0
365
        if self.autocommit and self._savepoint == 0:
366
            self.log_debug('Autocommitting')
367
            self.db.commit()
368
    
369
    def col_default(self, col):
370
        table = sql_gen.Table('columns', 'information_schema')
371
        
372
        conds = [('table_name', col.table.name), ('column_name', col.name)]
373
        schema = col.table.schema
374
        if schema != None: conds.append(('table_schema', schema))
375
        
376
        return sql_gen.as_Code(value(select(self, table, ['column_default'],
377
            conds, order_by='table_schema', limit=1, log_level=3)))
378
            # TODO: order_by search_path schema order
379

    
380
connect = DbConn
381

    
382
##### Querying
383

    
384
def run_raw_query(db, *args, **kw_args):
385
    '''For params, see DbConn.run_query()'''
386
    return db.run_query(*args, **kw_args)
387

    
388
def mogrify(db, query, params):
389
    module = util.root_module(db.db)
390
    if module == 'psycopg2': return db.db.cursor().mogrify(query, params)
391
    else: raise NotImplementedError("Can't mogrify query for "+module+
392
        ' database')
393

    
394
##### Recoverable querying
395

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

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

    
459
##### Basic queries
460

    
461
def next_version(name):
462
    version = 1 # first existing name was version 0
463
    match = re.match(r'^(.*)#(\d+)$', name)
464
    if match:
465
        name, version = match.groups()
466
        version = int(version)+1
467
    return sql_gen.add_suffix(name, '#'+str(version))
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
                None))
564
        
565
        query += '\n'+join_.to_str(db, left_table)
566
        
567
        left_table = table
568
    
569
    missing = True
570
    if conds != []:
571
        if len(conds) == 1: whitespace = ' '
572
        else: whitespace = '\n'
573
        query += '\n'+sql_gen.combine_conds([sql_gen.ColValueCond(l, r)
574
            .to_str(db) for l, r in conds], 'WHERE')
575
        missing = False
576
    if order_by != None:
577
        query += '\nORDER BY '+sql_gen.as_Col(order_by, table0).to_str(db)
578
    if limit != None: query += '\nLIMIT '+str(limit); missing = False
579
    if start != None:
580
        if start != 0: query += '\nOFFSET '+str(start)
581
        missing = False
582
    if missing: warnings.warn(DbWarning(
583
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
584
    
585
    return query
586

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

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

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

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

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

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

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

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

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

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

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

    
771
def track_data_error(db, errors_table, *args, **kw_args):
772
    '''
773
    @param errors_table If None, does nothing.
774
    '''
775
    if errors_table == None: return
776
    run_query(db, mk_track_data_error(db, errors_table, *args, **kw_args),
777
        cacheable=True, log_level=4)
778

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

    
835
##### Database structure queries
836

    
837
def table_row_count(db, table, recover=None):
838
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
839
        order_by=None, start=0), recover=recover, log_level=3))
840

    
841
def table_cols(db, table, recover=None):
842
    return list(col_names(select(db, table, limit=0, order_by=None,
843
        recover=recover, log_level=4)))
844

    
845
def pkey(db, table, recover=None):
846
    '''Assumed to be first column in table'''
847
    return table_cols(db, table, recover)[0]
848

    
849
not_null_col = 'not_null_col'
850

    
851
def table_not_null_col(db, table, recover=None):
852
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
853
    if not_null_col in table_cols(db, table, recover): return not_null_col
854
    else: return pkey(db, table, recover)
855

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

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

    
914
row_num_col = '_row_num'
915

    
916
def add_index(db, exprs, table=None, unique=False):
917
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
918
    Currently, only function calls are supported as expressions.
919
    '''
920
    if not lists.is_seq(exprs): exprs = [exprs]
921
    
922
    # Parse exprs
923
    old_exprs = exprs[:]
924
    exprs = []
925
    cols = []
926
    for i, expr in enumerate(old_exprs):
927
        expr = copy.deepcopy(expr) # don't modify input!
928
        expr = sql_gen.as_Col(expr)
929
        
930
        # Extract col
931
        if isinstance(expr, sql_gen.FunctionCall):
932
            col = expr.args[0]
933
            expr = sql_gen.Expr(expr)
934
        else: col = expr
935
        
936
        # Extract table
937
        if table == None:
938
            assert sql_gen.is_table_col(col)
939
            table = col.table
940
        
941
        col.table = None
942
        
943
        exprs.append(expr)
944
        cols.append(col)
945
    
946
    table = sql_gen.as_Table(table)
947
    index = sql_gen.Table(str(sql_gen.Col(','.join(map(str, cols)), table)))
948
    
949
    str_ = 'CREATE'
950
    if unique: str_ += ' UNIQUE'
951
    str_ += ' INDEX '+index.to_str(db)+' ON '+table.to_str(db)+' ('+(
952
        ', '.join((v.to_str(db) for v in exprs)))+')'
953
    
954
    try: run_query(db, str_, recover=True, cacheable=True, log_level=3)
955
    except DuplicateTableException: pass # index already existed
956

    
957
def add_pkey(db, table, cols=None, recover=None):
958
    '''Adds a primary key.
959
    @param cols [sql_gen.Col,...] The columns in the primary key.
960
        Defaults to the first column in the table.
961
    @pre The table must not already have a primary key.
962
    '''
963
    table = sql_gen.as_Table(table)
964
    if cols == None: cols = [pkey(db, table, recover)]
965
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
966
    
967
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
968
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
969
        log_ignore_excs=(DuplicateTableException,))
970

    
971
already_indexed = object() # tells add_indexes() the pkey has already been added
972

    
973
def add_indexes(db, table, has_pkey=True):
974
    '''Adds an index on all columns in a table.
975
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
976
        index should be added on the first column.
977
        * If already_indexed, the pkey is assumed to have already been added
978
    '''
979
    cols = table_cols(db, table)
980
    if has_pkey:
981
        if has_pkey is not already_indexed: add_pkey(db, table)
982
        cols = cols[1:]
983
    for col in cols: add_index(db, col, table)
984

    
985
def add_row_num(db, table):
986
    '''Adds a row number column to a table. Its name is in row_num_col. It will
987
    be the primary key.'''
988
    table = sql_gen.as_Table(table).to_str(db)
989
    run_query(db, 'ALTER TABLE '+table+' ADD COLUMN '+row_num_col
990
        +' serial NOT NULL PRIMARY KEY', log_level=3)
991

    
992
def create_table(db, table, cols, has_pkey=True, col_indexes=True):
993
    '''Creates a table.
994
    @param cols [sql_gen.TypedCol,...] The column names and types
995
    @param has_pkey If set, the first column becomes the primary key.
996
    @param col_indexes bool|[ref]
997
        * If True, indexes will be added on all non-pkey columns.
998
        * If a list reference, [0] will be set to a function to do this.
999
          This can be used to delay index creation until the table is populated.
1000
    '''
1001
    table = sql_gen.as_Table(table)
1002
    
1003
    if has_pkey:
1004
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1005
        pkey.type += ' NOT NULL PRIMARY KEY'
1006
    
1007
    str_ = 'CREATE TABLE '+table.to_str(db)+' (\n'
1008
    str_ += '\n, '.join(v.to_str(db) for v in cols)
1009
    str_ += '\n);\n'
1010
    run_query(db, str_, cacheable=True, log_level=2)
1011
    
1012
    # Add indexes
1013
    if has_pkey: has_pkey = already_indexed
1014
    def add_indexes_(): add_indexes(db, table, has_pkey)
1015
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1016
    elif col_indexes: add_indexes_() # add now
1017

    
1018
def vacuum(db, table):
1019
    table = sql_gen.as_Table(table)
1020
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1021
        log_level=3))
1022

    
1023
def truncate(db, table, schema='public'):
1024
    table = sql_gen.as_Table(table, schema)
1025
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE')
1026

    
1027
def tables(db, schema_like='public', table_like='%', exact=False):
1028
    if exact: compare = '='
1029
    else: compare = 'LIKE'
1030
    
1031
    module = util.root_module(db.db)
1032
    if module == 'psycopg2':
1033
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1034
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1035
        return values(select(db, 'pg_tables', ['tablename'], conds,
1036
            order_by='tablename', log_level=4))
1037
    elif module == 'MySQLdb':
1038
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1039
            , cacheable=True, log_level=4))
1040
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1041

    
1042
def table_exists(db, table):
1043
    table = sql_gen.as_Table(table)
1044
    return list(tables(db, table.schema, table.name, exact=True)) != []
1045

    
1046
def errors_table(db, table, if_exists=True):
1047
    '''
1048
    @param if_exists If set, returns None if the errors table doesn't exist
1049
    @return None|sql_gen.Table
1050
    '''
1051
    table = sql_gen.as_Table(table)
1052
    if table.srcs != (): table = table.srcs[0]
1053
    
1054
    errors_table = sql_gen.suffixed_table(table, '.errors')
1055
    if if_exists and not table_exists(db, errors_table): return None
1056
    return errors_table
1057

    
1058
##### Database management
1059

    
1060
def empty_db(db, schema='public', **kw_args):
1061
    '''For kw_args, see tables()'''
1062
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1063

    
1064
##### Heuristic queries
1065

    
1066
def put(db, table, row, pkey_=None, row_ct_ref=None):
1067
    '''Recovers from errors.
1068
    Only works under PostgreSQL (uses INSERT RETURNING).
1069
    '''
1070
    row = sql_gen.ColDict(db, table, row)
1071
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
1072
    
1073
    try:
1074
        cur = insert(db, table, row, pkey_, recover=True)
1075
        if row_ct_ref != None and cur.rowcount >= 0:
1076
            row_ct_ref[0] += cur.rowcount
1077
        return value(cur)
1078
    except DuplicateKeyException, e:
1079
        row = sql_gen.ColDict(db, table,
1080
            util.dict_subset_right_join(row, e.cols))
1081
        return value(select(db, table, [pkey_], row, recover=True))
1082

    
1083
def get(db, table, row, pkey, row_ct_ref=None, create=False):
1084
    '''Recovers from errors'''
1085
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
1086
    except StopIteration:
1087
        if not create: raise
1088
        return put(db, table, row, pkey, row_ct_ref) # insert new row
1089

    
1090
def is_func_result(col):
1091
    return col.table.name.find('(') >= 0 and col.name == 'result'
1092

    
1093
def into_table_name(out_table, in_tables0, mapping, is_func):
1094
    def in_col_str(in_col):
1095
        in_col = sql_gen.remove_col_rename(in_col)
1096
        if isinstance(in_col, sql_gen.Col):
1097
            table = in_col.table
1098
            if table == in_tables0:
1099
                in_col = sql_gen.to_name_only_col(in_col)
1100
            elif is_func_result(in_col): in_col = table # omit col name
1101
        return str(in_col)
1102
    
1103
    str_ = str(out_table)
1104
    if is_func:
1105
        str_ += '('
1106
        
1107
        try: value_in_col = mapping['value']
1108
        except KeyError:
1109
            str_ += ', '.join((str(k)+'='+in_col_str(v)
1110
                for k, v in mapping.iteritems()))
1111
        else: str_ += in_col_str(value_in_col)
1112
        
1113
        str_ += ')'
1114
    else: str_ += '_pkeys'
1115
    return str_
1116

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

    
1354
##### Data cleanup
1355

    
1356
def cleanup_table(db, table, cols):
1357
    table = sql_gen.as_Table(table)
1358
    cols = map(sql_gen.as_Col, cols)
1359
    
1360
    expr = ('nullif(nullif(trim(both from %s), '+db.esc_value('')+'), '
1361
        +db.esc_value(r'\N')+')')
1362
    changes = [(v, sql_gen.CustomCode(expr % v.to_str(db)))
1363
        for v in cols]
1364
    
1365
    update(db, table, changes)
(24-24/36)