From 55a77b0ef0a75292803640911c2bb71ddc4d010b Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Tue, 3 Jul 2018 13:00:24 +0200 Subject: [PATCH 1/5] Add a new helper function _CDB_Table_Exists --- Makefile | 3 ++- scripts-available/CDB_Helper.sql | 18 ++++++++++++++++++ test/CDB_HelperTest.sql | 10 ++++++++++ test/CDB_HelperTest_expect | 8 ++++++++ 4 files changed, 38 insertions(+), 1 deletion(-) diff --git a/Makefile b/Makefile index d72f7cc..f0925e7 100644 --- a/Makefile +++ b/Makefile @@ -1,7 +1,7 @@ # cartodb/Makefile EXTENSION = cartodb -EXTVERSION = 0.22.2 +EXTVERSION = 0.22.3 SED = sed AWK = awk @@ -88,6 +88,7 @@ UPGRADABLE = \ 0.22.0 \ 0.22.1 \ 0.22.2 \ + 0.22.3 \ $(EXTVERSION)dev \ $(EXTVERSION)next \ $(END) diff --git a/scripts-available/CDB_Helper.sql b/scripts-available/CDB_Helper.sql index 2732ac9..8d3c663 100644 --- a/scripts-available/CDB_Helper.sql +++ b/scripts-available/CDB_Helper.sql @@ -158,3 +158,21 @@ BEGIN RETURN left(string, (i - 1)); END; $$ LANGUAGE 'plpgsql' IMMUTABLE PARALLEL SAFE; + + +-- Checks if a given text representing a qualified or unqualified table name (relation) +-- actually exists in the database. It is meant to be used as a guard for other function/queries. +CREATE FUNCTION cartodb._CDB_Table_Exists(table_name_with_optional_schema TEXT) +RETURNS bool +AS $$ +BEGIN + IF EXISTS(SELECT * FROM pg_class WHERE table_name_with_optional_schema::regclass::oid = oid AND relkind = 'r') THEN + RETURN true; + ELSE + RETURN false; + END IF; +EXCEPTION + WHEN invalid_schema_name OR undefined_table THEN + RETURN false; +END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL SAFE; diff --git a/test/CDB_HelperTest.sql b/test/CDB_HelperTest.sql index ac543f5..f33c2c7 100644 --- a/test/CDB_HelperTest.sql +++ b/test/CDB_HelperTest.sql @@ -126,3 +126,13 @@ SELECT * FROM cartodb._CDB_Octet_Truncate('piraña', 6); -- Test _CDB_Octet_Truncate UTF8 case SELECT * FROM cartodb._CDB_Octet_Truncate('piraña', 7); + +-- Test _CDB_Table_Exists +CREATE TABLE public.this_table_exists(); +SELECT cartodb._CDB_Table_Exists('this_table_does_not_exist'); +SELECT cartodb._CDB_Table_Exists('this_schema_does_not_exist.this_table_does_not_exist'); +SELECT cartodb._CDB_Table_Exists('this_table_exists'); +SELECT cartodb._CDB_Table_Exists('public.this_table_exists'); +SELECT cartodb._CDB_Table_Exists('raster_overviews'); -- view created by postgis +SELECT cartodb._CDB_Table_Exists('public.raster_overviews'); +DROP TABLE public.this_table_exists diff --git a/test/CDB_HelperTest_expect b/test/CDB_HelperTest_expect index 10a8d48..5ef82e5 100644 --- a/test/CDB_HelperTest_expect +++ b/test/CDB_HelperTest_expect @@ -57,3 +57,11 @@ DROP TABLE pira pirañ piraña +CREATE TABLE +f +f +t +t +f +f +DROP TABLE From 82f90e618c7ca1af815119ad1534cb7d33469f52 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Tue, 3 Jul 2018 13:04:39 +0200 Subject: [PATCH 2/5] Use CREATE OR REPLACE FUNCTION --- scripts-available/CDB_Helper.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/scripts-available/CDB_Helper.sql b/scripts-available/CDB_Helper.sql index 8d3c663..55f5f19 100644 --- a/scripts-available/CDB_Helper.sql +++ b/scripts-available/CDB_Helper.sql @@ -162,7 +162,7 @@ $$ LANGUAGE 'plpgsql' IMMUTABLE PARALLEL SAFE; -- Checks if a given text representing a qualified or unqualified table name (relation) -- actually exists in the database. It is meant to be used as a guard for other function/queries. -CREATE FUNCTION cartodb._CDB_Table_Exists(table_name_with_optional_schema TEXT) +CREATE OR REPLACE FUNCTION cartodb._CDB_Table_Exists(table_name_with_optional_schema TEXT) RETURNS bool AS $$ BEGIN From 7437a9686b33c46224bc6ea9614ef9199c3b38c9 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Tue, 3 Jul 2018 15:08:34 +0200 Subject: [PATCH 3/5] Use a more suitable version number 0.23.0 & NEWS Use a better version number (as it adds a new function) and update NEWS.md accordingly. --- Makefile | 4 ++-- NEWS.md | 3 +++ 2 files changed, 5 insertions(+), 2 deletions(-) diff --git a/Makefile b/Makefile index f0925e7..6236c62 100644 --- a/Makefile +++ b/Makefile @@ -1,7 +1,7 @@ # cartodb/Makefile EXTENSION = cartodb -EXTVERSION = 0.22.3 +EXTVERSION = 0.23.0 SED = sed AWK = awk @@ -88,7 +88,7 @@ UPGRADABLE = \ 0.22.0 \ 0.22.1 \ 0.22.2 \ - 0.22.3 \ + 0.23.0 \ $(EXTVERSION)dev \ $(EXTVERSION)next \ $(END) diff --git a/NEWS.md b/NEWS.md index 989ee51..0b26f55 100644 --- a/NEWS.md +++ b/NEWS.md @@ -1,3 +1,6 @@ +0.23.0 (2018-07-03) +* Add a new helper function `_CDB_Table_Exists(table_name_with_optional_schema TEXT)` #332 + 0.22.2 (2018-05-29) * Fix: Fix hyphenates usernames in 0.22.1 fix (#331) From af142306aa32731f694856cff7f5b9839a95b72d Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Tue, 3 Jul 2018 15:26:48 +0200 Subject: [PATCH 4/5] Mark `_CDB_Table_Exists()` as PARALLEL UNSAFE As pointed out by Algunenano, PL/pgSQL function which establishes an EXCEPTION block to catch errors must be qualified with it. --- scripts-available/CDB_Helper.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/scripts-available/CDB_Helper.sql b/scripts-available/CDB_Helper.sql index 55f5f19..f582308 100644 --- a/scripts-available/CDB_Helper.sql +++ b/scripts-available/CDB_Helper.sql @@ -175,4 +175,4 @@ EXCEPTION WHEN invalid_schema_name OR undefined_table THEN RETURN false; END; -$$ LANGUAGE PLPGSQL VOLATILE PARALLEL SAFE; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; From 61d2024eb556651c644b6922593f39bbb545d9eb Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Tue, 3 Jul 2018 15:35:05 +0200 Subject: [PATCH 5/5] Make the code nicer by avoiding IF/THEN/ELSE As suggested by Algunenano. --- scripts-available/CDB_Helper.sql | 9 ++++----- 1 file changed, 4 insertions(+), 5 deletions(-) diff --git a/scripts-available/CDB_Helper.sql b/scripts-available/CDB_Helper.sql index f582308..00ef341 100644 --- a/scripts-available/CDB_Helper.sql +++ b/scripts-available/CDB_Helper.sql @@ -165,12 +165,11 @@ $$ LANGUAGE 'plpgsql' IMMUTABLE PARALLEL SAFE; CREATE OR REPLACE FUNCTION cartodb._CDB_Table_Exists(table_name_with_optional_schema TEXT) RETURNS bool AS $$ +DECLARE + table_exists bool := false; BEGIN - IF EXISTS(SELECT * FROM pg_class WHERE table_name_with_optional_schema::regclass::oid = oid AND relkind = 'r') THEN - RETURN true; - ELSE - RETURN false; - END IF; + table_exists := EXISTS(SELECT * FROM pg_class WHERE table_name_with_optional_schema::regclass::oid = oid AND relkind = 'r'); + RETURN table_exists; EXCEPTION WHEN invalid_schema_name OR undefined_table THEN RETURN false;