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 ExceptionWithNameType(DbException):
50
    def __init__(self, type_, name, cause=None):
51
        DbException.__init__(self, 'for type: '+strings.as_tt(str(type_))
52
            +'; name: '+strings.as_tt(name), cause)
53
        self.type = type_
54
        self.name = name
55

    
56
class ConstraintException(DbException):
57
    def __init__(self, name, cols, cause=None):
58
        DbException.__init__(self, 'Violated '+strings.as_tt(name)
59
            +' constraint on columns: '+strings.as_tt(', '.join(cols)), cause)
60
        self.name = name
61
        self.cols = cols
62

    
63
class MissingCastException(DbException):
64
    def __init__(self, type_, col, cause=None):
65
        DbException.__init__(self, 'Missing cast to type '+strings.as_tt(type_)
66
            +' on column: '+strings.as_tt(col), cause)
67
        self.type = type_
68
        self.col = col
69

    
70
class NameException(DbException): pass
71

    
72
class DuplicateKeyException(ConstraintException): pass
73

    
74
class NullValueException(ConstraintException): pass
75

    
76
class FunctionValueException(ExceptionWithNameValue): pass
77

    
78
class DuplicateException(ExceptionWithNameType): pass
79

    
80
class EmptyRowException(DbException): pass
81

    
82
##### Warnings
83

    
84
class DbWarning(UserWarning): pass
85

    
86
##### Result retrieval
87

    
88
def col_names(cur): return (col[0] for col in cur.description)
89

    
90
def rows(cur): return iter(lambda: cur.fetchone(), None)
91

    
92
def consume_rows(cur):
93
    '''Used to fetch all rows so result will be cached'''
94
    iters.consume_iter(rows(cur))
95

    
96
def next_row(cur): return rows(cur).next()
97

    
98
def row(cur):
99
    row_ = next_row(cur)
100
    consume_rows(cur)
101
    return row_
102

    
103
def next_value(cur): return next_row(cur)[0]
104

    
105
def value(cur): return row(cur)[0]
106

    
107
def values(cur): return iters.func_iter(lambda: next_value(cur))
108

    
109
def value_or_none(cur):
110
    try: return value(cur)
111
    except StopIteration: return None
112

    
113
##### Escaping
114

    
115
def esc_name_by_module(module, name):
116
    if module == 'psycopg2' or module == None: quote = '"'
117
    elif module == 'MySQLdb': quote = '`'
118
    else: raise NotImplementedError("Can't escape name for "+module+' database')
119
    return sql_gen.esc_name(name, quote)
120

    
121
def esc_name_by_engine(engine, name, **kw_args):
122
    return esc_name_by_module(db_engines[engine][0], name, **kw_args)
123

    
124
def esc_name(db, name, **kw_args):
125
    return esc_name_by_module(util.root_module(db.db), name, **kw_args)
126

    
127
def qual_name(db, schema, table):
128
    def esc_name_(name): return esc_name(db, name)
129
    table = esc_name_(table)
130
    if schema != None: return esc_name_(schema)+'.'+table
131
    else: return table
132

    
133
##### Database connections
134

    
135
db_config_names = ['engine', 'host', 'user', 'password', 'database', 'schemas']
136

    
137
db_engines = {
138
    'MySQL': ('MySQLdb', {'password': 'passwd', 'database': 'db'}),
139
    'PostgreSQL': ('psycopg2', {}),
140
}
141

    
142
DatabaseErrors_set = set([DbException])
143
DatabaseErrors = tuple(DatabaseErrors_set)
144

    
145
def _add_module(module):
146
    DatabaseErrors_set.add(module.DatabaseError)
147
    global DatabaseErrors
148
    DatabaseErrors = tuple(DatabaseErrors_set)
149

    
150
def db_config_str(db_config):
151
    return db_config['engine']+' database '+db_config['database']
152

    
153
log_debug_none = lambda msg, level=2: None
154

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

    
414
connect = DbConn
415

    
416
##### Recoverable querying
417

    
418
def with_savepoint(db, func): return db.with_savepoint(func)
419

    
420
def run_query(db, query, recover=None, cacheable=False, log_level=2,
421
    log_ignore_excs=None, **kw_args):
422
    '''For params, see DbConn.run_query()'''
423
    if recover == None: recover = False
424
    if log_ignore_excs == None: log_ignore_excs = ()
425
    log_ignore_excs = tuple(log_ignore_excs)
426
    
427
    debug_msg_ref = None # usually, db.run_query() logs query before running it
428
    # But if filtering with log_ignore_excs, wait until after exception parsing
429
    if log_ignore_excs != () or not db.can_mogrify(): debug_msg_ref = [None]
430
    
431
    try:
432
        try:
433
            def run(): return db.run_query(query, cacheable, log_level,
434
                debug_msg_ref, **kw_args)
435
            if recover and not db.is_cached(query):
436
                return with_savepoint(db, run)
437
            else: return run() # don't need savepoint if cached
438
        except Exception, e:
439
            if not recover: raise # need savepoint to run index_cols()
440
            msg = exc.str_(e)
441
            
442
            match = re.search(r'duplicate key value violates unique constraint '
443
                r'"((_?[^\W_]+)_.+?)"', msg)
444
            if match:
445
                constraint, table = match.groups()
446
                try: cols = index_cols(db, table, constraint)
447
                except NotImplementedError: raise e
448
                else: raise DuplicateKeyException(constraint, cols, e)
449
            
450
            match = re.search(r'null value in column "(.+?)" violates not-null'
451
                r' constraint', msg)
452
            if match: raise NullValueException('NOT NULL', [match.group(1)], e)
453
            
454
            match = re.search(r'\b(?:invalid input (?:syntax|value)\b.*?'
455
                r'|date/time field value out of range): "(.+?)"\n'
456
                r'(?:(?s).*?)\bfunction "(.+?)"', msg)
457
            if match:
458
                value, name = match.groups()
459
                raise FunctionValueException(name, strings.to_unicode(value), e)
460
            
461
            match = re.search(r'column "(.+?)" is of type (.+?) but expression '
462
                r'is of type', msg)
463
            if match:
464
                col, type_ = match.groups()
465
                raise MissingCastException(type_, col, e)
466
            
467
            match = re.search(r'\b(\S+) "(.+?)".*? already exists', msg)
468
            if match:
469
                type_, name = match.groups()
470
                raise DuplicateException(type_, name, e)
471
            
472
            raise # no specific exception raised
473
    except log_ignore_excs:
474
        log_level += 2
475
        raise
476
    finally:
477
        if debug_msg_ref != None and debug_msg_ref[0] != None:
478
            db.log_debug(debug_msg_ref[0], log_level)
