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
log_debug_none = lambda msg, level=2: None
149

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

    
381
connect = DbConn
382

    
383
##### Querying
384

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

    
391
##### Recoverable querying
392

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

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

    
456
##### Basic queries
457

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

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

    
499
order_by_pkey = object() # tells mk_select() to order by the pkey
500

    
501
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
502

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

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

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

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

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

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

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

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

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

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

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

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

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

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

    
832
##### Database structure queries
833

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

    
838
def table_cols(db, table, recover=None):
839
    return list(col_names(select(db, table, limit=0, order_by=None,
840
        recover=recover, log_level=4)))
841

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

    
846
not_null_col = 'not_null_col'
847

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

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

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

    
911
row_num_col = '_row_num'
912

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

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

    
968
already_indexed = object() # tells add_indexes() the pkey has already been added
969

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

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

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

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

    
1020
def truncate(db, table, schema='public'):
1021
    table = sql_gen.as_Table(table, schema)
1022
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE')
1023

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

    
1039
def table_exists(db, table):
1040
    table = sql_gen.as_Table(table)
1041
    return list(tables(db, table.schema, table.name, exact=True)) != []
1042

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

    
1055
##### Database management
1056

    
1057
def empty_db(db, schema='public', **kw_args):
1058
    '''For kw_args, see tables()'''
1059
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1060

    
1061
##### Heuristic queries
1062

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

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

    
1087
def is_func_result(col):
1088
    return col.table.name.find('(') >= 0 and col.name == 'result'
1089

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

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

    
1351
##### Data cleanup
1352

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