cartodb-postgresql/scripts-available/CDB_QueryTables.sql

76 lines
2.2 KiB
MySQL
Raw Normal View History

-- Return an array of table names scanned by a given query
--
-- Requires PostgreSQL 9.x+
--
2019-05-31 21:29:28 +08:00
CREATE OR REPLACE FUNCTION @extschema@.CDB_QueryTablesText(query text)
RETURNS text[]
AS $$
DECLARE
exp XML;
tables text[];
rec RECORD;
rec2 RECORD;
BEGIN
tables := '{}';
2019-05-31 21:29:28 +08:00
FOR rec IN SELECT @extschema@.CDB_QueryStatements(query) q LOOP
BEGIN
EXECUTE 'EXPLAIN (FORMAT XML, VERBOSE) ' || rec.q INTO STRICT exp;
EXCEPTION WHEN syntax_error THEN
-- We can get a syntax error if the user tries to EXPLAIN a DDL
CONTINUE;
WHEN others THEN
-- TODO: if error is 'relation "xxxxxx" does not exist', take xxxxxx as
-- the affected table ?
RAISE WARNING 'CDB_QueryTables cannot explain query: % (%: %)', rec.q, SQLSTATE, SQLERRM;
RAISE EXCEPTION '%', SQLERRM;
CONTINUE;
END;
-- Now need to extract all values of <Relation-Name>
-- RAISE DEBUG 'Explain: %', exp;
FOR rec2 IN WITH
inp AS (
SELECT
xpath('//x:Relation-Name/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as x,
xpath('//x:Relation-Name/../x:Schema/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as s
)
SELECT unnest(x)::text as p, unnest(s)::text as sc from inp
LOOP
-- RAISE DEBUG 'tab: %', rec2.p;
-- RAISE DEBUG 'sc: %', rec2.sc;
tables := array_append(tables, format('%s.%s', quote_ident(rec2.sc), quote_ident(rec2.p)));
END LOOP;
-- RAISE DEBUG 'Tables: %', tables;
END LOOP;
-- RAISE DEBUG 'Tables: %', tables;
-- Remove duplicates and sort by name
IF array_upper(tables, 1) > 0 THEN
WITH dist as ( SELECT DISTINCT unnest(tables)::text as p ORDER BY p )
SELECT array_agg(p) from dist into tables;
END IF;
--RAISE DEBUG 'Tables: %', tables;
return tables;
END
2017-10-24 20:16:56 +08:00
$$ LANGUAGE 'plpgsql' VOLATILE STRICT PARALLEL UNSAFE;
-- Keep CDB_QueryTables with same signature for backwards compatibility.
-- It should probably be removed in the future.
2019-05-31 21:29:28 +08:00
CREATE OR REPLACE FUNCTION @extschema@.CDB_QueryTables(query text)
RETURNS name[]
AS $$
BEGIN
2019-05-31 21:29:28 +08:00
RETURN @extschema@.CDB_QueryTablesText(query)::name[];
END
2017-10-24 20:16:56 +08:00
$$ LANGUAGE 'plpgsql' VOLATILE STRICT PARALLEL UNSAFE;