479

    
480
##### Basic queries
481

    
482
def next_version(name):
483
    version = 1 # first existing name was version 0
484
    match = re.match(r'^(.*)#(\d+)$', name)
485
    if match:
486
        name, version = match.groups()
487
        version = int(version)+1
488
    return sql_gen.concat(name, '#'+str(version))
489

    
490
def lock_table(db, table, mode):
491
    table = sql_gen.as_Table(table)
492
    run_query(db, 'LOCK TABLE '+table.to_str(db)+' IN '+mode+' MODE')
493

    
494
def run_query_into(db, query, into=None, add_indexes_=False, **kw_args):
495
    '''Outputs a query to a temp table.
496
    For params, see run_query().
497
    '''
498
    if into == None: return run_query(db, query, **kw_args)
499
    
500
    assert isinstance(into, sql_gen.Table)
501
    
502
    into.is_temp = True
503
    # "temporary tables cannot specify a schema name", so remove schema
504
    into.schema = None
505
    
506
    kw_args['recover'] = True
507
    kw_args.setdefault('log_ignore_excs', (DuplicateException,))
508
    
509
    temp = not db.debug_temp # tables are permanent in debug_temp mode
510
    
511
    # Create table
512
    while True:
513
        create_query = 'CREATE'
514
        if temp: create_query += ' TEMP'
515
        create_query += ' TABLE '+into.to_str(db)+' AS\n'+query
516
        
517
        try:
518
            cur = run_query(db, create_query, **kw_args)
519
                # CREATE TABLE AS sets rowcount to # rows in query
520
            break
521
        except DuplicateException, e:
522
            into.name = next_version(into.name)
523
            # try again with next version of name
524
    
525
    if add_indexes_: add_indexes(db, into)
526
    
527
    return cur
528

    
529
order_by_pkey = object() # tells mk_select() to order by the pkey
530

    
531
distinct_on_all = object() # tells mk_select() to SELECT DISTINCT ON all columns
532

    
533
def mk_select(db, tables, fields=None, conds=None, distinct_on=[], limit=None,
534
    start=None, order_by=order_by_pkey, default_table=None):
535
    '''
536
    @param tables The single table to select from, or a list of tables to join
537
        together, with tables after the first being sql_gen.Join objects
538
    @param fields Use None to select all fields in the table
539
    @param conds WHERE conditions: [(compare_left_side, compare_right_side),...]
540
        * container can be any iterable type
541
        * compare_left_side: sql_gen.Code|str (for col name)
542
        * compare_right_side: sql_gen.ValueCond|literal value
543
    @param distinct_on The columns to SELECT DISTINCT ON, or distinct_on_all to
544
        use all columns
545
    @return query
546
    '''
547
    # Parse tables param
548
    tables = lists.mk_seq(tables)
549
    tables = list(tables) # don't modify input! (list() copies input)
550
    table0 = sql_gen.as_Table(tables.pop(0)) # first table is separate
551
    
552
    # Parse other params
553
    if conds == None: conds = []
554
    elif dicts.is_dict(conds): conds = conds.items()
555
    conds = list(conds) # don't modify input! (list() copies input)
556
    assert limit == None or type(limit) == int
557
    assert start == None or type(start) == int
558
    if order_by is order_by_pkey:
559
        if distinct_on != []: order_by = None
560
        else: order_by = pkey(db, table0, recover=True)
561
    
562
    query = 'SELECT'
563
    
564
    def parse_col(col): return sql_gen.as_Col(col, default_table).to_str(db)
565
    
566
    # DISTINCT ON columns
567
    if distinct_on != []:
568
        query += '\nDISTINCT'
569
        if distinct_on is not distinct_on_all:
570
            query += ' ON ('+(', '.join(map(parse_col, distinct_on)))+')'
571
    
572
    # Columns
573
    query += '\n'
574
    if fields == None: query += '*'
575
    else:
576
        assert fields != []
577
        query += '\n, '.join(map(parse_col, fields))
578
    
579
    # Main table
580
    query += '\nFROM '+table0.to_str(db)
581
    
582
    # Add joins
583
    left_table = table0
584
    for join_ in tables:
585
        table = join_.table
586
        
587
        # Parse special values
588
        if join_.type_ is sql_gen.filter_out: # filter no match
589
            conds.append((sql_gen.Col(table_not_null_col(db, table), table),
590
                sql_gen.CompareCond(None, '~=')))
591
        
592
        query += '\n'+join_.to_str(db, left_table)
593
        
594
        left_table = table
595
    
596
    missing = True
597
    if conds != []:
598
        if len(conds) == 1: whitespace = ' '
599
        else: whitespace = '\n'
600
        query += '\n'+sql_gen.combine_conds([sql_gen.ColValueCond(l, r)
601
            .to_str(db) for l, r in conds], 'WHERE')
602
        missing = False
603
    if order_by != None:
604
        query += '\nORDER BY '+sql_gen.as_Col(order_by, table0).to_str(db)
605
    if limit != None: query += '\nLIMIT '+str(limit); missing = False
606
    if start != None:
607
        if start != 0: query += '\nOFFSET '+str(start)
608
        missing = False
609
    if missing: warnings.warn(DbWarning(
610
        'SELECT statement missing a WHERE, LIMIT, or OFFSET clause: '+query))
611
    
612
    return query
613

    
614
def select(db, *args, **kw_args):
615
    '''For params, see mk_select() and run_query()'''
616
    recover = kw_args.pop('recover', None)
617
    cacheable = kw_args.pop('cacheable', True)
618
    log_level = kw_args.pop('log_level', 2)
619
    
620
    return run_query(db, mk_select(db, *args, **kw_args), recover, cacheable,
621
        log_level=log_level)
622

    
623
def mk_insert_select(db, table, cols=None, select_query=None, returning=None,
624
    embeddable=False, ignore=False):
625
    '''
626
    @param returning str|None An inserted column (such as pkey) to return
627
    @param embeddable Whether the query should be embeddable as a nested SELECT.
628
        Warning: If you set this and cacheable=True when the query is run, the
629
        query will be fully cached, not just if it raises an exception.
630
    @param ignore Whether to ignore duplicate keys.
631
    '''
632
    table = sql_gen.remove_table_rename(sql_gen.as_Table(table))
633
    if cols == []: cols = None # no cols (all defaults) = unknown col names
634
    if cols != None:
635
        cols = [sql_gen.to_name_only_col(v, table).to_str(db) for v in cols]
636
    if select_query == None: select_query = 'DEFAULT VALUES'
637
    if returning != None: returning = sql_gen.as_Col(returning, table)
638
    
639
    first_line = 'INSERT INTO '+table.to_str(db)
640
    
641
    def mk_insert(select_query):
642
        query = first_line
643
        if cols != None: query += '\n('+', '.join(cols)+')'
