From d25847fe178bf9fabbd1846cafb6d90abe63f971 Mon Sep 17 00:00:00 2001 From: Rogan Hamby Date: Mon, 13 Aug 2018 15:27:54 -0400 Subject: [PATCH] added function to trim and null out all columns, useful when importing from reports --- sql/base/base.sql | 39 +++++++++++++++++++++++++++++++++++++++ 1 files changed, 39 insertions(+), 0 deletions(-) diff --git a/sql/base/base.sql b/sql/base/base.sql index a333a1b..8683362 100644 --- a/sql/base/base.sql +++ b/sql/base/base.sql @@ -4075,6 +4075,26 @@ BEGIN END $function$; +DROP FUNCTION IF EXISTS migration_tools.btrim_columns(TEXT,TEXT); +CREATE OR REPLACE FUNCTION migration_tools.btrim_columns(s_name TEXT, t_name TEXT) RETURNS BOOLEAN + LANGUAGE plpgsql +AS $function$ +DECLARE + c_name TEXT; +BEGIN + + FOR c_name IN SELECT column_name FROM information_schema.columns WHERE + table_name = t_name + AND table_schema = s_name + AND (data_type='text' OR data_type='character varying') + LOOP + EXECUTE FORMAT('UPDATE ' || s_name || '.' || t_name || ' SET ' || c_name || ' = BTRIM(' || c_name || ')'); + END LOOP; + + RETURN TRUE; +END +$function$; + DROP FUNCTION IF EXISTS migration_tools.null_empty_lcolumns(TEXT,TEXT); CREATE OR REPLACE FUNCTION migration_tools.null_empty_lcolumns(s_name TEXT, t_name TEXT) RETURNS BOOLEAN LANGUAGE plpgsql @@ -4096,3 +4116,22 @@ BEGIN END $function$; +DROP FUNCTION IF EXISTS migration_tools.null_empty_columns(TEXT,TEXT); +CREATE OR REPLACE FUNCTION migration_tools.null_empty_columns(s_name TEXT, t_name TEXT) RETURNS BOOLEAN + LANGUAGE plpgsql +AS $function$ +DECLARE + c_name TEXT; +BEGIN + + FOR c_name IN SELECT column_name FROM information_schema.columns WHERE + table_name = t_name + AND table_schema = s_name + AND (data_type='text' OR data_type='character varying') + LOOP + EXECUTE FORMAT('UPDATE ' || s_name || '.' || t_name || ' SET ' || c_name || ' = NULL WHERE ' || c_name || ' = '''' '); + END LOOP; + + RETURN TRUE; +END +$function$; -- 1.7.2.5