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: '+str(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
##### Input validation
109

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

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

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

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

    
128
##### Database connections
129

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

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

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

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

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

    
148
def _query_lookup(query, params): return (query, dicts.make_hashable(params))
149

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

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

    
375
connect = DbConn
376

    
377
##### Querying
378

    
379
def run_raw_query(db, *args, **kw_args):
380
    '''For params, see DbConn.run_query()'''
381
    return db.run_query(*args, **kw_args)
382

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

    
389
##### Recoverable querying
390

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

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

    
454
##### Basic queries
455

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

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

    
491
order_by_pkey = object() # tells mk_select() to order by the pkey
492

    
493
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
494

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

    
574
def select(db, *args, **kw_args):
575
    '''For params, see mk_select() and run_query()'''
576
    recover = kw_args.pop('recover', None)
577
    cacheable = kw_args.pop('cacheable', True)
578
    log_level = kw_args.pop('log_level', 2)
579
    
580
    query, params = mk_select(db, *args, **kw_args)
581
    return run_query(db, query, params, recover, cacheable, log_level=log_level)
582

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

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

    
657
default = object() # tells insert() to use the default value for a column
658

    
659
def insert(db, table, row, *args, **kw_args):
660
    '''For params, see insert_select()'''
661
    if lists.is_seq(row): cols = None
662
    else:
663
        cols = row.keys()
664
        row = row.values()
665
    row = list(row) # ensure that "!= []" works
666
    
667
    # Check for special values
668
    labels = []
669
    values = []
670
    for value in row:
671
        value = sql_gen.remove_col_rename(sql_gen.as_Value(value)).value
672
        if value is default: labels.append('DEFAULT')
673
        else:
674
            labels.append('%s')
675
            values.append(value)
676
    
677
    # Build query
678
    if values != []: query = 'VALUES ('+(', '.join(labels))+')'
679
    else: query = None
680
    
681
    return insert_select(db, table, cols, query, values, *args, **kw_args)
682

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

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

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

    
711
def truncate(db, table, schema='public'):
712
    return run_query(db, 'TRUNCATE '+qual_name(db, schema, table)+' CASCADE')
713

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

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

    
756
def cast(db, type_, col, errors_table=None):
757
    '''Casts an (unrenamed) column or value.
758
    If a column, converts any errors to warnings.
759
    @param col sql_gen.Col|sql_gen.Literal
760
    @param errors_table None|sql_gen.Table|str
761
        If set and col is a column with srcs, saves any errors in this table,
762
        using column's srcs attr as the source columns.
763
    '''
764
    if isinstance(col, sql_gen.Literal): # literal value, so just cast
765
        return sql_gen.CustomCode(col.to_str(db)+'::'+type_)
766
    
767
    assert isinstance(col, sql_gen.Col)
768
    assert not isinstance(col, sql_gen.NamedCol)
769
    
770
    save_errors = errors_table != None and col.srcs != ()
771
    if save_errors:
772
        errors_table = sql_gen.as_Table(errors_table)
773
        srcs = map(sql_gen.to_name_only_col, col.srcs)
774
        function_name = str(sql_gen.FunctionCall(type_, *srcs))
775
    else: function_name = type_
776
    function = sql_gen.TempFunction(function_name, db.autocommit)
777
    
778
    while True:
779
        # Create function definition
780
        query = '''\
781
CREATE FUNCTION '''+function.to_str(db)+'''(value text)
782
RETURNS '''+type_+'''
783
LANGUAGE plpgsql
784
'''
785
        if not save_errors: query += 'IMMUTABLE\n'
786
        query += '''\
787
STRICT
788
AS $$
789
BEGIN
790
    /* The explicit cast to the return type is needed to make the cast happen
791
    inside the try block. (Implicit casts to the return type happen at the end
792
    of the function, outside any block.) */
793
    RETURN value::'''+type_+''';
794
EXCEPTION
795
    WHEN data_exception THEN
796
'''
797
        if save_errors:
798
            cols = [sql_gen.Literal(c.name) for c in srcs]
799
            query += '''\
800
        -- Save error in errors table.
801
        BEGIN
802
            INSERT INTO '''+errors_table.to_str(db)+'''
803
            ("column", value, error)
804
            SELECT *
805
            FROM (VALUES '''+(', '.join(('('+c.to_str(db)+')' for c in cols))
806
                )+''') AS c
807
            CROSS JOIN (VALUES (value, SQLERRM)) AS v
808
            ;
809
        EXCEPTION
810
            WHEN unique_violation THEN NULL; -- ignore duplicate key
811
        END;
812
        
813
'''
814
        query += '''\
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
            if save_errors: function.name = next_version(function.name)
828
                # try again with next version of name
829
            else: break # plain cast function, so only need one version
830
    
831
    return sql_gen.FunctionCall(function, col)
832

    
833
##### Database structure queries
834

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

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

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

    
847
not_null_col = 'not_null_col'
848

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

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

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

    
912
row_num_col = '_row_num'
913

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

    
955
def add_pkey(db, table, cols=None, recover=None):
956
    '''Adds a primary key.
957
    @param cols [sql_gen.Col,...] The columns in the primary key.