644
        query += '\n'+select_query
645
        
646
        if returning != None:
647
            returning_name_col = sql_gen.to_name_only_col(returning)
648
            query += '\nRETURNING '+returning_name_col.to_str(db)
649
        
650
        return query
651
    
652
    lang = 'sql'
653
    if ignore:
654
        embeddable = True # must use function
655
        lang = 'plpgsql'
656
        
657
        query = '''\
658
BEGIN
659
END;
660
'''
661
    else: query = mk_insert(select_query)
662
    
663
    if embeddable:
664
        return_type = 'void'
665
        if returning != None:
666
            return_type = 'SETOF '+returning.to_str(db)+'%TYPE'
667
        
668
        # Create function
669
        function_name = sql_gen.clean_name(first_line)
670
        while True:
671
            try:
672
                function = db.TempFunction(function_name)
673
                
674
                function_query = '''\
675
CREATE FUNCTION '''+function.to_str(db)+'''()
676
RETURNS '''+return_type+'''
677
LANGUAGE '''+lang+'''
678
AS $$
679
'''+query+'''
680
$$;
681
'''
682
                run_query(db, function_query, recover=True, cacheable=True,
683
                    log_ignore_excs=(DuplicateException,))
684
                break # this version was successful
685
            except DuplicateException, e:
686
                function_name = next_version(function_name)
687
                # try again with next version of name
688
        
689
        # Return query that uses function
690
        cols = None
691
        if returning != None: cols = [returning]
692
        func_table = sql_gen.NamedTable('f', sql_gen.FunctionCall(function),
693
            cols) # AS clause requires function alias
694
        return mk_select(db, func_table, start=0, order_by=None)
695
    
696
    return query
697

    
698
def insert_select(db, *args, **kw_args):
699
    '''For params, see mk_insert_select() and run_query_into()
700
    @param into sql_gen.Table with suggested name of temp table to put RETURNING
701
        values in
702
    '''
703
    into = kw_args.pop('into', None)
704
    if into != None: kw_args['embeddable'] = True
705
    recover = kw_args.pop('recover', None)
706
    cacheable = kw_args.pop('cacheable', True)
707
    log_level = kw_args.pop('log_level', 2)
708
    
709
    return run_query_into(db, mk_insert_select(db, *args, **kw_args), into,
710
        recover=recover, cacheable=cacheable, log_level=log_level)
711

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

    
714
def insert(db, table, row, *args, **kw_args):
715
    '''For params, see insert_select()'''
716
    if lists.is_seq(row): cols = None
717
    else:
718
        cols = row.keys()
719
        row = row.values()
720
    row = list(row) # ensure that "== []" works
721
    
722
    if row == []: query = None
723
    else: query = sql_gen.Values(row).to_str(db)
724
    
725
    return insert_select(db, table, cols, query, *args, **kw_args)
726

    
727
def mk_update(db, table, changes=None, cond=None):
728
    '''
729
    @param changes [(col, new_value),...]
730
        * container can be any iterable type
731
        * col: sql_gen.Code|str (for col name)
732
        * new_value: sql_gen.Code|literal value
733
    @param cond sql_gen.Code WHERE condition. e.g. use sql_gen.*Cond objects.
734
    @return str query
735
    '''
736
    query = 'UPDATE '+sql_gen.as_Table(table).to_str(db)+'\nSET\n'
737
    query += ',\n'.join((sql_gen.to_name_only_col(col, table).to_str(db)+' = '
738
        +sql_gen.as_Value(new_value).to_str(db) for col, new_value in changes))
739
    if cond != None: query += '\nWHERE\n'+cond.to_str(db)
740
    
741
    return query
742

    
743
def update(db, *args, **kw_args):
744
    '''For params, see mk_update() and run_query()'''
745
    recover = kw_args.pop('recover', None)
746
    
747
    return run_query(db, mk_update(db, *args, **kw_args), recover)
748

    
749
def last_insert_id(db):
750
    module = util.root_module(db.db)
751
    if module == 'psycopg2': return value(run_query(db, 'SELECT lastval()'))
752
    elif module == 'MySQLdb': return db.insert_id()
753
    else: return None
754

    
755
def mk_flatten_mapping(db, into, cols, preserve=[], as_items=False):
756
    '''Creates a mapping from original column names (which may have collisions)
757
    to names that will be distinct among the columns' tables.
758
    This is meant to be used for several tables that are being joined together.
759
    @param cols The columns to combine. Duplicates will be removed.
760
    @param into The table for the new columns.
761
    @param preserve [sql_gen.Col...] Columns not to rename. Note that these
762
        columns will be included in the mapping even if they are not in cols.
763
        The tables of the provided Col objects will be changed to into, so make
764
        copies of them if you want to keep the original tables.
765
    @param as_items Whether to return a list of dict items instead of a dict
766
    @return dict(orig_col=new_col, ...)
767
        * orig_col: sql_gen.Col(orig_col_name, orig_table)
768
        * new_col: sql_gen.Col(orig_col_name, into)
769
        * All mappings use the into table so its name can easily be
770
          changed for all columns at once
771
    '''
772
    cols = lists.uniqify(cols)
773
    
774
    items = []
775
    for col in preserve:
776
        orig_col = copy.copy(col)
777
        col.table = into
778
        items.append((orig_col, col))
779
    preserve = set(preserve)
780
    for col in cols:
781
        if col not in preserve:
782
            items.append((col, sql_gen.Col(str(col), into, col.srcs)))
783
    
784
    if not as_items: items = dict(items)
785
    return items
786

    
787
def flatten(db, into, joins, cols, limit=None, start=None, **kw_args):
788
    '''For params, see mk_flatten_mapping()
789
    @return See return value of mk_flatten_mapping()
790
    '''
791
    items = mk_flatten_mapping(db, into, cols, as_items=True, **kw_args)
792
    cols = [sql_gen.NamedCol(new.name, old) for old, new in items]
793
    run_query_into(db, mk_select(db, joins, cols, limit=limit, start=start),
794
        into=into, add_indexes_=True)
795
    return dict(items)
796

    
797
def mk_track_data_error(db, errors_table, cols, value, error_code, error):
798
    assert cols != ()
799
    
800
    cols = map(sql_gen.to_name_only_col, cols)
801
    
802
    columns_cols = ['column']
803
    columns = sql_gen.NamedValues('columns', columns_cols,
804
        [[c.name] for c in cols])
805
    values_cols = ['value', 'error_code', 'error']
806
    values = sql_gen.NamedValues('values', values_cols,
807
        [value, error_code, error])
808
    
809
    select_cols = columns_cols+values_cols
810
    name_only_cols = map(sql_gen.to_name_only_col, select_cols)
