Project

General

Profile

1
# Database access
2

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

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

    
18
##### Exceptions
19

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

    
28
def _add_cursor_info(e, *args, **kw_args):
29
    '''For params, see get_cur_query()'''
30
    exc.add_msg(e, 'query: '+strings.ustr(get_cur_query(*args, **kw_args)))
31

    
32
class DbException(exc.ExceptionWithCause):
33
    def __init__(self, msg, cause=None, cur=None):
34
        exc.ExceptionWithCause.__init__(self, msg, cause, cause_newline=True)
35
        if cur != None: _add_cursor_info(self, cur)
36

    
37
class ExceptionWithName(DbException):
38
    def __init__(self, name, cause=None):
39
        DbException.__init__(self, 'for name: '+strings.as_tt(str(name)), cause)
40
        self.name = name
41

    
42
class ExceptionWithNameValue(DbException):
43
    def __init__(self, name, value, cause=None):
44
        DbException.__init__(self, 'for name: '+strings.as_tt(str(name))
45
            +'; value: '+strings.as_tt(repr(value)), cause)
46
        self.name = name
47
        self.value = value
48

    
49
class ConstraintException(DbException):
50
    def __init__(self, name, cols, cause=None):
51
        DbException.__init__(self, 'Violated '+strings.as_tt(name)
52
            +' constraint on columns: '+strings.as_tt(', '.join(cols)), cause)
53
        self.name = name
54
        self.cols = cols
55

    
56
class MissingCastException(DbException):
57
    def __init__(self, type_, col, cause=None):
58
        DbException.__init__(self, 'Missing cast to type '+strings.as_tt(type_)
59
            +' on column: '+strings.as_tt(col), cause)
60
        self.type = type_
61
        self.col = col
62

    
63
class NameException(DbException): pass
64

    
65
class DuplicateKeyException(ConstraintException): pass
66

    
67
class NullValueException(ConstraintException): pass
68

    
69
class FunctionValueException(ExceptionWithNameValue): pass
70

    
71
class DuplicateTableException(ExceptionWithName): pass
72

    
73
class DuplicateFunctionException(ExceptionWithName): pass
74

    
75
class EmptyRowException(DbException): pass
76

    
77
##### Warnings
78

    
79
class DbWarning(UserWarning): pass
80

    
81
##### Result retrieval
82

    
83
def col_names(cur): return (col[0] for col in cur.description)
84

    
85
def rows(cur): return iter(lambda: cur.fetchone(), None)
86

    
87
def consume_rows(cur):
88
    '''Used to fetch all rows so result will be cached'''
89
    iters.consume_iter(rows(cur))
90

    
91
def next_row(cur): return rows(cur).next()
92

    
93
def row(cur):
94
    row_ = next_row(cur)
95
    consume_rows(cur)
96
    return row_
97

    
98
def next_value(cur): return next_row(cur)[0]
99

    
100
def value(cur): return row(cur)[0]
101

    
102
def values(cur): return iters.func_iter(lambda: next_value(cur))
103

    
104
def value_or_none(cur):
105
    try: return value(cur)
106
    except StopIteration: return None
107

    
108
##### Escaping
109

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

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

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

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

    
128
##### Database connections
129

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

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

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

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

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

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

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

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

    
381
connect = DbConn
382

    
383
##### Querying
384

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

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

    
395
##### Recoverable querying
396

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

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

    
460
##### Basic queries
461

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

    
836
##### Database structure queries
837

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

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

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

    
850
not_null_col = 'not_null_col'
851

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

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

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

    
915
row_num_col = '_row_num'
916

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

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

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

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

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

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

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

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

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

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

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

    
1059
##### Database management
1060

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

    
1065
##### Heuristic queries
1066

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

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

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

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

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

    
1355
##### Data cleanup
1356

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