adding actor.usr_setting to production tables
[migration-tools.git] / sql / base / base.sql
index 7eb55e0..ef2f138 100644 (file)
@@ -117,7 +117,7 @@ CREATE OR REPLACE FUNCTION migration_tools.init (TEXT) RETURNS VOID AS $$
         END;
         PERFORM migration_tools.exec( $1, 'DROP TABLE IF EXISTS ' || migration_schema || '.config;' );
         PERFORM migration_tools.exec( $1, 'CREATE TABLE ' || migration_schema || '.config ( key TEXT UNIQUE, value TEXT);' );
-        PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''production_tables'', ''asset.call_number,asset.call_number_prefix,asset.call_number_suffix,asset.copy_location,asset.copy,asset.stat_cat,asset.stat_cat_entry,asset.stat_cat_entry_copy_map,asset.copy_note,actor.usr,actor.card,actor.usr_address,actor.stat_cat,actor.stat_cat_entry,actor.stat_cat_entry_usr_map,actor.usr_note,actor.usr_standing_penalty,action.circulation,action.hold_request,action.hold_notification,action.hold_request_note,action.hold_transit_copy,action.transit_copy,money.grocery,money.billing,money.cash_payment,money.forgive_payment,acq.provider,acq.provider_address,acq.provider_note,acq.provider_contact,acq.provider_contact_address,acq.fund,acq.fund_allocation,acq.fund_tag,acq.fund_tag_map,acq.funding_source,acq.funding_source_credit,acq.lineitem,acq.purchase_order,acq.po_item,acq.invoice,acq.invoice_item,acq.invoice_entry,acq.lineitem_detail,acq.fund_debit,acq.fund_transfer,acq.po_note,config.circ_matrix_matchpoint,config.circ_matrix_limit_set_map,config.hold_matrix_matchpoint'' );' );
+        PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''production_tables'', ''asset.call_number,asset.call_number_prefix,asset.call_number_suffix,asset.copy_location,asset.copy,asset.stat_cat,asset.stat_cat_entry,asset.stat_cat_entry_copy_map,asset.copy_note,actor.usr,actor.card,actor.usr_address,actor.stat_cat,actor.stat_cat_entry,actor.stat_cat_entry_usr_map,actor.usr_note,actor.usr_standing_penalty,actor.usr_setting,action.circulation,action.hold_request,action.hold_notification,action.hold_request_note,action.hold_transit_copy,action.transit_copy,money.grocery,money.billing,money.cash_payment,money.forgive_payment,acq.provider,acq.provider_address,acq.provider_note,acq.provider_contact,acq.provider_contact_address,acq.fund,acq.fund_allocation,acq.fund_tag,acq.fund_tag_map,acq.funding_source,acq.funding_source_credit,acq.lineitem,acq.purchase_order,acq.po_item,acq.invoice,acq.invoice_item,acq.invoice_entry,acq.lineitem_detail,acq.fund_debit,acq.fund_transfer,acq.po_note,config.circ_matrix_matchpoint,config.circ_matrix_limit_set_map,config.hold_matrix_matchpoint'' );' );
         PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''country_code'', ''USA'' );' );
         PERFORM migration_tools.exec( $1, 'DROP TABLE IF EXISTS ' || migration_schema || '.fields_requiring_mapping;' );
         PERFORM migration_tools.exec( $1, 'CREATE TABLE ' || migration_schema || '.fields_requiring_mapping( table_schema TEXT, table_name TEXT, column_name TEXT, data_type TEXT);' );
@@ -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;
@@ -2454,7 +2540,9 @@ CREATE OR REPLACE FUNCTION migration_tools.assert (BOOLEAN) RETURNS VOID AS $$
     DECLARE
         test ALIAS FOR $1;
     BEGIN
-        ASSERT test;
+        IF NOT test THEN
+            RAISE EXCEPTION 'assertion';
+        END IF;
     END;
 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
 
@@ -2463,7 +2551,22 @@ CREATE OR REPLACE FUNCTION migration_tools.assert (BOOLEAN,TEXT) RETURNS VOID AS
         test ALIAS FOR $1;
         msg ALIAS FOR $2;
     BEGIN
-        ASSERT test, msg;
+        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;