811
    errors_table = sql_gen.NamedTable('errors', errors_table)
812
    joins = [columns, sql_gen.Join(values, type_='CROSS'),
813
        sql_gen.Join(errors_table, dict(zip(name_only_cols, select_cols)),
814
        sql_gen.filter_out)]
815
    
816
    return mk_insert_select(db, errors_table, name_only_cols,
817
        mk_select(db, joins, select_cols, order_by=None))
818

    
819
def track_data_error(db, errors_table, cols, *args, **kw_args):
820
    '''
821
    @param errors_table If None, does nothing.
822
    '''
823
    if errors_table == None or cols == (): return
824
    run_query(db, mk_track_data_error(db, errors_table, cols, *args, **kw_args),
825
        cacheable=True, log_level=4)
826

    
827
def cast(db, type_, col, errors_table=None):
828
    '''Casts an (unrenamed) column or value.
829
    If errors_table set and col has srcs, saves errors in errors_table (using
830
    col's srcs attr as the source columns) and converts errors to warnings.
831
    @param col str|sql_gen.Col|sql_gen.Literal
832
    @param errors_table None|sql_gen.Table|str
833
    '''
834
    col = sql_gen.as_Col(col)
835
    save_errors = (errors_table != None and isinstance(col, sql_gen.Col)
836
        and col.srcs != ())
837
    if not save_errors: return sql_gen.Cast(type_, col) # can't save errors
838
    
839
    assert not isinstance(col, sql_gen.NamedCol)
840
    
841
    errors_table = sql_gen.as_Table(errors_table)
842
    srcs = map(sql_gen.to_name_only_col, col.srcs)
843
    function_name = str(sql_gen.FunctionCall(type_, *srcs))
844
    function = db.TempFunction(function_name)
845
    
846
    while True:
847
        # Create function definition
848
        query = '''\
849
CREATE FUNCTION '''+function.to_str(db)+'''(value text)
850
RETURNS '''+type_+'''
851
LANGUAGE plpgsql
852
STRICT
853
AS $$
854
BEGIN
855
    /* The explicit cast to the return type is needed to make the cast happen
856
    inside the try block. (Implicit casts to the return type happen at the end
857
    of the function, outside any block.) */
858
    RETURN value::'''+type_+''';
859
EXCEPTION
860
    WHEN data_exception THEN
861
        -- Save error in errors table.
862
        -- Insert the value and error for *each* source column.
863
'''+mk_track_data_error(db, errors_table, srcs,
864
    *map(sql_gen.CustomCode, ['value', 'SQLSTATE', 'SQLERRM']))+''';
865
        
866
        RAISE WARNING '%', SQLERRM;
867
        RETURN NULL;
868
END;
869
$$;
870
'''
871
        
872
        # Create function
873
        try:
874
            run_query(db, query, recover=True, cacheable=True,
875
                log_ignore_excs=(DuplicateException,))
876
            break # successful
877
        except DuplicateException:
878
            function.name = next_version(function.name)
879
            # try again with next version of name
880
    
881
    return sql_gen.FunctionCall(function, col)
882

    
883
##### Database structure queries
884

    
885
def table_row_count(db, table, recover=None):
886
    return value(run_query(db, mk_select(db, table, [sql_gen.row_count],
887
        order_by=None, start=0), recover=recover, log_level=3))
888

    
889
def table_cols(db, table, recover=None):
890
    return list(col_names(select(db, table, limit=0, order_by=None,
891
        recover=recover, log_level=4)))
892

    
893
def pkey(db, table, recover=None):
894
    '''Assumed to be first column in table'''
895
    return table_cols(db, table, recover)[0]
896

    
897
not_null_col = 'not_null_col'
898

    
899
def table_not_null_col(db, table, recover=None):
900
    '''Name assumed to be the value of not_null_col. If not found, uses pkey.'''
901
    if not_null_col in table_cols(db, table, recover): return not_null_col
902
    else: return pkey(db, table, recover)
903

    
904
def index_cols(db, table, index):
905
    '''Can also use this for UNIQUE constraints, because a UNIQUE index is
906
    automatically created. When you don't know whether something is a UNIQUE
907
    constraint or a UNIQUE index, use this function.'''
908
    module = util.root_module(db.db)
909
    if module == 'psycopg2':
910
        return list(values(run_query(db, '''\
911
SELECT attname
912
FROM
913
(
914
        SELECT attnum, attname
915
        FROM pg_index
916
        JOIN pg_class index ON index.oid = indexrelid
917
        JOIN pg_class table_ ON table_.oid = indrelid
918
        JOIN pg_attribute ON attrelid = indrelid AND attnum = ANY (indkey)
919
        WHERE
920
            table_.relname = '''+db.esc_value(table)+'''
921
            AND index.relname = '''+db.esc_value(index)+'''
922
    UNION
923
        SELECT attnum, attname
924
        FROM
925
        (
926
            SELECT
927
                indrelid
928
                , (regexp_matches(indexprs, E':varattno (\\\\d+)', 'g'))[1]::int
929
                    AS indkey
930
            FROM pg_index
931
            JOIN pg_class index ON index.oid = indexrelid
932
            JOIN pg_class table_ ON table_.oid = indrelid
933
            WHERE
934
                table_.relname = '''+db.esc_value(table)+'''
935
                AND index.relname = '''+db.esc_value(index)+'''
936
        ) s
937
        JOIN pg_attribute ON attrelid = indrelid AND attnum = indkey
938
) s
939
ORDER BY attnum
940
'''
941
            , cacheable=True, log_level=4)))
942
    else: raise NotImplementedError("Can't list index columns for "+module+
943
        ' database')
944

    
945
def constraint_cols(db, table, constraint):
946
    module = util.root_module(db.db)
947
    if module == 'psycopg2':
948
        return list(values(run_query(db, '''\
949
SELECT attname
950
FROM pg_constraint
951
JOIN pg_class ON pg_class.oid = conrelid
952
JOIN pg_attribute ON attrelid = conrelid AND attnum = ANY (conkey)
953
WHERE
954
    relname = '''+db.esc_value(table)+'''
955
    AND conname = '''+db.esc_value(constraint)+'''
956
ORDER BY attnum
957
'''
958
            )))
959
    else: raise NotImplementedError("Can't list constraint columns for "+module+
960
        ' database')
961

    
962
row_num_col = '_row_num'
963

    
964
def add_index(db, exprs, table=None, unique=False, ensure_not_null_=True):
965
    '''Adds an index on column(s) or expression(s) if it doesn't already exist.
966
    Currently, only function calls are supported as expressions.
967
    @param ensure_not_null_ If set, translates NULL values to sentinel values.
968
        This allows indexes to be used for comparisons where NULLs are equal.
969
    '''
