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):
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)
27

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

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

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

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

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

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

    
63
class NameException(DbException): pass
64

    
65
class DuplicateKeyException(ConstraintException): pass
66

    
67
class NullValueException(ConstraintException): pass
68

    
69
class FunctionValueException(ExceptionWithNameValue): pass
70

    
71
class DuplicateTableException(ExceptionWithName): pass
72

    
73
class DuplicateFunctionException(ExceptionWithName): pass
74

    
75
class EmptyRowException(DbException): pass
76

    
77
##### Warnings
78

    
79
class DbWarning(UserWarning): pass
80

    
81
##### Result retrieval
82

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

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

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

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

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

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

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

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

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

    
108
##### Escaping
109

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

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

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

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

    
128
##### Database connections
129

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

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

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

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

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

    
148
log_debug_none = lambda msg, level=2: None
149

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

    
384
connect = DbConn
385

    
386
##### Recoverable querying
387

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

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

    
451
##### Basic queries
452

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

    
829
##### Database structure queries
830

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

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

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

    
843
not_null_col = 'not_null_col'
844

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

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

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

    
908
row_num_col = '_row_num'
909

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

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

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

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

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

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

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

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

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

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

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

    
1052
##### Database management
1053

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

    
1058
##### Heuristic queries
1059

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

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

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

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

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

    
1353
##### Data cleanup
1354

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