From: Jason Etheridge Date: Wed, 12 Aug 2009 04:58:48 +0000 (+0000) Subject: move dynamic item mapping functionality to base.sql; it's not ILS specific X-Git-Url: http://git.equinoxoli.org/?p=migration-tools.git;a=commitdiff_plain;h=75ea5d77a8cd63071d6752ffdd191346348402db move dynamic item mapping functionality to base.sql; it's not ILS specific --- diff --git a/sql/base/base.sql b/sql/base/base.sql index 832f43c..66f2a89 100644 --- a/sql/base/base.sql +++ b/sql/base/base.sql @@ -118,6 +118,23 @@ CREATE OR REPLACE FUNCTION migration_tools.init (TEXT) RETURNS VOID AS $$ legacy_value3 TEXT );' ); PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''base_profile_map'', ''base_profile_map'' );' ); + PERFORM migration_tools.exec( $1, 'DROP TABLE IF EXISTS ' || migration_schema || '.base_item_dynamic_field_map;' ); + PERFORM migration_tools.exec( $1, 'CREATE TABLE ' || migration_schema || E'.base_item_dynamic_field_map ( + id SERIAL, + evergreen_field TEXT, + evergreen_value TEXT, + evergreen_datatype TEXT, + legacy_field1 TEXT, + legacy_value1 TEXT, + legacy_field2 TEXT, + legacy_value2 TEXT, + legacy_field3 TEXT, + legacy_value3 TEXT + );' ); + PERFORM migration_tools.exec( $1, 'CREATE INDEX ' || migration_schema || '_item_dynamic_lf1_idx ON ' || migration_schema || '.base_item_dynamic_field_map (legacy_field1,legacy_value1);' ); + PERFORM migration_tools.exec( $1, 'CREATE INDEX ' || migration_schema || '_item_dynamic_lf2_idx ON ' || migration_schema || '.base_item_dynamic_field_map (legacy_field2,legacy_value2);' ); + PERFORM migration_tools.exec( $1, 'CREATE INDEX ' || migration_schema || '_item_dynamic_lf3_idx ON ' || migration_schema || '.base_item_dynamic_field_map (legacy_field3,legacy_value3);' ); + PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''base_item_dynamic_field_map'', ''base_item_dynamic_field_map'' );' ); BEGIN PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''last_init'', now() );' ); EXCEPTION @@ -317,6 +334,20 @@ CREATE OR REPLACE FUNCTION migration_tools.base_profile_map (TEXT) RETURNS TEXT END; $$ LANGUAGE PLPGSQL STRICT STABLE; +CREATE OR REPLACE FUNCTION migration_tools.base_item_dynamic_field_map (TEXT) RETURNS TEXT AS $$ + DECLARE + migration_schema ALIAS FOR $1; + output TEXT; + BEGIN + FOR output IN + EXECUTE 'SELECT ''' || migration_schema || '.'' || value FROM ' || migration_schema || '.config WHERE key = ''base_item_dynamic_field_map'';' + LOOP + RETURN output; + END LOOP; + END; +$$ LANGUAGE PLPGSQL STRICT STABLE; + + CREATE OR REPLACE FUNCTION migration_tools.map_base_patron_profile (TEXT,TEXT,INTEGER) RETURNS VOID AS $$ DECLARE migration_schema ALIAS FOR $1; @@ -351,4 +382,36 @@ CREATE OR REPLACE FUNCTION migration_tools.map_base_patron_profile (TEXT,TEXT,IN END; $$ LANGUAGE PLPGSQL STRICT STABLE; +CREATE OR REPLACE FUNCTION migration_tools.map_base_item_table_dynamic (TEXT,TEXT) RETURNS VOID AS $$ + DECLARE + migration_schema ALIAS FOR $1; + field_map TEXT; + item_table TEXT ALIAS FOR $2; + sql TEXT; + sql_update TEXT; + sql_where1 TEXT := ''; + sql_where2 TEXT := ''; + sql_where3 TEXT := ''; + output RECORD; + BEGIN + SELECT migration_tools.base_item_dynamic_field_map(migration_schema) INTO STRICT field_map; + FOR output IN + EXECUTE 'SELECT * FROM ' || field_map || E' ORDER BY id;' + LOOP + sql_update := 'UPDATE ' || item_table || ' AS i SET ' || output.evergreen_field || E' = ' || quote_literal(output.evergreen_value) || '::' || output.evergreen_datatype || E' FROM ' || field_map || ' AS m WHERE '; + sql_where1 := NULLIF(output.legacy_field1,'') || ' = ' || quote_literal( output.legacy_value1 ) || ' AND legacy_field1 = ' || quote_literal(output.legacy_field1) || ' AND legacy_value1 = ' || quote_literal(output.legacy_value1); + sql_where2 := NULLIF(output.legacy_field2,'') || ' = ' || quote_literal( output.legacy_value2 ) || ' AND legacy_field2 = ' || quote_literal(output.legacy_field2) || ' AND legacy_value2 = ' || quote_literal(output.legacy_value2); + sql_where3 := NULLIF(output.legacy_field3,'') || ' = ' || quote_literal( output.legacy_value3 ) || ' AND legacy_field3 = ' || quote_literal(output.legacy_field3) || ' AND legacy_value3 = ' || quote_literal(output.legacy_value3); + sql := sql_update || COALESCE(sql_where1,'') || CASE WHEN sql_where1 <> '' AND sql_where2<> '' THEN ' AND ' ELSE '' END || COALESCE(sql_where2,'') || CASE WHEN sql_where2 <> '' AND sql_where3 <> '' THEN ' AND ' ELSE '' END || COALESCE(sql_where3,'') || ';'; + --RAISE INFO 'sql = %', sql; + PERFORM migration_tools.exec( $1, sql ); + END LOOP; + BEGIN + PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''last_base_item_mapping_dynamic'', now() );' ); + EXCEPTION + WHEN OTHERS THEN PERFORM migration_tools.exec( $1, 'UPDATE ' || migration_schema || '.config SET value = now() WHERE key = ''last_base_item_mapping_dynamic'';' ); + END; + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; +