970
    exprs = lists.mk_seq(exprs)
971
    
972
    # Parse exprs
973
    old_exprs = exprs[:]
974
    exprs = []
975
    cols = []
976
    for i, expr in enumerate(old_exprs):
977
        expr = sql_gen.as_Col(expr, table)
978
        
979
        # Handle nullable columns
980
        if ensure_not_null_:
981
            try: expr = ensure_not_null(db, expr)
982
            except KeyError: pass # unknown type, so just create plain index
983
        
984
        # Extract col
985
        expr = copy.deepcopy(expr) # don't modify input!
986
        if isinstance(expr, sql_gen.FunctionCall):
987
            col = expr.args[0]
988
            expr = sql_gen.Expr(expr)
989
        else: col = expr
990
        assert isinstance(col, sql_gen.Col)
991
        
992
        # Extract table
993
        if table == None:
994
            assert sql_gen.is_table_col(col)
995
            table = col.table
996
        
997
        col.table = None
998
        
999
        exprs.append(expr)
1000
        cols.append(col)
1001
    
1002
    table = sql_gen.as_Table(table)
1003
    index = sql_gen.Table(str(sql_gen.Col(','.join(map(str, cols)), table)))
1004
    
1005
    # Add index
1006
    while True:
1007
        str_ = 'CREATE'
1008
        if unique: str_ += ' UNIQUE'
1009
        str_ += ' INDEX '+index.to_str(db)+' ON '+table.to_str(db)+' ('+(
1010
            ', '.join((v.to_str(db) for v in exprs)))+')'
1011
        
1012
        try:
1013
            run_query(db, str_, recover=True, cacheable=True, log_level=3,
1014
                log_ignore_excs=(DuplicateException,))
1015
            break
1016
        except DuplicateException:
1017
            index.name = next_version(index.name)
1018
            # try again with next version of name
1019

    
1020
def add_pkey(db, table, cols=None, recover=None):
1021
    '''Adds a primary key.
1022
    @param cols [sql_gen.Col,...] The columns in the primary key.
1023
        Defaults to the first column in the table.
1024
    @pre The table must not already have a primary key.
1025
    '''
1026
    table = sql_gen.as_Table(table)
1027
    if cols == None: cols = [pkey(db, table, recover)]
1028
    col_strs = [sql_gen.to_name_only_col(v).to_str(db) for v in cols]
1029
    
1030
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD PRIMARY KEY ('
1031
        +(', '.join(col_strs))+')', recover=True, cacheable=True, log_level=3,
1032
        log_ignore_excs=(DuplicateException,))
1033

    
1034
def add_not_null(db, col):
1035
    table = col.table
1036
    col = sql_gen.to_name_only_col(col)
1037
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ALTER COLUMN '
1038
        +col.to_str(db)+' SET NOT NULL', cacheable=True)
1039

    
1040
def add_index_col(db, col, suffix, expr, nullable=True):
1041
    if sql_gen.index_col(col) != None: return # already has index col
1042
    
1043
    new_col = sql_gen.suffixed_col(col, suffix)
1044
    
1045
    # Add column
1046
    while True:
1047
        new_typed_col = sql_gen.TypedCol(new_col.name, db.col_info(col).type)
1048
        try:
1049
            add_col(db, col.table, new_typed_col,
1050
                log_ignore_excs=(DuplicateException,))
1051
            break
1052
        except DuplicateException:
1053
            new_col.name = next_version(new_col.name)
1054
            # try again with next version of name
1055
    
1056
    update(db, col.table, [(new_col, expr)])
1057
    if not nullable: add_not_null(db, new_col)
1058
    add_index(db, new_col)
1059
    
1060
    col.table.index_cols[col.name] = new_col
1061

    
1062
def ensure_not_null(db, col):
1063
    '''For params, see sql_gen.ensure_not_null()'''
1064
    expr = sql_gen.ensure_not_null(db, col)
1065
    
1066
    # If nullable column in a temp table, add separate column instead
1067
    if sql_gen.is_temp_col(col) and isinstance(expr, sql_gen.EnsureNotNull):
1068
        add_index_col(db, col, '::NOT NULL', expr, nullable=False)
1069
        expr = sql_gen.index_col(col)
1070
    
1071
    return expr
1072

    
1073
already_indexed = object() # tells add_indexes() the pkey has already been added
1074

    
1075
def add_indexes(db, table, has_pkey=True):
1076
    '''Adds an index on all columns in a table.
1077
    @param has_pkey bool|already_indexed Whether a pkey instead of a regular
1078
        index should be added on the first column.
1079
        * If already_indexed, the pkey is assumed to have already been added
1080
    '''
1081
    cols = table_cols(db, table)
1082
    if has_pkey:
1083
        if has_pkey is not already_indexed: add_pkey(db, table)
1084
        cols = cols[1:]
1085
    for col in cols: add_index(db, col, table)
1086

    
1087
def add_col(db, table, col, **kw_args):
1088
    assert isinstance(col, sql_gen.TypedCol)
1089
    run_query(db, 'ALTER TABLE '+table.to_str(db)+' ADD COLUMN '
1090
        +col.to_str(db), recover=True, cacheable=True, **kw_args)
1091

    
1092
row_num_typed_col = sql_gen.TypedCol(row_num_col, 'serial', nullable=False,
1093
    constraints='PRIMARY KEY')
1094

    
1095
def add_row_num(db, table):
1096
    '''Adds a row number column to a table. Its name is in row_num_col. It will
1097
    be the primary key.'''
1098
    add_col(db, table, row_num_typed_col, log_level=3)
1099

    
1100
def cast_temp_col(db, type_, col, errors_table=None):
1101
    '''Like cast(), but creates a new column with the cast values if the input
1102
    is a column.
1103
    @return The new column or cast value
1104
    '''
1105
    def cast_(col): return cast(db, type_, col, errors_table)
1106
    
1107
    try: col = sql_gen.underlying_col(col)
1108
    except sql_gen.NoUnderlyingTableException: return sql_gen.wrap(cast_, col)
1109
    
1110
    table = col.table
1111
    new_col = sql_gen.Col(sql_gen.concat(col.name, '::'+type_), table, col.srcs)
1112
    expr = cast_(col)
1113
    add_col(db, table, sql_gen.TypedCol(new_col.name, type_))
1114
    update(db, table, [(new_col, expr)])
1115
    add_index(db, new_col)
1116
    
1117
    return new_col
1118

    
1119
def drop_table(db, table):
1120
    table = sql_gen.as_Table(table)
1121
    return run_query(db, 'DROP TABLE IF EXISTS '+table.to_str(db)+' CASCADE')
