#!/usr/bin/env python3 """ Database table definitions and prepared statements. Note: (short) postfix queue IDs are not unique: http://postfix.1071664.n5.nabble.com/Queue-ID-gets-reused-Not-unique-td25387.html """ from typing import Dict, List _table_def_delivery_from = [ [ dict(name='t_i', dtype='TIMESTAMP'), dict(name='t_f', dtype='TIMESTAMP'), dict(name='queue_id', dtype='VARCHAR(16)', null=False, extra='UNIQUE'), dict(name='host', dtype='VARCHAR(200)'), dict(name='ip', dtype='VARCHAR(50)'), dict(name='sasl_username', dtype='VARCHAR(300)'), dict(name='orig_queue_id', dtype='VARCHAR(16)'), dict(name='status', dtype='VARCHAR(10)'), dict(name='accepted', dtype='BOOL', null=False, default='TRUE'), dict(name='done', dtype='BOOL', null=False, default='FALSE'), dict(name='sender', dtype='VARCHAR(300)'), dict(name='message_id', dtype='VARCHAR(1000)'), dict(name='resent_message_id', dtype='VARCHAR(1000)'), dict(name='subject', dtype='VARCHAR(1000)'), dict(name='phase', dtype='VARCHAR(15)'), dict(name='error', dtype='VARCHAR(1000)'), dict(name='size', dtype='INT'), dict(name='nrcpt', dtype='INT'), dict(name='verp_id', dtype='INT'), dict(name='messages', dtype='JSONB', null=False, default="'{}'::JSONB"), ], "CREATE INDEX delivery_from__queue_id ON delivery_from (queue_id)", "CREATE INDEX delivery_from__t_i ON delivery_from (t_i)", "CREATE INDEX delivery_from__t_f ON delivery_from (t_f)", "CREATE INDEX delivery_from__sender ON delivery_from (sender)", "CREATE INDEX delivery_from__message_id ON delivery_from (message_id)", ] _table_def_delivery_to = [ [ dict(name='t_i', dtype='TIMESTAMP'), dict(name='t_f', dtype='TIMESTAMP'), dict(name='queue_id', dtype='VARCHAR(16)', null=False), dict(name='recipient', dtype='VARCHAR(300)'), dict(name='orig_recipient', dtype='VARCHAR(300)'), dict(name='host', dtype='VARCHAR(200)'), dict(name='ip', dtype='VARCHAR(50)'), dict(name='port', dtype='VARCHAR(10)'), dict(name='relay', dtype='VARCHAR(10)'), dict(name='delay', dtype='VARCHAR(200)'), dict(name='delays', dtype='VARCHAR(200)'), dict(name='dsn', dtype='VARCHAR(10)'), dict(name='status', dtype='VARCHAR(10)'), dict(name='status_text', dtype='VARCHAR(1000)'), dict(name='messages', dtype='JSONB', null=False, default="'{}'::JSONB"), ], "ALTER TABLE delivery_to ADD CONSTRAINT" " delivery_to__queue_id_recipient UNIQUE(queue_id, recipient)", "CREATE INDEX delivery_to__queue_id ON delivery_to (queue_id)", "CREATE INDEX delivery_to__recipient ON delivery_to (recipient)", "CREATE INDEX delivery_to__t_i ON delivery_to (t_i)", "CREATE INDEX delivery_to__t_f ON delivery_to (t_f)", ] _table_def_noqueue = [ [ dict(name='t', dtype='TIMESTAMP'), dict(name='host', dtype='VARCHAR(200)'), dict(name='ip', dtype='VARCHAR(50)'), dict(name='sender', dtype='VARCHAR(300)'), dict(name='recipient', dtype='VARCHAR(300)'), dict(name='sasl_username', dtype='VARCHAR(300)'), dict(name='status', dtype='VARCHAR(10)'), dict(name='phase', dtype='VARCHAR(15)'), dict(name='error', dtype='VARCHAR(1000)'), dict(name='message', dtype='TEXT'), ], "CREATE INDEX noqueue__t ON noqueue (t)", "CREATE INDEX noqueue__sender ON noqueue (sender)", "CREATE INDEX noqueue__recipient ON noqueue (recipient)", ] _tables: Dict[str, list] = { 'delivery_from': _table_def_delivery_from, 'delivery_to': _table_def_delivery_to, 'noqueue': _table_def_noqueue, } _prepared_statements = { 'delivery_from': "PREPARE delivery_from_insert ({}) AS " "INSERT INTO delivery_from ({}) VALUES ({}) " "ON CONFLICT (queue_id) DO UPDATE SET {}", 'delivery_to': "PREPARE delivery_to_insert ({}) AS " "INSERT INTO delivery_to ({}) VALUES ({}) " "ON CONFLICT (queue_id, recipient) DO UPDATE SET {}", 'noqueue': "PREPARE noqueue_insert ({}) AS " "INSERT INTO noqueue ({}) VALUES ({}){}", } table_fields: Dict[str, List[str]] = {} """ Lists of field names for tables, populated by get_create_table_stmts(). """ def get_sql_prepared_statement(table_name: str) -> str: """ Return SQL defining a prepared statement for inserting into a table. Table 'noqueue' is handled differently, because it does not have an UPDATE clause. """ col_names = [] col_types = [] col_args = [] col_upds = [] col_i = 0 for field in _tables[table_name][0]: # column type col_type = field['dtype'] if field['dtype'].lower().startswith('varchar'): col_type = 'TEXT' col_types.append(col_type) # column args col_i += 1 col_arg = '$' + str(col_i) # column name col_name = field['name'] col_names.append(col_name) if 'default' in field: default = field['default'] col_args.append(f'COALESCE({col_arg},{default})') else: col_args.append(col_arg) # column update col_upd = f'{col_name}=COALESCE({col_arg},{table_name}.{col_name})' if col_name != 't_i': if col_name == 'messages': col_upd = f'{col_name}={table_name}.{col_name}||{col_arg}' if table_name != 'noqueue': col_upds.append(col_upd) stmt = _prepared_statements[table_name].format( ','.join(col_types), ','.join(col_names), ','.join(col_args), ','.join(col_upds), ) return stmt def get_sql_execute_prepared_statement(table_name: str) -> str: """ Return SQL for executing the given table's prepared statement. The result is based on global variable _tables. """ fields = _tables[table_name][0] return "EXECUTE {}_insert ({})"\ .format(table_name, ','.join(['%s' for i in range(len(fields))])) def get_create_table_stmts() -> Dict[str, List[str]]: """ Return a dict mapping table names to SQL statements creating the tables. Also populate global variable table_fields. """ res = {} for table_name, table_def in _tables.items(): stmts = table_def.copy() stmts[0] = _get_sql_create_stmt(table_name, table_def[0]) res[table_name] = stmts field_names = [x['name'] for x in table_def[0]] global table_fields table_fields[table_name] = field_names return res def _get_sql_create_stmt(table_name: str, fields: List[dict]): """ Return the 'CREATE TABLE' SQL statement for a table. Factor in NULL, DEFAULT and extra DDL text. """ sql = f"CREATE TABLE {table_name} (\n id BIGSERIAL," col_defs = [] for field in fields: col_def = f" {field['name']} {field['dtype']}" if 'null' in field and field['null'] is False: col_def += " NOT NULL" if 'default' in field: col_def += f" DEFAULT {field['default']}" if 'extra' in field: col_def += f" {field['extra']}" col_defs.append(col_def) sql += '\n' + ',\n'.join(col_defs) sql += '\n)' return sql