958
        Defaults to the first column in the table.
959
    @pre The table must not already have a primary key.
960
    '''
961
    table = sql_gen.as_Table(table)
962
    if cols == None: cols = [pkey(db, table, recover)]
963
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
964
    
965
    index = sql_gen.as_Table(sql_gen.add_suffix(table.name, '_pkey'))
966
    try:
967
        run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD CONSTRAINT '
968
            +index.to_str(db)+' PRIMARY KEY ('+(', '.join(col_strs))+')',
969
            recover=True, cacheable=True, log_level=3,
970
            log_ignore_excs=(DuplicateTableException,))
971
    except DuplicateTableException, e:
972
        index.name = next_version(index.name)
973
        # try again with next version of name
974

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

    
982
def create_table(db, table, cols, has_pkey=True):
983
    '''Creates a table.
984
    @param cols [sql_gen.TypedCol,...] The column names and types
985
    @param has_pkey If set, the first column becomes the primary key.
986
    '''
987
    table = sql_gen.as_Table(table)
988
    
989
    if has_pkey:
990
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
991
        pkey.type += ' NOT NULL PRIMARY KEY'
992
    
993
    str_ = 'CREATE TABLE '+table.to_str(db)+' (\n'
994
    str_ += '\n, '.join(v.to_str(db) for v in cols)
995
    str_ += '\n);\n'
996
    run_query(db, str_, cacheable=True, log_level=2)
997

    
998
def vacuum(db, table):
999
    table = sql_gen.as_Table(table)
1000
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1001
        log_level=3))
1002

    
1003
def tables(db, schema_like='public', table_like='%'):
1004
    module = util.root_module(db.db)
1005
    params = {'schema_like': schema_like, 'table_like': table_like}
1006
    if module == 'psycopg2':
1007
        return values(run_query(db, '''\
1008
SELECT tablename
1009
FROM pg_tables
1010
WHERE
1011
    schemaname LIKE %(schema_like)s
1012
    AND tablename LIKE %(table_like)s
1013
ORDER BY tablename
1014
''',
1015
            params, cacheable=True))
1016
    elif module == 'MySQLdb':
1017
        return values(run_query(db, 'SHOW TABLES LIKE %(table_like)s', params,
1018
            cacheable=True))
1019
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1020

    
1021
##### Database management
1022

    
1023
def empty_db(db, schema='public', **kw_args):
1024
    '''For kw_args, see tables()'''
1025
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1026

    
1027
##### Heuristic queries
1028

    
1029
def put(db, table, row, pkey_=None, row_ct_ref=None):
1030
    '''Recovers from errors.
1031
    Only works under PostgreSQL (uses INSERT RETURNING).
1032
    '''
1033
    row = sql_gen.ColDict(db, table, row)
1034
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
1035
    
1036
    try:
1037
        cur = insert(db, table, row, pkey_, recover=True)
1038
        if row_ct_ref != None and cur.rowcount >= 0:
1039
            row_ct_ref[0] += cur.rowcount
1040
        return value(cur)
1041
    except DuplicateKeyException, e:
1042
        row = sql_gen.ColDict(db, table,
1043
            util.dict_subset_right_join(row, e.cols))
1044
        return value(select(db, table, [pkey_], row, recover=True))
1045

    
1046
def get(db, table, row, pkey, row_ct_ref=None, create=False):
1047
    '''Recovers from errors'''
1048
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
1049
    except StopIteration:
1050
        if not create: raise
1051
        return put(db, table, row, pkey, row_ct_ref) # insert new row
1052

    
1053
def is_func_result(col):
1054
    return col.table.name.find('(') >= 0 and col.name == 'result'
1055

    
1056
def into_table_name(out_table, in_tables0, mapping, is_func):
1057
    def in_col_str(in_col):
1058
        in_col = sql_gen.remove_col_rename(in_col)
1059
        if isinstance(in_col, sql_gen.Col):
1060
            table = in_col.table
1061
            if table == in_tables0:
1062
                in_col = sql_gen.to_name_only_col(in_col)
1063
            elif is_func_result(in_col): in_col = table # omit col name
1064
        return str(in_col)
1065
    
1066
    str_ = str(out_table)
1067
    if is_func:
1068
        str_ += '('
1069
        
1070
        try: value_in_col = mapping['value']
1071
        except KeyError:
1072
            str_ += ', '.join((str(k)+'='+in_col_str(v)
1073
                for k, v in mapping.iteritems()))
1074
        else: str_ += in_col_str(value_in_col)
1075
        
1076
        str_ += ')'
1077
    else: str_ += '_pkeys'
1078
    return str_
1079

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

    
1306
##### Data cleanup
1307

    
1308
def cleanup_table(db, table, cols):
1309
    table = sql_gen.as_Table(table)
1310
    cols = map(sql_gen.as_Col, cols)
1311
    
1312
    expr = ('nullif(nullif(trim(both from %s), '+db.esc_value('')+'), '
1313
        +db.esc_value(r'\N')+')')
1314
    changes = [(v, sql_gen.CustomCode(expr % v.to_str(db)))
1315
        for v in cols]
1316
    
1317
    update(db, table, changes)
(24-24/36)