1122

    
1123
def create_table(db, table, cols, has_pkey=True, col_indexes=True):
1124
    '''Creates a table.
1125
    @param cols [sql_gen.TypedCol,...] The column names and types
1126
    @param has_pkey If set, the first column becomes the primary key.
1127
    @param col_indexes bool|[ref]
1128
        * If True, indexes will be added on all non-pkey columns.
1129
        * If a list reference, [0] will be set to a function to do this.
1130
          This can be used to delay index creation until the table is populated.
1131
    '''
1132
    table = sql_gen.as_Table(table)
1133
    
1134
    if has_pkey:
1135
        cols[0] = pkey = copy.copy(cols[0]) # don't modify input!
1136
        pkey.constraints = 'PRIMARY KEY'
1137
    
1138
    str_ = 'CREATE TABLE '+table.to_str(db)+' (\n'
1139
    str_ += '\n, '.join(v.to_str(db) for v in cols)
1140
    str_ += '\n);\n'
1141
    run_query(db, str_, cacheable=True, log_level=2)
1142
    
1143
    # Add indexes
1144
    if has_pkey: has_pkey = already_indexed
1145
    def add_indexes_(): add_indexes(db, table, has_pkey)
1146
    if isinstance(col_indexes, list): col_indexes[0] = add_indexes_ # defer
1147
    elif col_indexes: add_indexes_() # add now
1148

    
1149
def vacuum(db, table):
1150
    table = sql_gen.as_Table(table)
1151
    db.with_autocommit(lambda: run_query(db, 'VACUUM ANALYZE '+table.to_str(db),
1152
        log_level=3))
1153

    
1154
def truncate(db, table, schema='public', **kw_args):
1155
    '''For params, see run_query()'''
1156
    table = sql_gen.as_Table(table, schema)
1157
    return run_query(db, 'TRUNCATE '+table.to_str(db)+' CASCADE', **kw_args)
1158

    
1159
def empty_temp(db, tables):
1160
    if db.debug_temp: return # leave temp tables there for debugging
1161
    tables = lists.mk_seq(tables)
1162
    for table in tables: truncate(db, table, log_level=3)
1163

    
1164
def tables(db, schema_like='public', table_like='%', exact=False):
1165
    if exact: compare = '='
1166
    else: compare = 'LIKE'
1167
    
1168
    module = util.root_module(db.db)
1169
    if module == 'psycopg2':
1170
        conds = [('schemaname', sql_gen.CompareCond(schema_like, compare)),
1171
            ('tablename', sql_gen.CompareCond(table_like, compare))]
1172
        return values(select(db, 'pg_tables', ['tablename'], conds,
1173
            order_by='tablename', log_level=4))
1174
    elif module == 'MySQLdb':
1175
        return values(run_query(db, 'SHOW TABLES LIKE '+db.esc_value(table_like)
1176
            , cacheable=True, log_level=4))
1177
    else: raise NotImplementedError("Can't list tables for "+module+' database')
1178

    
1179
def table_exists(db, table):
1180
    table = sql_gen.as_Table(table)
1181
    return list(tables(db, table.schema, table.name, exact=True)) != []
1182

    
1183
def function_exists(db, function):
1184
    function = sql_gen.as_Function(function)
1185
    
1186
    info_table = sql_gen.Table('routines', 'information_schema')
1187
    conds = [('routine_name', function.name)]
1188
    schema = function.schema
1189
    if schema != None: conds.append(('routine_schema', schema))
1190
    # Exclude trigger functions, since they cannot be called directly
1191
    conds.append(('data_type', sql_gen.CompareCond('trigger', '!=')))
1192
    
1193
    return list(values(select(db, info_table, ['routine_name'], conds,
1194
        order_by='routine_schema', limit=1, log_level=4))) != []
1195
        # TODO: order_by search_path schema order
1196

    
1197
def errors_table(db, table, if_exists=True):
1198
    '''
1199
    @param if_exists If set, returns None if the errors table doesn't exist
1200
    @return None|sql_gen.Table
1201
    '''
1202
    table = sql_gen.as_Table(table)
1203
    if table.srcs != (): table = table.srcs[0]
1204
    
1205
    errors_table = sql_gen.suffixed_table(table, '.errors')
1206
    if if_exists and not table_exists(db, errors_table): return None
1207
    return errors_table
1208

    
1209
##### Database management
1210

    
1211
def empty_db(db, schema='public', **kw_args):
1212
    '''For kw_args, see tables()'''
1213
    for table in tables(db, schema, **kw_args): truncate(db, table, schema)
1214

    
1215
##### Heuristic queries
1216

    
1217
def put(db, table, row, pkey_=None, row_ct_ref=None):
1218
    '''Recovers from errors.
1219
    Only works under PostgreSQL (uses INSERT RETURNING).
1220
    '''
1221
    row = sql_gen.ColDict(db, table, row)
1222
    if pkey_ == None: pkey_ = pkey(db, table, recover=True)
1223
    
1224
    try:
1225
        cur = insert(db, table, row, pkey_, recover=True)
1226
        if row_ct_ref != None and cur.rowcount >= 0:
1227
            row_ct_ref[0] += cur.rowcount
1228
        return value(cur)
1229
    except DuplicateKeyException, e:
1230
        row = sql_gen.ColDict(db, table,
1231
            util.dict_subset_right_join(row, e.cols))
1232
        return value(select(db, table, [pkey_], row, recover=True))
1233

    
1234
def get(db, table, row, pkey, row_ct_ref=None, create=False):
1235
    '''Recovers from errors'''
1236
    try: return value(select(db, table, [pkey], row, limit=1, recover=True))
1237
    except StopIteration:
1238
        if not create: raise
1239
        return put(db, table, row, pkey, row_ct_ref) # insert new row
1240

    
1241
def is_func_result(col):
1242
    return col.table.name.find('(') >= 0 and col.name == 'result'
1243

    
1244
def into_table_name(out_table, in_tables0, mapping, is_func):
1245
    def in_col_str(in_col):
1246
        in_col = sql_gen.remove_col_rename(in_col)
1247
        if isinstance(in_col, sql_gen.Col):
1248
            table = in_col.table
1249
            if table == in_tables0:
1250
                in_col = sql_gen.to_name_only_col(in_col)
1251
            elif is_func_result(in_col): in_col = table # omit col name
1252
        return str(in_col)
1253
    
1254
    str_ = str(out_table)
1255
    if is_func:
1256
        str_ += '('
1257
        
1258
        try: value_in_col = mapping['value']
1259
        except KeyError:
1260
            str_ += ', '.join((str(k)+'='+in_col_str(v)
1261
                for k, v in mapping.iteritems()))
1262
        else: str_ += in_col_str(value_in_col)
1263
        
1264
        str_ += ')'
1265
    else:
1266
        out_col = 'rank'
1267
        try: in_col = mapping[out_col]
