From b919be887d03ee11eef2c3193cea2ba6c1786d49 Mon Sep 17 00:00:00 2001 From: Jason Etheridge Date: Sun, 8 Apr 2018 23:42:00 -0400 Subject: [PATCH] more more generic generic convenience function: migration_tools.handle_link2 Signed-off-by: Jason Etheridge --- sql/base/base.sql | 58 +++++++++++++++++++++++++++++++++++++++++++++++++++++ 1 files changed, 58 insertions(+), 0 deletions(-) diff --git a/sql/base/base.sql b/sql/base/base.sql index 51391d7..f75ba25 100644 --- a/sql/base/base.sql +++ b/sql/base/base.sql @@ -3414,3 +3414,61 @@ CREATE OR REPLACE FUNCTION migration_tools.handle_link (TEXT,TEXT,TEXT,TEXT,TEXT END; $$ LANGUAGE PLPGSQL STRICT VOLATILE; + +-- convenience function for linking two tables, but copying column w into column x instead of "id" +-- e.g. select migration_tools.handle_link2(:'migschema','asset_copy','barcode','test_foo','l_barcode','id','x_acp_id',false); +CREATE OR REPLACE FUNCTION migration_tools.handle_link2 (TEXT,TEXT,TEXT,TEXT,TEXT,TEXT,TEXT,BOOLEAN) RETURNS VOID AS $$ + DECLARE + table_schema ALIAS FOR $1; + table_a ALIAS FOR $2; + column_a ALIAS FOR $3; + table_b ALIAS FOR $4; + column_b ALIAS FOR $5; + column_w ALIAS FOR $6; + column_x ALIAS FOR $7; + btrim_desired ALIAS FOR $8; + proceed BOOLEAN; + BEGIN + EXECUTE 'SELECT EXISTS ( + SELECT 1 + FROM information_schema.columns + WHERE table_schema = $1 + AND table_name = $2 + and column_name = $3 + )' INTO proceed USING table_schema, table_a, column_a; + IF NOT proceed THEN + RAISE EXCEPTION '%.% missing column %', table_schema, table_a, column_a; + END IF; + + EXECUTE 'SELECT EXISTS ( + SELECT 1 + FROM information_schema.columns + WHERE table_schema = $1 + AND table_name = $2 + and column_name = $3 + )' INTO proceed USING table_schema, table_b, column_b; + IF NOT proceed THEN + RAISE EXCEPTION '%.% missing column %', table_schema, table_b, column_b; + END IF; + + EXECUTE 'ALTER TABLE ' + || quote_ident(table_b) + || ' DROP COLUMN IF EXISTS ' || quote_ident(column_x); + EXECUTE 'ALTER TABLE ' + || quote_ident(table_b) + || ' ADD COLUMN ' || quote_ident(column_x) || ' TEXT'; + + IF btrim_desired THEN + EXECUTE 'UPDATE ' || quote_ident(table_b) || ' b' + || ' SET ' || quote_ident(column_x) || ' = ' || quote_ident(column_w) || ' FROM ' || quote_ident(table_a) || ' a' + || ' WHERE BTRIM(a.' || quote_ident(column_a) + || ') = BTRIM(b.' || quote_ident(column_b) || ')'; + ELSE + EXECUTE 'UPDATE ' || quote_ident(table_b) || ' b' + || ' SET ' || quote_ident(column_x) || ' = ' || quote_ident(column_w) || ' FROM ' || quote_ident(table_a) || ' a' + || ' WHERE a.' || quote_ident(column_a) + || ' = b.' || quote_ident(column_b); + END IF; + + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; -- 1.7.2.5