#!/usr/bin/env python import sys import os import re # import time import logging import argparse as arg import psycopg2 as pg from psycopg2.extensions import AsIs from classes.CustomFormater import CustomFormatter from classes.Timer import Timer import locale locale.setlocale(locale.LC_ALL, 'fr_FR.UTF-8') # Schema name is NAMEDATALEN-1 (PGSQL source code) # -> src/include/pg_config_manual.h def check_schema_name(arg_value, pat=re.compile(r"^[a-z0-9A-Z]{1,63}$")): if not pat.match(arg_value): raise ValueError return arg_value def parse_args(): """ Parse arguments """ parser = arg.ArgumentParser('Process csv files from INSEE') parser.add_argument('--source', '-s', help='csv source directory', default='exports') parser.add_argument('--connection-file', '-f', help='Postgresql connexion file', default='.pgconn' ) # As whe use AsIs function to not include '' in our sql queries for schema # name, me mus ensure that it is not contains SQL special characters # like comments --, final coma etc and avoid SQL injection parser.add_argument('--schema-name', help='Database schema name', type=check_schema_name, default='insee' ) parser.add_argument('--test', '-t', help='test view, get 10 record of each', action='store_true' ) debug_group = parser.add_mutually_exclusive_group() debug_group.add_argument('--verbose', '-V', help='Verbose output', action='store_true') debug_group.add_argument('--debug', '-d', help='Activate debug mode', action='store_true') return parser.parse_args() if __name__ == '__main__': args = parse_args() #logging.basicConfig(level=logging.DEBUG) logger = logging.getLogger() tty_handler = logging.StreamHandler() # create console handler with a higher log level tty_handler.setFormatter(CustomFormatter()) logger.addHandler(tty_handler) if args.verbose is True: logger.setLevel(logging.INFO) logger.info('VERBOSE mode activated') if args.debug is True: logger.setLevel(logging.DEBUG) logger.debug('DEBUG mode activated') logging.debug('Import pgsql connection file {}'.format(args.connection_file)) with open(args.connection_file) as cf: pg_conn = cf.read() t = Timer(logger=logger.info) conn = pg.connect(pg_conn) with conn.cursor() as curs: logger.debug('Create trigger on region and departement') t.start('dep reg trigger') try: curs.execute(""" CREATE OR REPLACE FUNCTION %(schema)s.block_maj_reg_dep() RETURNS TRIGGER AS $bloquage$ BEGIN RAISE EXCEPTION 'Mise à jour non autorisé'; END; $bloquage$ language plpgsql; CREATE TRIGGER TRG_BLOQ_MAJ_REG BEFORE INSERT OR UPDATE OR DELETE ON %(schema)s.region FOR EACH ROW EXECUTE PROCEDURE %(schema)s.block_maj_reg_dep(); CREATE TRIGGER TRG_BLOQ_MAJ_DEP BEFORE INSERT OR UPDATE OR DELETE ON %(schema)s.departement FOR EACH ROW EXECUTE PROCEDURE %(schema)s.block_maj_reg_dep(); """, {'schema':AsIs(args.schema_name)}) conn.commit() except Exception as e: logger.error('Something goes wrong on block trigger: {}'.format(e)) sys.exit(1) t.stop() logger.debug('Add procedure to modify pop. values on region and dep') t.start('Add fun_maj_pop() procedure') try: curs.execute(""" CREATE OR REPLACE FUNCTION %(schema)s.FUN_MAJ_POP() RETURNS TRIGGER AS $maj_population$ BEGIN ALTER TABLE %(schema)s.region DISABLE TRIGGER TRG_BLOQ_MAJ_REG; ALTER TABLE %(schema)s.departement DISABLE TRIGGER TRG_BLOQ_MAJ_DEP; IF(TG_OP = 'INSERT' AND NEW.ID_INDICATEUR = 1 AND (NEW.VALEUR <> 0 OR NEW.VALEUR <> NULL)) THEN CALL %(schema)s.PRC_POP_REG_DEP(); END IF; IF(TG_OP = 'UPDATE' AND NEW.ID_INDICATEUR = 1 AND NEW.VALEUR <> OLD.VALEUR) THEN CALL %(schema)s.PRC_POP_REG_DEP(); END IF; IF(TG_OP = 'DELETE' AND OLD.ID_INDICATEUR = 1 AND (OLD.VALEUR <> 0 OR OLD.VALEUR <> NULL)) THEN CALL %(schema)s.PRC_POP_REG_DEP(); END IF; ALTER TABLE %(schema)s.region ENABLE TRIGGER TRG_BLOQ_MAJ_REG; ALTER TABLE %(schema)s.departement ENABLE TRIGGER TRG_BLOQ_MAJ_DEP; RETURN NULL; END; $maj_population$ language plpgsql; """, {'schema':AsIs(args.schema_name)}) conn.commit() except Exception as e: logger.error( 'Something goes wrong on fun_maj_pop procedure: {}'.format(e) ) sys.exit(1) t.stop() logger.debug('Add trigger on statistique tto update pop. values') t.start('Add fun_maj_pop() procedure') try: curs.execute(""" CREATE TRIGGER TRG_MAJ_POP AFTER INSERT OR UPDATE OR DELETE ON %(schema)s.statistique FOR EACH ROW EXECUTE PROCEDURE %(schema)s.FUN_MAJ_POP(); """, {'schema':AsIs(args.schema_name)}) conn.commit() except Exception as e: logger.error( 'Something goes wrong on statistique trigger: {}'.format(e) ) sys.exit(1) t.stop()