1268
        except KeyError: str_ += '_pkeys'
1269
        else: # has a rank column, so hierarchical
1270
            str_ += '['+str(out_col)+'='+in_col_str(in_col)+']'
1271
    return str_
1272

    
1273
def put_table(db, out_table, in_tables, mapping, row_ct_ref=None, into=None,
1274
    default=None, is_func=False, on_error=exc.raise_):
1275
    '''Recovers from errors.
1276
    Only works under PostgreSQL (uses INSERT RETURNING).
1277
    IMPORTANT: Must be run at the *beginning* of a transaction.
1278
    @param in_tables The main input table to select from, followed by a list of
1279
        tables to join with it using the main input table's pkey
1280
    @param mapping dict(out_table_col=in_table_col, ...)
1281
        * out_table_col: str (*not* sql_gen.Col)
1282
        * in_table_col: sql_gen.Col|literal-value
1283
    @param into The table to contain the output and input pkeys.
1284
        Defaults to `out_table.name+'_pkeys'`.
1285
    @param default The *output* column to use as the pkey for missing rows.
1286
        If this output column does not exist in the mapping, uses None.
1287
    @param is_func Whether out_table is the name of a SQL function, not a table
1288
    @return sql_gen.Col Where the output pkeys are made available
1289
    '''
1290
    out_table = sql_gen.as_Table(out_table)
1291
    
1292
    def log_debug(msg): db.log_debug(msg, level=1.5)
1293
    def col_ustr(str_):
1294
        return strings.repr_no_u(sql_gen.remove_col_rename(str_))
1295
    
1296
    log_debug('********** New iteration **********')
1297
    log_debug('Inserting these input columns into '+strings.as_tt(
1298
        out_table.to_str(db))+':\n'+strings.as_table(mapping, ustr=col_ustr))
1299
    
1300
    is_function = function_exists(db, out_table)
1301
    
1302
    if is_function: out_pkey = 'result'
1303
    else: out_pkey = pkey(db, out_table, recover=True)
1304
    out_pkey_col = sql_gen.as_Col(out_pkey, out_table)
1305
    
1306
    if mapping == {}: # need at least one column for INSERT SELECT
1307
        mapping = {out_pkey: None} # ColDict will replace with default value
1308
    
1309
    # Create input joins from list of input tables
1310
    in_tables_ = in_tables[:] # don't modify input!
1311
    in_tables0 = in_tables_.pop(0) # first table is separate
1312
    errors_table_ = errors_table(db, in_tables0)
1313
    in_pkey = pkey(db, in_tables0, recover=True)
1314
    in_pkey_col = sql_gen.as_Col(in_pkey, in_tables0)
1315
    input_joins = [in_tables0]+[sql_gen.Join(v,
1316
        {in_pkey: sql_gen.join_same_not_null}) for v in in_tables_]
1317
    
1318
    if into == None:
1319
        into = into_table_name(out_table, in_tables0, mapping, is_func)
1320
    into = sql_gen.as_Table(into)
1321
    
1322
    # Set column sources
1323
    in_cols = filter(sql_gen.is_table_col, mapping.values())
1324
    for col in in_cols:
1325
        if col.table == in_tables0: col.set_srcs(sql_gen.src_self)
1326
    
1327
    log_debug('Joining together input tables into temp table')
1328
    # Place in new table for speed and so don't modify input if values edited
1329
    in_table = sql_gen.Table('in')
1330
    mapping = dicts.join(mapping, flatten(db, in_table, input_joins, in_cols,
1331
        preserve=[in_pkey_col], start=0))
1332
    input_joins = [in_table]
1333
    db.log_debug('Temp table: '+strings.as_tt(in_table.to_str(db)), level=2)
1334
    
1335
    mapping = sql_gen.ColDict(db, out_table, mapping)
1336
        # after applying dicts.join() because that returns a plain dict
1337
    
1338
    # Resolve default value column
1339
    if default != None:
1340
        try: default = mapping[default]
1341
        except KeyError:
1342
            db.log_debug('Default value column '
1343
                +strings.as_tt(strings.repr_no_u(default))
1344
                +' does not exist in mapping, falling back to None', level=2.1)
1345
            default = None
1346
    
1347
    pkeys_names = [in_pkey, out_pkey]
1348
    pkeys_cols = [in_pkey_col, out_pkey_col]
1349
    
1350
    pkeys_table_exists_ref = [False]
1351
    def insert_into_pkeys(joins, cols, distinct=False):
1352
        kw_args = {}
1353
        if distinct: kw_args.update(dict(distinct_on=[in_pkey_col]))
1354
        query = mk_select(db, joins, cols, order_by=None, start=0, **kw_args)
1355
        
1356
        if pkeys_table_exists_ref[0]:
1357
            insert_select(db, into, pkeys_names, query)
1358
        else:
1359
            run_query_into(db, query, into=into)
1360
            pkeys_table_exists_ref[0] = True
1361
    
1362
    limit_ref = [None]
1363
    conds = set()
1364
    distinct_on = sql_gen.ColDict(db, out_table)
1365
    def mk_main_select(joins, cols):
1366
        distinct_on_cols = [c.to_Col() for c in distinct_on.values()]
1367
        return mk_select(db, joins, cols, conds, distinct_on_cols,
1368
            limit=limit_ref[0], start=0)
1369
    
1370
    exc_strs = set()
1371
    def log_exc(e):
1372
        e_str = exc.str_(e, first_line_only=True)
1373
        log_debug('Caught exception: '+e_str)
1374
        assert e_str not in exc_strs # avoid infinite loops
1375
        exc_strs.add(e_str)
1376
    
1377
    def remove_all_rows():
1378
        log_debug('Ignoring all rows')
1379
        limit_ref[0] = 0 # just create an empty pkeys table
1380
    
1381
    def ignore(in_col, value, e):
1382
        track_data_error(db, errors_table_, in_col.srcs, value, e.cause.pgcode,
1383
            e.cause.pgerror)
1384
        log_debug('Ignoring rows with '+strings.as_tt(repr(in_col))+' = '
1385
            +strings.as_tt(repr(value)))
1386
    
1387
    def remove_rows(in_col, value, e):
1388
        ignore(in_col, value, e)
1389
        cond = (in_col, sql_gen.CompareCond(value, '!='))
1390
        assert cond not in conds # avoid infinite loops
1391
        conds.add(cond)
1392
    
1393
    def invalid2null(in_col, value, e):
1394
        ignore(in_col, value, e)
1395
        update(db, in_table, [(in_col, None)],
1396
            sql_gen.ColValueCond(in_col, value))
1397
    
1398
    def insert_pkeys_table(which):
1399
        return sql_gen.Table(sql_gen.concat(in_table.name,
1400
            '_insert_'+which+'_pkeys'))
