Project

General

Profile

1
# Database access
2

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

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

    
18
##### Exceptions
19

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

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

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

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

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

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

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

    
63
class NameException(DbException): pass
64

    
65
class DuplicateKeyException(ConstraintException): pass
66

    
67
class NullValueException(ConstraintException): pass
68

    
69
class FunctionValueException(ExceptionWithNameValue): pass
70

    
71
class DuplicateTableException(ExceptionWithName): pass
72

    
73
class DuplicateFunctionException(ExceptionWithName): pass
74

    
75
class EmptyRowException(DbException): pass
76

    
77
##### Warnings
78

    
79
class DbWarning(UserWarning): pass
80

    
81
##### Result retrieval
82

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

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

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

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

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

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

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

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

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

    
108
##### Escaping
109

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

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

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

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

    
128
##### Database connections
129

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

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

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

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

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

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

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

    
376
connect = DbConn
377

    
378
##### Querying
379

    
380
def mogrify(db, query, params):
381
    module = util.root_module(db.db)
382
    if module == 'psycopg2': return db.db.cursor().mogrify(query, params)
383
    else: raise NotImplementedError("Can't mogrify query for "+module+
384
        ' database')
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
    cols = map(sql_gen.to_name_only_col, cols)
745
    
746
    columns_cols = ['column']
747
    columns = sql_gen.NamedValues('columns', columns_cols,
748
        [[c.name] for c in cols])
749
    values_cols = ['value', 'error_code', 'error']
750
    values = sql_gen.NamedValues('values', values_cols,
751
        [value, error_code, error])
752
    
753
    select_cols = columns_cols+values_cols
754
    name_only_cols = map(sql_gen.to_name_only_col, select_cols)
755
    errors_table = sql_gen.NamedTable('errors', errors_table)
756
    joins = [columns, sql_gen.Join(values, type_='CROSS'),
757
        sql_gen.Join(errors_table, dict(zip(name_only_cols, select_cols)),
758
        sql_gen.filter_out)]
759
    
760
    return mk_insert_select(db, errors_table, name_only_cols,
761
        mk_select(db, joins, select_cols, order_by=None))
762

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

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

    
827
##### Database structure queries
828

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

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

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

    
841
not_null_col = 'not_null_col'
842

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

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

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

    
906
row_num_col = '_row_num'
907

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

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

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

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

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

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

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

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

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

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

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

    
1050
##### Database management
1051

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

    
1056
##### Heuristic queries
1057

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

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

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

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

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

    
1346
##### Data cleanup
1347

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