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):
214
            self._is_insert = query.startswith('INSERT')
215
            self.query_lookup = query
216
            try:
217
                try:
218
                    cur = self.inner.execute(query)
219
                    self.outer.do_autocommit()
220
                finally: self.query = get_cur_query(self.inner, query)
221
            except Exception, e:
222
                _add_cursor_info(e, self, query)
223
                self.result = e # cache the exception as the result
224
                self._cache_result()
225
                raise
226
            if self.rowcount == 0 and query.startswith('SELECT'): # empty SELECT
227
                consume_rows(self) # fetch all rows so result will be cached
228
            return cur
229
        
230
        def fetchone(self):
231
            row = self.inner.fetchone()
232
            if row != None: self.result.append(row)
233
            # otherwise, fetched all rows
234
            else: self._cache_result()
235
            return row
236
        
237
        def _cache_result(self):
238
            # For inserts, only cache exceptions since inserts are not
239
            # idempotent, but an invalid insert will always be invalid
240
            if self.query_results != None and (not self._is_insert
241
                or isinstance(self.result, Exception)):
242
                
243
                assert self.query_lookup != None
244
                self.query_results[self.query_lookup] = self.CacheCursor(
245
                    util.dict_subset(dicts.AttrsDictView(self),
246
                    ['query', 'result', 'rowcount', 'description']))
247
        
248
        class CacheCursor:
249
            def __init__(self, cached_result): self.__dict__ = cached_result
250
            
251
            def execute(self, *args, **kw_args):
252
                if isinstance(self.result, Exception): raise self.result
253
                # otherwise, result is a rows list
254
                self.iter = iter(self.result)
255
            
256
            def fetchone(self):
257
                try: return self.iter.next()
258
                except StopIteration: return None
259
    
260
    def esc_value(self, value):
261
        try: str_ = self.mogrify('%s', [value])
262
        except NotImplementedError, e:
263
            module = util.root_module(self.db)
264
            if module == 'MySQLdb':
265
                import _mysql
266
                str_ = _mysql.escape_string(value)
267
            else: raise e
268
        return strings.to_unicode(str_)
269
    
270
    def esc_name(self, name): return esc_name(self, name) # calls global func
271
    
272
    def can_mogrify(self):
273
        module = util.root_module(self.db)
274
        return module == 'psycopg2'
275
    
276
    def mogrify(self, query, params=None):
277
        if self.can_mogrify(): return self.db.cursor().mogrify(query, params)
278
        else: raise NotImplementedError("Can't mogrify query")
279
    
280
    def print_notices(self):
281
        if hasattr(self.db, 'notices'):
282
            for msg in self.db.notices:
283
                if msg not in self._notices_seen:
284
                    self._notices_seen.add(msg)
285
                    self.log_debug(msg, level=2)
286
    
287
    def run_query(self, query, cacheable=False, log_level=2,
288
        debug_msg_ref=None):
289
        '''
290
        @param log_ignore_excs The log_level will be increased by 2 if the query
291
            throws one of these exceptions.
292
        @param debug_msg_ref If specified, the log message will be returned in
293
            this instead of being output. This allows you to filter log messages
294
            depending on the result of the query.
295
        '''
296
        assert query != None
297
        
298
        if not self.caching: cacheable = False
299
        used_cache = False
300
        
301
        def log_msg(query):
302
            if used_cache: cache_status = 'cache hit'
303
            elif cacheable: cache_status = 'cache miss'
304
            else: cache_status = 'non-cacheable'
305
            return 'DB query: '+cache_status+':\n'+strings.as_code(query, 'SQL')
306
        
307
        try:
308
            # Get cursor
309
            if cacheable:
310
                try:
311
                    cur = self.query_results[query]
312
                    used_cache = True
313
                except KeyError: cur = self.DbCursor(self)
314
            else: cur = self.db.cursor()
315
            
316
            # Log query
317
            if self.debug and debug_msg_ref == None: # log before running
318
                self.log_debug(log_msg(query), log_level)
319
            
320
            # Run query
321
            cur.execute(query)
322
        finally:
323
            self.print_notices()
324
            if self.debug and debug_msg_ref != None: # return after running
325
                debug_msg_ref[0] = log_msg(str(get_cur_query(cur, query)))
326
        
327
        return cur
328
    
329
    def is_cached(self, query): return query in self.query_results
330
    
331
    def with_autocommit(self, func, autocommit=True):
332
        import psycopg2.extensions
333
        if autocommit:
