X-Git-Url: http://git.equinoxoli.org/?p=migration-tools.git;a=blobdiff_plain;f=sql%2Fbase%2Fbase.sql;h=de80f0f8bb849241f80a39e704d406ca45e37f37;hp=bd2b58a4a7dc1b539160cac018907557812c350e;hb=e9506234be916a9a719b844c7005c9cfa8251edf;hpb=8821acd9cde150b10241e02841bc0bdd52b5cf3a diff --git a/sql/base/base.sql b/sql/base/base.sql index bd2b58a..de80f0f 100644 --- a/sql/base/base.sql +++ b/sql/base/base.sql @@ -244,7 +244,7 @@ CREATE OR REPLACE FUNCTION migration_tools.build_specific_base_staging_table (TE BEGIN base_staging_table = REPLACE( production_table, '.', '_' ); --RAISE INFO 'In migration_tools.build_specific_base_staging_table(%,%) -> %', migration_schema, production_table, base_staging_table; - PERFORM migration_tools.exec( $1, 'CREATE TABLE ' || migration_schema || '.' || base_staging_table || ' ( LIKE ' || production_table || ' INCLUDING DEFAULTS EXCLUDING CONSTRAINTS );' ); + PERFORM migration_tools.exec( $1, 'CREATE UNLOGGED TABLE ' || migration_schema || '.' || base_staging_table || ' ( LIKE ' || production_table || ' INCLUDING DEFAULTS EXCLUDING CONSTRAINTS );' ); PERFORM migration_tools.exec( $1, ' INSERT INTO ' || migration_schema || '.fields_requiring_mapping SELECT table_schema, table_name, column_name, data_type @@ -452,6 +452,74 @@ CREATE OR REPLACE FUNCTION migration_tools.address_parse_out_citystatezip (TEXT) END; $$ LANGUAGE PLPGSQL STRICT VOLATILE; +-- try to parse data like this: 100 MAIN ST$COVINGTON, GA 30016 +CREATE OR REPLACE FUNCTION migration_tools.parse_out_address (TEXT) RETURNS TEXT[] AS $$ + DECLARE + fullstring TEXT := $1; + address1 TEXT := ''; + address2 TEXT := ''; + scratch1 TEXT := ''; + scratch2 TEXT := ''; + city TEXT := ''; + state TEXT := ''; + zip TEXT := ''; + BEGIN + zip := CASE + WHEN fullstring ~ E'\\d\\d\\d\\d\\d' + THEN REGEXP_REPLACE( fullstring, E'^.*(\\d\\d\\d\\d\\d-?\\d*).*$', E'\\1' ) + ELSE '' + END; + fullstring := REGEXP_REPLACE( fullstring, E'^(.*)\\d\\d\\d\\d\\d-?\\d*(.*)$', E'\\1\\2'); + + IF fullstring ~ ',' THEN + state := REGEXP_REPLACE( fullstring, E'^(.*),(.*)$', E'\\2'); + scratch1 := REGEXP_REPLACE( fullstring, E'^(.*),(.*)$', E'\\1'); + ELSE + IF fullstring ~ E'\\s+[A-Z][A-Z]\\s*$' THEN + state := REGEXP_REPLACE( fullstring, E'^.*,?\\s+([A-Z][A-Z])\\s*$', E'\\1' ); + scratch1 := REGEXP_REPLACE( fullstring, E'^(.*?),?\\s+[A-Z][A-Z](\\s*)$', E'\\1\\2' ); + ELSE + IF fullstring ~ E'^\\S+$' THEN + scratch1 := fullstring; + state := 'N/A'; + ELSE + state := REGEXP_REPLACE( fullstring, E'^(.*?),?\\s*(\\S+)\\s*$', E'\\2'); + scratch1 := REGEXP_REPLACE( fullstring, E'^(.*?),?\\s*(\\S+)\\s*$', E'\\1'); + END IF; + END IF; + END IF; + + IF scratch1 ~ '[\$]' THEN + scratch2 := REGEXP_REPLACE( scratch1, E'^(.+)[\$](.+?)$', E'\\1'); + city := REGEXP_REPLACE( scratch1, E'^(.+)[\$](.+?)$', E'\\2'); + ELSE + IF scratch1 ~ '\s' THEN + scratch2 := REGEXP_REPLACE( scratch1, E'^(.+)\\s+(.+?)$', E'\\1'); + city := REGEXP_REPLACE( scratch1, E'^(.+)\\s+(.+?)$', E'\\2'); + ELSE + scratch2 := 'N/A'; + city := scratch1; + END IF; + END IF; + + IF scratch2 ~ '^\d' THEN + address1 := scratch2; + address2 := ''; + ELSE + address1 := REGEXP_REPLACE( scratch2, E'^(.+?)(\\d.+)$', E'\\1'); + address2 := REGEXP_REPLACE( scratch2, E'^(.+?)(\\d.+)$', E'\\2'); + END IF; + + RETURN ARRAY[ + TRIM(BOTH ' ' FROM address1) + ,TRIM(BOTH ' ' FROM address2) + ,TRIM(BOTH ' ' FROM city) + ,TRIM(BOTH ' ' FROM state) + ,TRIM(BOTH ' ' FROM zip) + ]; + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + CREATE OR REPLACE FUNCTION migration_tools.rebarcode (o TEXT, t BIGINT) RETURNS TEXT AS $$ DECLARE n TEXT := o; @@ -772,6 +840,24 @@ CREATE OR REPLACE FUNCTION migration_tools.attempt_hz_date (TEXT,TEXT) RETURNS D END; $$ LANGUAGE PLPGSQL STRICT STABLE; +CREATE OR REPLACE FUNCTION migration_tools.attempt_sierra_timestamp (TEXT,TEXT) RETURNS TIMESTAMP AS $$ + DECLARE + attempt_value ALIAS FOR $1; + fail_value ALIAS FOR $2; + output TIMESTAMP; + BEGIN + output := REGEXP_REPLACE(attempt_value,E'^(..)(..)(..)(..)(..)$',E'20\\1-\\2-\\3 \\4:\\5')::TIMESTAMP; + RETURN output; + EXCEPTION + WHEN OTHERS THEN + FOR output IN + EXECUTE 'SELECT ' || quote_literal(fail_value) || '::TIMESTAMP AS a;' + LOOP + RETURN output; + END LOOP; + END; +$$ LANGUAGE PLPGSQL STRICT STABLE; + CREATE OR REPLACE FUNCTION migration_tools.attempt_money (TEXT,TEXT) RETURNS NUMERIC(8,2) AS $$ DECLARE attempt_value ALIAS FOR $1; @@ -2449,3 +2535,38 @@ CREATE OR REPLACE FUNCTION migration_tools.find_circ_matrix_matchpoint (INTEGER) ) ); $$ LANGUAGE SQL; + +CREATE OR REPLACE FUNCTION migration_tools.assert (BOOLEAN) RETURNS VOID AS $$ + DECLARE + test ALIAS FOR $1; + BEGIN + IF NOT test THEN + RAISE EXCEPTION 'assertion'; + END IF; + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +CREATE OR REPLACE FUNCTION migration_tools.assert (BOOLEAN,TEXT) RETURNS VOID AS $$ + DECLARE + test ALIAS FOR $1; + msg ALIAS FOR $2; + BEGIN + IF NOT test THEN + RAISE EXCEPTION '%', msg; + END IF; + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +CREATE OR REPLACE FUNCTION migration_tools.assert (BOOLEAN,TEXT,TEXT) RETURNS TEXT AS $$ + DECLARE + test ALIAS FOR $1; + fail_msg ALIAS FOR $2; + success_msg ALIAS FOR $3; + BEGIN + IF NOT test THEN + RAISE EXCEPTION '%', fail_msg; + END IF; + RETURN success_msg; + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; +