CDB_GetTableQueries: Add function to extract queries associated to a table
This commit is contained in:
parent
c9ae99e4a7
commit
bb1c644f5b
3
NEWS.md
3
NEWS.md
@ -1,6 +1,7 @@
|
||||
0.37.0 (XXXX-XX-XX)
|
||||
* Raised minimum PG version to 11.
|
||||
* Add `CDB_RegenerateTable` to regenerate a table.
|
||||
* Add `CDB_RegenerateTable` function to regenerate a table.
|
||||
* Add `CDB_GetTableQueries` to get the queries of a table (constraints, indices, triggers...).
|
||||
* Deprecate creation of new overview tables.
|
||||
|
||||
0.36.0 (2020-02-13)
|
||||
|
@ -48,6 +48,50 @@ AS $$
|
||||
$$
|
||||
LANGUAGE @@plpythonu@@ VOLATILE PARALLEL UNSAFE;
|
||||
|
||||
-- Returns a list of queries that can be used to regenerate the structure of a table
|
||||
-- The query to create the table and the config set by pg_dump are removed
|
||||
-- The optional parameter **ignore_cartodbfication** will remove queries related to the cartodbfication of the table
|
||||
CREATE OR REPLACE FUNCTION @extschema@.CDB_GetTableQueries(tableoid OID, ignore_cartodbfication BOOL DEFAULT false)
|
||||
RETURNS text[]
|
||||
AS
|
||||
$$
|
||||
DECLARE
|
||||
children INTEGER;
|
||||
queries TEXT[];
|
||||
BEGIN
|
||||
EXECUTE FORMAT ('SELECT count(*) FROM pg_catalog.pg_inherits WHERE inhparent = %L', tableoid)
|
||||
INTO children;
|
||||
IF children > 0 THEN
|
||||
RAISE EXCEPTION 'CDB_GetTableQueries does not support the parent of partitioned tables';
|
||||
END IF;
|
||||
IF NOT ignore_cartodbfication THEN
|
||||
EXECUTE FORMAT('
|
||||
SELECT array_agg(a)
|
||||
FROM unnest(@extschema@.__CDB_RegenerateTable_Get_Commands(%L)) a
|
||||
WHERE a NOT SIMILAR TO ''CREATE TABLE%%'' AND
|
||||
a NOT SIMILAR TO ''SET%%'' AND
|
||||
a NOT SIMILAR TO (''%%pg_catalog.set_config%%'');', tableoid) INTO queries;
|
||||
ELSE
|
||||
EXECUTE FORMAT('
|
||||
SELECT array_agg(a)
|
||||
FROM unnest(@extschema@.__CDB_RegenerateTable_Get_Commands(%L)) a
|
||||
WHERE a NOT SIMILAR TO ''CREATE TABLE%%'' AND
|
||||
a NOT SIMILAR TO ''SET%%'' AND
|
||||
a NOT SIMILAR TO (''%%pg_catalog.set_config%%'') AND
|
||||
a NOT SIMILAR TO (''%%PRIMARY KEY \(cartodb_id\)%%'') AND
|
||||
a NOT SIMILAR TO (''%%cartodb_id_seq%%'') AND
|
||||
a NOT SIMILAR TO (''%%track_updates%%'') AND
|
||||
a NOT SIMILAR TO (''%%update_the_geom_webmercator_trigger%%'') AND
|
||||
a NOT SIMILAR TO (''%%test_quota%%'') AND
|
||||
a NOT SIMILAR TO (''%%test_quota_per_row%%'') AND
|
||||
a NOT SIMILAR TO (''%%gist \(the_geom\)%%'') AND
|
||||
a NOT SIMILAR TO (''%%gist \(the_geom_webmercator\)%%'');', tableoid) INTO queries;
|
||||
END IF;
|
||||
RETURN queries;
|
||||
END
|
||||
$$
|
||||
LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE;
|
||||
|
||||
-- Regenerates a table
|
||||
CREATE OR REPLACE FUNCTION @extschema@.CDB_RegenerateTable(tableoid OID)
|
||||
RETURNS void
|
||||
|
@ -79,8 +79,14 @@ ORDER BY table_schema,
|
||||
trigger_name;
|
||||
|
||||
\echo '## Check Cartodbfycation'
|
||||
DROP INDEX testtable_stable_idx;
|
||||
DROP TRIGGER testtable_trigger_example ON testtable;
|
||||
SELECT cartodb.CDB_GetTableQueries('testtable'::regclass::oid, ignore_cartodbfication := false);
|
||||
SELECT cartodb.CDB_GetTableQueries('testtable'::regclass::oid, ignore_cartodbfication := true);
|
||||
SELECT CDB_SetUserQuotaInBytes(0);
|
||||
SELECT CDB_CartodbfyTable('testtable'::regclass);
|
||||
SELECT cartodb.CDB_GetTableQueries('testtable'::regclass::oid, ignore_cartodbfication := false);
|
||||
SELECT cartodb.CDB_GetTableQueries('testtable'::regclass::oid, ignore_cartodbfication := true);
|
||||
\d+ testtable
|
||||
SELECT tablename, indexname, indexdef FROM pg_indexes WHERE tablename = 'testtable' ORDER BY tablename, indexname;
|
||||
SELECT event_object_schema as table_schema,
|
||||
@ -96,6 +102,9 @@ ORDER BY table_schema,
|
||||
|
||||
SELECT cartodb.CDB_RegenerateTable('testtable'::regclass::oid);
|
||||
|
||||
SELECT cartodb.CDB_GetTableQueries('testtable'::regclass::oid, ignore_cartodbfication := false);
|
||||
SELECT cartodb.CDB_GetTableQueries('testtable'::regclass::oid, ignore_cartodbfication := true);
|
||||
|
||||
\d+ testtable
|
||||
SELECT tablename, indexname, indexdef FROM pg_indexes WHERE tablename = 'testtable' ORDER BY tablename, indexname;
|
||||
SELECT event_object_schema as table_schema,
|
||||
@ -185,6 +194,8 @@ ORDER BY pg_catalog.pg_get_expr(c.relpartbound, c.oid) = 'DEFAULT', c.oid::pg_ca
|
||||
\d measurement_y2006m02
|
||||
\d measurement_y2006m03
|
||||
|
||||
SELECT cartodb.CDB_GetTableQueries('measurement'::regclass::oid, ignore_cartodbfication := false);
|
||||
|
||||
\echo '## teardown'
|
||||
|
||||
DROP TABLE measurement CASCADE;
|
||||
|
@ -53,8 +53,14 @@ public|testtable|public|testtable_trigger_example
|
||||
|
||||
public|testtable|public|testtable_trigger_example
|
||||
## Check Cartodbfycation
|
||||
DROP INDEX
|
||||
DROP TRIGGER
|
||||
{"ALTER TABLE public.testtable OWNER TO postgres","ALTER TABLE ONLY public.testtable ADD CONSTRAINT testtable_c2_key UNIQUE (c2)"}
|
||||
{"ALTER TABLE public.testtable OWNER TO postgres","ALTER TABLE ONLY public.testtable ADD CONSTRAINT testtable_c2_key UNIQUE (c2)"}
|
||||
0
|
||||
testtable
|
||||
{"ALTER TABLE public.testtable OWNER TO postgres","CREATE SEQUENCE public.testtable_cartodb_id_seq START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1","ALTER TABLE public.testtable_cartodb_id_seq OWNER TO postgres","ALTER SEQUENCE public.testtable_cartodb_id_seq OWNED BY public.testtable.cartodb_id","ALTER TABLE ONLY public.testtable ALTER COLUMN cartodb_id SET DEFAULT nextval('public.testtable_cartodb_id_seq'::regclass)","ALTER TABLE ONLY public.testtable ADD CONSTRAINT testtable_pkey PRIMARY KEY (cartodb_id)","CREATE INDEX testtable_the_geom_idx ON public.testtable USING gist (the_geom)","CREATE INDEX testtable_the_geom_webmercator_idx ON public.testtable USING gist (the_geom_webmercator)","CREATE TRIGGER test_quota BEFORE INSERT OR UPDATE ON public.testtable FOR EACH STATEMENT EXECUTE FUNCTION cartodb.cdb_checkquota('0.1', '-1', 'public')","CREATE TRIGGER test_quota_per_row BEFORE INSERT OR UPDATE ON public.testtable FOR EACH ROW EXECUTE FUNCTION cartodb.cdb_checkquota('0.001', '-1', 'public')","CREATE TRIGGER track_updates AFTER INSERT OR DELETE OR UPDATE OR TRUNCATE ON public.testtable FOR EACH STATEMENT EXECUTE FUNCTION cartodb.cdb_tablemetadata_trigger()","CREATE TRIGGER update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON public.testtable FOR EACH ROW EXECUTE FUNCTION cartodb._cdb_update_the_geom_webmercator()"}
|
||||
{"ALTER TABLE public.testtable OWNER TO postgres"}
|
||||
cartodb_id|bigint||not null|nextval('testtable_cartodb_id_seq'::regclass)|plain||
|
||||
the_geom|geometry(Geometry,4326)||||main||
|
||||
the_geom_webmercator|geometry(Geometry,3857)||||main||
|
||||
@ -71,6 +77,8 @@ public|testtable|public|test_quota_per_row
|
||||
public|testtable|public|track_updates
|
||||
public|testtable|public|update_the_geom_webmercator_trigger
|
||||
|
||||
{"ALTER TABLE public.testtable OWNER TO postgres","CREATE SEQUENCE public.testtable_cartodb_id_seq START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1","ALTER TABLE public.testtable_cartodb_id_seq OWNER TO postgres","ALTER SEQUENCE public.testtable_cartodb_id_seq OWNED BY public.testtable.cartodb_id","ALTER TABLE ONLY public.testtable ALTER COLUMN cartodb_id SET DEFAULT nextval('public.testtable_cartodb_id_seq'::regclass)","ALTER TABLE ONLY public.testtable ADD CONSTRAINT testtable_pkey PRIMARY KEY (cartodb_id)","CREATE INDEX testtable_the_geom_idx ON public.testtable USING gist (the_geom)","CREATE INDEX testtable_the_geom_webmercator_idx ON public.testtable USING gist (the_geom_webmercator)","CREATE TRIGGER test_quota BEFORE INSERT OR UPDATE ON public.testtable FOR EACH STATEMENT EXECUTE FUNCTION cartodb.cdb_checkquota('0.1', '-1', 'public')","CREATE TRIGGER test_quota_per_row BEFORE INSERT OR UPDATE ON public.testtable FOR EACH ROW EXECUTE FUNCTION cartodb.cdb_checkquota('0.001', '-1', 'public')","CREATE TRIGGER track_updates AFTER INSERT OR DELETE OR UPDATE OR TRUNCATE ON public.testtable FOR EACH STATEMENT EXECUTE FUNCTION cartodb.cdb_tablemetadata_trigger()","CREATE TRIGGER update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON public.testtable FOR EACH ROW EXECUTE FUNCTION cartodb._cdb_update_the_geom_webmercator()"}
|
||||
{"ALTER TABLE public.testtable OWNER TO postgres"}
|
||||
cartodb_id|bigint||not null|nextval('testtable_cartodb_id_seq'::regclass)|plain||
|
||||
the_geom|geometry(Geometry,4326)||||main||
|
||||
the_geom_webmercator|geometry(Geometry,3857)||||main||
|
||||
@ -168,6 +176,7 @@ city_id|integer||not null|
|
||||
logdate|date||not null|
|
||||
peaktemp|integer|||
|
||||
unitsales|integer|||
|
||||
ERROR: CDB_GetTableQueries does not support the parent of partitioned tables
|
||||
## teardown
|
||||
DROP TABLE
|
||||
DROP TABLE
|
||||
|
Loading…
Reference in New Issue
Block a user