334
            isolation_level = psycopg2.extensions.ISOLATION_LEVEL_AUTOCOMMIT
335
        else: isolation_level = psycopg2.extensions.ISOLATION_LEVEL_SERIALIZABLE
336
        
337
        prev_isolation_level = self.db.isolation_level
338
        self.db.set_isolation_level(isolation_level)
339
        try: return func()
340
        finally: self.db.set_isolation_level(prev_isolation_level)
341
    
342
    def with_savepoint(self, func):
343
        savepoint = 'level_'+str(self._savepoint)
344
        self.run_query('SAVEPOINT '+savepoint, log_level=4)
345
        self._savepoint += 1
346
        try:
347
            try: return_val = func()
348
            finally:
349
                self._savepoint -= 1
350
                assert self._savepoint >= 0
351
        except:
352
            self.run_query('ROLLBACK TO SAVEPOINT '+savepoint, log_level=4)
353
            raise
354
        else:
355
            self.run_query('RELEASE SAVEPOINT '+savepoint, log_level=4)
356
            self.do_autocommit()
357
            return return_val
358
    
359
    def do_autocommit(self):
360
        '''Autocommits if outside savepoint'''
361
        assert self._savepoint >= 0
362
        if self.autocommit and self._savepoint == 0:
363
            self.log_debug('Autocommitting')
364
            self.db.commit()
365
    
366
    def col_default(self, col):
367
        table = sql_gen.Table('columns', 'information_schema')
368
        
369
        conds = [('table_name', col.table.name), ('column_name', col.name)]
370
        schema = col.table.schema
371
        if schema != None: conds.append(('table_schema', schema))
372
        
373
        return sql_gen.as_Code(value(select(self, table, ['column_default'],
374
            conds, order_by='table_schema', limit=1, log_level=3)))
375
            # TODO: order_by search_path schema order
376

    
377
connect = DbConn
378

    
379
##### Querying
380

    
381
def mogrify(db, query, params):
382
    module = util.root_module(db.db)
383
    if module == 'psycopg2': return db.db.cursor().mogrify(query, params)
384
    else: raise NotImplementedError("Can't mogrify query for "+module+
385
        ' database')
386

    
387
##### Recoverable querying
388

    
389
def with_savepoint(db, func): return db.with_savepoint(func)
390

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

    
452
##### Basic queries
453

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

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

    
495
order_by_pkey = object() # tells mk_select() to order by the pkey
496

    
497
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
498

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

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

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

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

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

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

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

    
690
def update(db, *args, **kw_args):
691
    '''For params, see mk_update() and run_query()'''
692
    recover = kw_args.pop('recover', None)
693
    
694
    return run_query(db, mk_update(db, *args, **kw_args), recover)
695

    
696
def last_insert_id(db):
697
    module = util.root_module(db.db)
698
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
699
    elif module == 'MySQLdb': return db.insert_id()
700
    else: return None
701

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

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

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

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

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

    
828
##### Database structure queries
829

    
830
def table_row_count(db, table, recover=None):
831
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
832
        order_by=None, start=0), recover=recover, log_level=3))
833

    
834
def table_cols(db, table, recover=None):
835
    return list(col_names(select(db, table, limit=0, order_by=None,
836
        recover=recover, log_level=4)))
837

    
838
def pkey(db, table, recover=None):
839
    '''Assumed to be first column in table'''
840
    return table_cols(db, table, recover)[0]
841

    
842
not_null_col = 'not_null_col'
843

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

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

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

    
907
row_num_col = '_row_num'
908

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

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

    
964
already_indexed = object() # tells add_indexes() the pkey has already been added
965

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

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

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

    
1011
def vacuum(db, table):
1012
    table = sql_gen.as_Table(table)
1013
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1014
        log_level=3))
1015

    
1016
def truncate(db, table, schema='public'):
1017
    table = sql_gen.as_Table(table, schema)
1018
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE')
1019

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

    
1035
def table_exists(db, table):
1036
    table = sql_gen.as_Table(table)
1037
    return list(tables(db, table.schema, table.name, exact=True)) != []
1038

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

    
1051
##### Database management
1052

    
1053
def empty_db(db, schema='public', **kw_args):
1054
    '''For kw_args, see tables()'''
1055
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1056

    
1057
##### Heuristic queries
1058

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

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

    
1083
def is_func_result(col):
1084
    return col.table.name.find('(') >= 0 and col.name == 'result'
1085

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

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

    
1347
##### Data cleanup
1348

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