Moves new CDB_Unique_Identifier and _CDB_Octet_Trim to CDB_Helper.sql file
This commit is contained in:
parent
5f46ff10e9
commit
5dfe56a664
1
Makefile
1
Makefile
@ -11,6 +11,7 @@ CDBSCRIPTS = \
|
|||||||
scripts-available/CDB_DDLTriggers.sql \
|
scripts-available/CDB_DDLTriggers.sql \
|
||||||
scripts-available/CDB_ExtensionPost.sql \
|
scripts-available/CDB_ExtensionPost.sql \
|
||||||
scripts-available/CDB_ExtensionUtils.sql \
|
scripts-available/CDB_ExtensionUtils.sql \
|
||||||
|
scripts-available/CDB_Helper.sql \
|
||||||
$(END)
|
$(END)
|
||||||
|
|
||||||
UPGRADABLE = \
|
UPGRADABLE = \
|
||||||
|
@ -1,4 +1,5 @@
|
|||||||
-- Depends on:
|
-- Depends on:
|
||||||
|
-- * CDB_Helper.sql
|
||||||
-- * CDB_ExtensionUtils.sql
|
-- * CDB_ExtensionUtils.sql
|
||||||
-- * CDB_TransformToWebmercator.sql
|
-- * CDB_TransformToWebmercator.sql
|
||||||
-- * CDB_TableMetadata.sql
|
-- * CDB_TableMetadata.sql
|
||||||
@ -427,7 +428,7 @@ END;
|
|||||||
$$ LANGUAGE 'plpgsql';
|
$$ LANGUAGE 'plpgsql';
|
||||||
|
|
||||||
|
|
||||||
-- DEPRECATED: Use _CDB_Unique_Identifier since it's UTF8 Safe and length
|
-- DEPRECATED: Use cartodb.CDB_Unique_Identifier since it's UTF8 Safe and length
|
||||||
-- aware. Find a unique relation name in the given schema, starting from the
|
-- aware. Find a unique relation name in the given schema, starting from the
|
||||||
-- template given. If the template is already unique, just return it;
|
-- template given. If the template is already unique, just return it;
|
||||||
-- otherwise, append an increasing integer until you find a unique variant.
|
-- otherwise, append an increasing integer until you find a unique variant.
|
||||||
@ -468,101 +469,8 @@ END;
|
|||||||
$$ LANGUAGE 'plpgsql';
|
$$ LANGUAGE 'plpgsql';
|
||||||
|
|
||||||
|
|
||||||
-- UTF8 safe. Find a unique identifier with a given prefix and/or suffix and withing a schema.
|
-- DEPRECATED: Use cartodb.CDB_Unique_Identifier since it's UTF8 Safe and length
|
||||||
CREATE OR REPLACE FUNCTION _CDB_Unique_Identifier(prefix TEXT, schema TEXT, relname TEXT, suffix TEXT)
|
-- aware. Find a unique column name in the given relation, starting from the
|
||||||
RETURNS TEXT
|
|
||||||
AS $$
|
|
||||||
DECLARE
|
|
||||||
rec RECORD;
|
|
||||||
usedspace INTEGER;
|
|
||||||
identifier TEXT;
|
|
||||||
i INTEGER;
|
|
||||||
originalidentifier 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;
|
|
||||||
|
|
||||||
identifier := COALESCE(prefix, '') || relname || COALESCE(suffix, '');
|
|
||||||
|
|
||||||
i := 0;
|
|
||||||
originalidentifier := identifier;
|
|
||||||
|
|
||||||
WHILE i < 100 LOOP
|
|
||||||
SELECT c.relname, n.nspname
|
|
||||||
INTO rec
|
|
||||||
FROM pg_class c
|
|
||||||
JOIN pg_namespace n ON c.relnamespace = n.oid
|
|
||||||
WHERE c.relname = identifier
|
|
||||||
AND n.nspname = schema;
|
|
||||||
|
|
||||||
IF NOT FOUND THEN
|
|
||||||
RETURN identifier;
|
|
||||||
END IF;
|
|
||||||
|
|
||||||
identifier := originalidentifier || '_' || i;
|
|
||||||
i := i + 1;
|
|
||||||
END LOOP;
|
|
||||||
|
|
||||||
PERFORM _CDB_Error('looping too far', '_CDB_Unique_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.
|
|
||||||
CREATE OR REPLACE FUNCTION _CDB_Octet_Trim(tostrip TEXT, octets INTEGER)
|
|
||||||
RETURNS TEXT
|
|
||||||
AS $$
|
|
||||||
DECLARE
|
|
||||||
expected INTEGER;
|
|
||||||
examined INTEGER;
|
|
||||||
tostriplen INTEGER;
|
|
||||||
charlen INTEGER;
|
|
||||||
|
|
||||||
i INTEGER;
|
|
||||||
tail TEXT;
|
|
||||||
|
|
||||||
trimmed TEXT;
|
|
||||||
BEGIN
|
|
||||||
charlen := bit_length('a');
|
|
||||||
tostriplen := char_length(tostrip);
|
|
||||||
expected := tostriplen * charlen;
|
|
||||||
examined := bit_length(tostrip);
|
|
||||||
|
|
||||||
IF expected = examined OR octets = 0 THEN
|
|
||||||
RETURN SUBSTRING(tostrip from 1 for (tostriplen - octets));
|
|
||||||
ELSIF octets < 0 THEN
|
|
||||||
RETURN tostrip;
|
|
||||||
ELSIF (octets * charlen) > examined THEN
|
|
||||||
RETURN '';
|
|
||||||
END IF;
|
|
||||||
|
|
||||||
i := tostriplen - ((octets - 1) / 2);
|
|
||||||
LOOP
|
|
||||||
tail := SUBSTRING(tostrip from i for tostriplen);
|
|
||||||
|
|
||||||
EXIT WHEN octet_length(tail) >= octets OR i <= 0;
|
|
||||||
|
|
||||||
i := i - 1;
|
|
||||||
END LOOP;
|
|
||||||
|
|
||||||
trimmed := SUBSTRING(tostrip from 1 for (tostriplen - char_length(tail)));
|
|
||||||
RETURN trimmed;
|
|
||||||
END;
|
|
||||||
$$ LANGUAGE 'plpgsql';
|
|
||||||
|
|
||||||
|
|
||||||
-- 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;
|
-- column name given. If the column name is already unique, just return it;
|
||||||
-- otherwise, append an increasing integer until you find a unique variant.
|
-- otherwise, append an increasing integer until you find a unique variant.
|
||||||
CREATE OR REPLACE FUNCTION _CDB_Unique_Column_Name(reloid REGCLASS, columnname TEXT)
|
CREATE OR REPLACE FUNCTION _CDB_Unique_Column_Name(reloid REGCLASS, columnname TEXT)
|
||||||
@ -684,7 +592,7 @@ BEGIN
|
|||||||
PERFORM _CDB_SQL(
|
PERFORM _CDB_SQL(
|
||||||
Format('ALTER TABLE %s RENAME COLUMN %s TO %I',
|
Format('ALTER TABLE %s RENAME COLUMN %s TO %I',
|
||||||
reloid::text, rec.attname,
|
reloid::text, rec.attname,
|
||||||
_CDB_Unique_Column_Name(reloid, const.pkey)),
|
cartodb.CDB_Unique_Identifier(NULL, reloid::text, '_' || const.pkey)),
|
||||||
'_CDB_Has_Usable_Primary_ID');
|
'_CDB_Has_Usable_Primary_ID');
|
||||||
|
|
||||||
END IF;
|
END IF;
|
||||||
@ -701,7 +609,7 @@ BEGIN
|
|||||||
|
|
||||||
PERFORM _CDB_SQL(
|
PERFORM _CDB_SQL(
|
||||||
Format('ALTER TABLE %s RENAME COLUMN %s TO %I',
|
Format('ALTER TABLE %s RENAME COLUMN %s TO %I',
|
||||||
reloid::text, rec.attname, _CDB_Unique_Column_Name(reloid, const.pkey)),
|
reloid::text, rec.attname, cartodb.CDB_Unique_Identifier(NULL, reloid::text, '_' || const.pkey)),
|
||||||
'_CDB_Has_Usable_Primary_ID');
|
'_CDB_Has_Usable_Primary_ID');
|
||||||
|
|
||||||
END IF;
|
END IF;
|
||||||
@ -867,7 +775,7 @@ BEGIN
|
|||||||
WHEN others THEN
|
WHEN others THEN
|
||||||
IF SQLERRM = 'parse error - invalid geometry' THEN
|
IF SQLERRM = 'parse error - invalid geometry' THEN
|
||||||
text_geom_column := false;
|
text_geom_column := false;
|
||||||
str := _CDB_Unique_Column_Name(reloid, r1.attname);
|
str := cartodb.CDB_Unique_Identifier(NULL, reloid::text, '_' || r1.attname);
|
||||||
sql := Format('ALTER TABLE %s RENAME COLUMN %s TO %I', reloid::text, r1.attname, str);
|
sql := Format('ALTER TABLE %s RENAME COLUMN %s TO %I', reloid::text, r1.attname, str);
|
||||||
PERFORM _CDB_SQL(sql,'_CDB_Has_Usable_Geom');
|
PERFORM _CDB_SQL(sql,'_CDB_Has_Usable_Geom');
|
||||||
RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %',
|
RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %',
|
||||||
@ -879,7 +787,7 @@ BEGIN
|
|||||||
|
|
||||||
-- Just change its name so we can write a new column into that name.
|
-- Just change its name so we can write a new column into that name.
|
||||||
ELSE
|
ELSE
|
||||||
str := _CDB_Unique_Column_Name(reloid, r1.attname);
|
str := cartodb.CDB_Unique_Identifier(NULL, reloid::text, '_' || r1.attname);
|
||||||
sql := Format('ALTER TABLE %s RENAME COLUMN %s TO %I', reloid::text, r1.attname, str);
|
sql := Format('ALTER TABLE %s RENAME COLUMN %s TO %I', reloid::text, r1.attname, str);
|
||||||
PERFORM _CDB_SQL(sql,'_CDB_Has_Usable_Geom');
|
PERFORM _CDB_SQL(sql,'_CDB_Has_Usable_Geom');
|
||||||
RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %',
|
RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %',
|
||||||
@ -1056,14 +964,14 @@ BEGIN
|
|||||||
-- Put the primary key sequence in the right schema
|
-- Put the primary key sequence in the right schema
|
||||||
-- If the new table is not moving, better ensure the sequence name
|
-- If the new table is not moving, better ensure the sequence name
|
||||||
-- is unique
|
-- is unique
|
||||||
destseq := _CDB_Unique_Identifier(NULL, destschema, relname, '_' || const.pkey || '_seq');
|
destseq := cartodb.CDB_Unique_Identifier(NULL, relname, '_' || const.pkey || '_seq', destschema);
|
||||||
destseq := Format('%I.%I', destschema, destseq);
|
destseq := Format('%I.%I', destschema, destseq);
|
||||||
PERFORM _CDB_SQL(Format('CREATE SEQUENCE %s', destseq), '_CDB_Rewrite_Table');
|
PERFORM _CDB_SQL(Format('CREATE SEQUENCE %s', destseq), '_CDB_Rewrite_Table');
|
||||||
|
|
||||||
-- Salt a temporary table name if we are re-writing in place
|
-- Salt a temporary table name if we are re-writing in place
|
||||||
-- Note copyname is already escaped and safe to use as identifier
|
-- Note copyname is already escaped and safe to use as identifier
|
||||||
IF destschema = relschema THEN
|
IF destschema = relschema THEN
|
||||||
copyname := Format('%I.%I', destschema, _CDB_Unique_Identifier(NULL, destschema, destname, '_' || salt));
|
copyname := Format('%I.%I', destschema, cartodb.CDB_Unique_Identifier(NULL, destname, '_' || salt), destschema);
|
||||||
ELSE
|
ELSE
|
||||||
copyname := Format('%I.%I', destschema, destname);
|
copyname := Format('%I.%I', destschema, destname);
|
||||||
END IF;
|
END IF;
|
||||||
|
102
scripts-available/CDB_Helper.sql
Normal file
102
scripts-available/CDB_Helper.sql
Normal file
@ -0,0 +1,102 @@
|
|||||||
|
-- UTF8 safe and lenght aware. Find a unique identifier with a given prefix
|
||||||
|
-- and/or suffix and withing a schema.
|
||||||
|
CREATE OR REPLACE FUNCTION cartodb.CDB_Unique_Identifier(prefix TEXT, relname TEXT, suffix TEXT, schema TEXT 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 schema IS NOT NULL THEN
|
||||||
|
SELECT c.relname, n.nspname
|
||||||
|
INTO rec
|
||||||
|
FROM pg_class c
|
||||||
|
JOIN pg_namespace n ON c.relnamespace = n.oid
|
||||||
|
WHERE c.relname = ident
|
||||||
|
AND n.nspname = schema;
|
||||||
|
ELSE
|
||||||
|
SELECT c.relname, n.nspname
|
||||||
|
INTO rec
|
||||||
|
FROM pg_class c
|
||||||
|
JOIN pg_namespace n ON c.relnamespace = n.oid
|
||||||
|
WHERE c.relname = 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_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.
|
||||||
|
CREATE OR REPLACE FUNCTION cartodb.CDB_Octet_Trim(tostrip TEXT, octets INTEGER)
|
||||||
|
RETURNS TEXT
|
||||||
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
expected INTEGER;
|
||||||
|
examined INTEGER;
|
||||||
|
tostriplen INTEGER;
|
||||||
|
charlen INTEGER;
|
||||||
|
|
||||||
|
i INTEGER;
|
||||||
|
tail TEXT;
|
||||||
|
|
||||||
|
trimmed TEXT;
|
||||||
|
BEGIN
|
||||||
|
charlen := bit_length('a');
|
||||||
|
tostriplen := char_length(tostrip);
|
||||||
|
expected := tostriplen * charlen;
|
||||||
|
examined := bit_length(tostrip);
|
||||||
|
|
||||||
|
IF expected = examined OR octets = 0 THEN
|
||||||
|
RETURN SUBSTRING(tostrip from 1 for (tostriplen - octets));
|
||||||
|
ELSIF octets < 0 THEN
|
||||||
|
RETURN tostrip;
|
||||||
|
ELSIF (octets * charlen) > examined THEN
|
||||||
|
RETURN '';
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
i := tostriplen - ((octets - 1) / 2);
|
||||||
|
LOOP
|
||||||
|
tail := SUBSTRING(tostrip from i for tostriplen);
|
||||||
|
|
||||||
|
EXIT WHEN octet_length(tail) >= octets OR i <= 0;
|
||||||
|
|
||||||
|
i := i - 1;
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
trimmed := SUBSTRING(tostrip from 1 for (tostriplen - char_length(tail)));
|
||||||
|
RETURN trimmed;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE 'plpgsql';
|
||||||
|
|
Loading…
Reference in New Issue
Block a user