From 8479c3375bab35d9b450f38488fba0a04fce70d7 Mon Sep 17 00:00:00 2001 From: Guido Fioravantti Date: Thu, 22 Oct 2015 17:01:47 +0200 Subject: [PATCH] Adds CDB_Unique_Column_Identifier for columns 173 --- scripts-available/CDB_CartodbfyTable.sql | 10 +- scripts-available/CDB_Helper.sql | 65 ++++++++++++- test/CDB_HelperTest_expected | 113 ++++------------------- 3 files changed, 87 insertions(+), 101 deletions(-) diff --git a/scripts-available/CDB_CartodbfyTable.sql b/scripts-available/CDB_CartodbfyTable.sql index ace030b..b468928 100644 --- a/scripts-available/CDB_CartodbfyTable.sql +++ b/scripts-available/CDB_CartodbfyTable.sql @@ -469,7 +469,7 @@ END; $$ LANGUAGE 'plpgsql'; --- DEPRECATED: Use cartodb.CDB_Unique_Identifier since it's UTF8 Safe and length +-- DEPRECATED: Use cartodb.CDB_Unique_Column_Identifier since it's UTF8 Safe and length -- aware. Find a unique column name in the given relation, starting from the -- column name given. If the column name is already unique, just return it; -- otherwise, append an increasing integer until you find a unique variant. @@ -592,7 +592,7 @@ BEGIN PERFORM _CDB_SQL( Format('ALTER TABLE %s RENAME COLUMN %s TO %I', reloid::text, rec.attname, - cartodb.CDB_Unique_Identifier(NULL, reloid::text, '_' || const.pkey)), + cartodb.CDB_Unique_Column_Identifier(NULL, const.pkey, NULL, reloid)), '_CDB_Has_Usable_Primary_ID'); END IF; @@ -609,7 +609,7 @@ BEGIN PERFORM _CDB_SQL( Format('ALTER TABLE %s RENAME COLUMN %s TO %I', - reloid::text, rec.attname, cartodb.CDB_Unique_Identifier(NULL, reloid::text, '_' || const.pkey)), + reloid::text, rec.attname, cartodb.CDB_Unique_Column_Identifier(NULL, const.pkey, NULL, reloid)), '_CDB_Has_Usable_Primary_ID'); END IF; @@ -775,7 +775,7 @@ BEGIN WHEN others THEN IF SQLERRM = 'parse error - invalid geometry' THEN text_geom_column := false; - str := cartodb.CDB_Unique_Identifier(NULL, reloid::text, '_' || r1.attname); + str := cartodb.CDB_Unique_Column_Identifier(NULL, r1.attname, NULL, reloid); sql := Format('ALTER TABLE %s RENAME COLUMN %s TO %I', reloid::text, r1.attname, str); PERFORM _CDB_SQL(sql,'_CDB_Has_Usable_Geom'); RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', @@ -787,7 +787,7 @@ BEGIN -- Just change its name so we can write a new column into that name. ELSE - str := cartodb.CDB_Unique_Identifier(NULL, reloid::text, '_' || r1.attname); + str := cartodb.CDB_Unique_Column_Identifier(NULL, r1.attname, NULL, reloid); sql := Format('ALTER TABLE %s RENAME COLUMN %s TO %I', reloid::text, r1.attname, str); PERFORM _CDB_SQL(sql,'_CDB_Has_Usable_Geom'); RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', diff --git a/scripts-available/CDB_Helper.sql b/scripts-available/CDB_Helper.sql index 013f3ad..687d6cf 100644 --- a/scripts-available/CDB_Helper.sql +++ b/scripts-available/CDB_Helper.sql @@ -20,7 +20,7 @@ BEGIN relname := CDB_Octet_Trim(relname, usedspace + octet_length(relname) - maxlen); IF relname = '' THEN - PERFORM _CDB_Error('prefixes are to long to generate a valid identifier', '_CDB_Unique_Identifier'); + PERFORM _CDB_Error('prefixes are to long to generate a valid identifier', 'CDB_Unique_Identifier'); END IF; ident := coalesce(prefix, '') || relname || coalesce(suffix, ''); @@ -52,10 +52,71 @@ BEGIN i := i + 1; END LOOP; - PERFORM _CDB_Error('looping too far', '_CDB_Unique_Identifier'); + PERFORM _CDB_Error('looping too far', 'CDB_Unique_Identifier'); END; $$ LANGUAGE 'plpgsql'; +-- UTF8 safe and lenght aware. Find a unique identifier for a column with a given prefix +-- and/or suffix and withing a realtion. If no reloid is give, all relations are examined +CREATE OR REPLACE FUNCTION cartodb.CDB_Unique_Column_Identifier(prefix TEXT, relname TEXT, suffix TEXT, reloid REGCLASS DEFAULT NULL) +RETURNS TEXT +AS $$ +DECLARE + rec RECORD; + usedspace INTEGER; + ident TEXT; + i INTEGER; + origident TEXT; + maxlen INTEGER; +BEGIN + maxlen := 63; + + usedspace := 3; + usedspace := usedspace + coalesce(octet_length(prefix), 0); + usedspace := usedspace + coalesce(octet_length(suffix), 0); + + relname := CDB_Octet_Trim(relname, usedspace + octet_length(relname) - maxlen); + + IF relname = '' THEN + PERFORM _CDB_Error('prefixes are to long to generate a valid identifier', 'CDB_Unique_Identifier'); + END IF; + + ident := coalesce(prefix, '') || relname || coalesce(suffix, ''); + + i := 0; + origident := ident; + + WHILE i < 100 LOOP + IF reloid IS NOT NULL THEN + SELECT a.attname + INTO rec + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + WHERE NOT a.attisdropped + AND a.attnum > 0 + AND c.oid = reloid + AND a.attname = ident; + ELSE + SELECT a.attname + INTO rec + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + WHERE NOT a.attisdropped + AND a.attnum > 0 + AND a.attname = ident; + END IF; + + IF NOT FOUND THEN + RETURN ident; + END IF; + + ident := origident || '_' || i; + i := i + 1; + END LOOP; + + PERFORM _CDB_Error('looping too far', 'CDB_Unique_Column_Identifier'); +END; +$$ LANGUAGE 'plpgsql'; -- Trims the end of a given string by the given number of octets taking care -- not to leave characters in half. UTF8 safe. diff --git a/test/CDB_HelperTest_expected b/test/CDB_HelperTest_expected index 885a831..acea935 100644 --- a/test/CDB_HelperTest_expected +++ b/test/CDB_HelperTest_expected @@ -1,102 +1,27 @@ - cdb_unique_identifier ------------------------ - relname -(1 row) - - cdb_unique_identifier ------------------------ - prefix_relname -(1 row) - - cdb_unique_identifier ------------------------ - relname_suffix -(1 row) - - cdb_unique_identifier --------------------------------------------------------------- - largolargolargolargolargolargolargolargolargolargolargolargo -(1 row) - - cdb_unique_identifier --------------------------------------------------------------- - prefix_largolargolargolargolargolargolargolargolargolargolar -(1 row) - +relname +prefix_relname +relname_suffix +largolargolargolargolargolargolargolargolargolargolargolargo +prefix_largolargolargolargolargolargolargolargolargolargolar CREATE TABLE - cdb_unique_identifier ----------------------------------------------------------------- - prefix_largolargolargolargolargolargolargolargolargolargolar_0 -(1 row) - +prefix_largolargolargolargolargolargolargolargolargolargolar_0 DROP TABLE - cdb_unique_identifier --------------------------------------------------------------- - largolargolargolargolargolargolargolargolargolargolar_suffix -(1 row) - +largolargolargolargolargolargolargolargolargolargolar_suffix CREATE TABLE - cdb_unique_identifier ----------------------------------------------------------------- - largolargolargolargolargolargolargolargolargolargolar_suffix_0 -(1 row) - +largolargolargolargolargolargolargolargolargolargolar_suffix_0 DROP TABLE - cdb_unique_identifier ------------------------ - piraña -(1 row) - - cdb_unique_identifier ------------------------ - prefix_piraña -(1 row) - - cdb_unique_identifier ------------------------ - piraña_suffix -(1 row) - - cdb_unique_identifier --------------------------------------------------- - piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpiñaácid -(1 row) - - cdb_unique_identifier ---------------------------------------------------- - prefix_piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi -(1 row) - +piraña +prefix_piraña +piraña_suffix +piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpiñaácid +prefix_piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi CREATE TABLE - cdb_unique_identifier ------------------------------------------------------ - prefix_piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_0 -(1 row) - +prefix_piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_0 DROP TABLE - cdb_unique_identifier ---------------------------------------------------- - piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_suffix -(1 row) - +piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_suffix CREATE TABLE - cdb_unique_identifier ------------------------------------------------------ - piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_suffix_0 -(1 row) - +piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_suffix_0 DROP TABLE - cdb_octet_trim ----------------- - pirañ -(1 row) - - cdb_octet_trim ----------------- - pira -(1 row) - - cdb_octet_trim ----------------- - pira -(1 row) +pirañ +pira +pira