1401
    insert_out_pkeys = insert_pkeys_table('out')
1402
    insert_in_pkeys = insert_pkeys_table('in')
1403
    
1404
    # Do inserts and selects
1405
    join_cols = sql_gen.ColDict(db, out_table)
1406
    while True:
1407
        if limit_ref[0] == 0: # special case
1408
            log_debug('Creating an empty pkeys table')
1409
            cur = run_query_into(db, mk_select(db, out_table, [out_pkey],
1410
                limit=limit_ref[0]), into=insert_out_pkeys)
1411
            break # don't do main case
1412
        
1413
        has_joins = join_cols != {}
1414
        
1415
        log_debug('Trying to insert new rows')
1416
        
1417
        # Prepare to insert new rows
1418
        insert_joins = input_joins[:] # don't modify original!
1419
        insert_args = dict(recover=True, cacheable=False)
1420
        if has_joins:
1421
            insert_joins.append(sql_gen.Join(out_table, join_cols,
1422
                sql_gen.filter_out))
1423
        else:
1424
            insert_args.update(dict(returning=out_pkey, into=insert_out_pkeys))
1425
        main_select = mk_main_select(insert_joins, mapping.values())
1426
        
1427
        def main_insert():
1428
            if is_function:
1429
                log_debug('Calling function on input rows')
1430
                args = dict(((k.name, v) for k, v in mapping.iteritems()))
1431
                func_call = sql_gen.NamedCol(out_pkey,
1432
                    sql_gen.FunctionCall(out_table, **args))
1433
                insert_into_pkeys(input_joins, [in_pkey_col, func_call])
1434
                return None
1435
            else:
1436
                lock_table(db, out_table, 'EXCLUSIVE')
1437
                return insert_select(db, out_table, mapping.keys(), main_select,
1438
                    **insert_args)
1439
        
1440
        try:
1441
            cur = with_savepoint(db, main_insert)
1442
            break # insert successful
1443
        except MissingCastException, e:
1444
            log_exc(e)
1445
            
1446
            out_col = e.col
1447
            type_ = e.type
1448
            
1449
            log_debug('Casting '+strings.as_tt(out_col)+' input to '
1450
                +strings.as_tt(type_))
1451
            mapping[out_col] = cast_temp_col(db, type_, mapping[out_col],
1452
                errors_table_)
1453
        except DuplicateKeyException, e:
1454
            log_exc(e)
1455
            
1456
            old_join_cols = join_cols.copy()
1457
            distinct_on.update(util.dict_subset(mapping, e.cols))
1458
            join_cols.update(util.dict_subset_right_join(mapping, e.cols))
1459
            log_debug('Ignoring existing rows, comparing on these columns:\n'
1460
                +strings.as_inline_table(join_cols, ustr=col_ustr))
1461
            assert join_cols != old_join_cols # avoid infinite loops
1462
        except NullValueException, e:
1463
            log_exc(e)
1464
            
1465
            out_col, = e.cols
1466
            try: in_col = mapping[out_col]
1467
            except KeyError:
1468
                log_debug('Missing mapping for NOT NULL column '+out_col)
1469
                remove_all_rows()
1470
            else: remove_rows(in_col, None, e)
1471
        except FunctionValueException, e:
1472
            log_exc(e)
1473
            
1474
            func_name = e.name
1475
            value = e.value
1476
            for out_col, in_col in mapping.iteritems():
1477
                in_col = sql_gen.unwrap_func_call(in_col, func_name)
1478
                invalid2null(in_col, value, e)
1479
        except DatabaseErrors, e:
1480
            log_exc(e)
1481
            
1482
            log_debug('No handler for exception')
1483
            on_error(e)
1484
            remove_all_rows()
1485
        # after exception handled, rerun loop with additional constraints
1486
    
1487
    if cur != None and row_ct_ref != None and cur.rowcount >= 0:
1488
        row_ct_ref[0] += cur.rowcount
1489
    
1490
    if is_function: pass # pkeys table already created
1491
    elif has_joins:
1492
        select_joins = input_joins+[sql_gen.Join(out_table, join_cols)]
1493
        log_debug('Getting output table pkeys of existing/inserted rows')
1494
        insert_into_pkeys(select_joins, pkeys_cols, distinct=True)
1495
    else:
1496
        add_row_num(db, insert_out_pkeys) # for joining with input pkeys
1497
        
1498
        log_debug('Getting input table pkeys of inserted rows')
1499
        run_query_into(db, mk_main_select(input_joins, [in_pkey]),
1500
            into=insert_in_pkeys)
1501
        add_row_num(db, insert_in_pkeys) # for joining with output pkeys
1502
        
1503
        assert table_row_count(db, insert_out_pkeys) == table_row_count(db,
1504
            insert_in_pkeys)
1505
        
1506
        log_debug('Combining output and input pkeys in inserted order')
1507
        pkey_joins = [insert_in_pkeys, sql_gen.Join(insert_out_pkeys,
1508
            {row_num_col: sql_gen.join_same_not_null})]
1509
        insert_into_pkeys(pkey_joins, pkeys_names)
1510
        
1511
        empty_temp(db, [insert_out_pkeys, insert_in_pkeys])
1512
    
1513
    db.log_debug('Adding pkey on pkeys table to enable fast joins', level=2.5)
1514
    add_pkey(db, into)
1515
    
1516
    log_debug('Setting pkeys of missing rows to '+strings.as_tt(repr(default)))
1517
    missing_rows_joins = input_joins+[sql_gen.Join(into,
1518
        {in_pkey: sql_gen.join_same_not_null}, sql_gen.filter_out)]
1519
        # must use join_same_not_null or query will take forever
1520
    insert_into_pkeys(missing_rows_joins,
1521
        [in_pkey_col, sql_gen.NamedCol(out_pkey, default)])
1522
    
1523
    assert table_row_count(db, into) == table_row_count(db, in_table)
1524
    
1525
    empty_temp(db, in_table)
1526
    
1527
    srcs = []
1528
    if is_func: srcs = sql_gen.cols_srcs(in_cols)
1529
    return sql_gen.Col(out_pkey, into, srcs)
1530

    
1531
##### Data cleanup
1532

    
1533
def cleanup_table(db, table, cols):
1534
    table = sql_gen.as_Table(table)
1535
    cols = map(sql_gen.as_Col, cols)
1536
    
1537
    expr = ('nullif(nullif(trim(both from %s), '+db.esc_value('')+'), '
1538
        +db.esc_value(r'\N')+')')
1539
    changes = [(v, sql_gen.CustomCode(expr % v.to_str(db)))
1540
        for v in cols]
1541
    
1542
    update(db, table, changes)
(24-24/36)