diff --git a/scripts-available/CDB_QueryTables.sql b/scripts-available/CDB_QueryTables.sql index 1ddf675..b3b81dc 100644 --- a/scripts-available/CDB_QueryTables.sql +++ b/scripts-available/CDB_QueryTables.sql @@ -22,7 +22,7 @@ BEGIN END IF; BEGIN - EXECUTE 'EXPLAIN (FORMAT XML) ' || rec.q INTO STRICT exp; + EXECUTE 'EXPLAIN (FORMAT XML, VERBOSE) ' || rec.q INTO STRICT exp; EXCEPTION WHEN others THEN -- TODO: if error is 'relation "xxxxxx" does not exist', take xxxxxx as -- the affected table ? @@ -33,14 +33,19 @@ BEGIN -- Now need to extract all values of - --RAISE DEBUG 'Explain: %', exp; + -- 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 ) - SELECT unnest(x)::name as p from inp + inp AS ( + SELECT + xpath('//x:Relation-Name/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as x, + xpath('//x:Schema/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as s + ) + SELECT unnest(x)::name as p, unnest(s)::name as sc from inp LOOP - --RAISE DEBUG 'tab: %', rec2.p; - tables := array_append(tables, rec2.p); + -- RAISE DEBUG 'tab: %', rec2.p; + -- RAISE DEBUG 'sc: %', rec2.sc; + tables := array_append(tables, (rec2.sc || '.' || rec2.p)::name); END LOOP; -- RAISE DEBUG 'Tables: %', tables; diff --git a/test/CDB_QueryTablesTest.sql b/test/CDB_QueryTablesTest.sql index 40c1197..6c3911f 100644 --- a/test/CDB_QueryTablesTest.sql +++ b/test/CDB_QueryTablesTest.sql @@ -25,3 +25,9 @@ WITH inp AS ( select 'create table test (a int); insert into test values (1); se WITH inp AS ( select 'WITH a AS (select * from pg_class) select * from a'::text as q ) SELECT q, CDB_QueryTables(q) from inp; + +CREATE SCHEMA sc; +create table sc.test (a int); +insert into sc.test values (1); +WITH inp AS ( select 'select * from sc.test'::text as q ) + SELECT q, CDB_QueryTables(q) from inp; diff --git a/test/CDB_QueryTablesTest_expect b/test/CDB_QueryTablesTest_expect index 9b04725..6d44860 100644 --- a/test/CDB_QueryTablesTest_expect +++ b/test/CDB_QueryTablesTest_expect @@ -1,11 +1,15 @@ -SELECT * FROM geometry_columns|{pg_attribute,pg_class,pg_namespace,pg_type} -SELECT a.attname FROM pg_class c JOIN pg_attribute a on (a.attrelid = c.oid)|{pg_attribute,pg_class} +SELECT * FROM geometry_columns|{pg_catalog.pg_attribute,pg_catalog.pg_class,pg_catalog.pg_namespace,pg_catalog.pg_type} +SELECT a.attname FROM pg_class c JOIN pg_attribute a on (a.attrelid = c.oid)|{pg_catalog.pg_attribute,pg_catalog.pg_class} CREATE table "my'tab;le" as select 1|{} -SELECT a.oid, b.oid FROM pg_class a, pg_class b|{pg_class} +SELECT a.oid, b.oid FROM pg_class a, pg_class b|{pg_catalog.pg_class} SELECT 1 as col1; select 2 as col2|{} WARNING: CDB_QueryTables cannot explain query: select 1 from nonexistant (42P01: relation "nonexistant" does not exist) ERROR: relation "nonexistant" does not exist -begin; select * from pg_class; commit;|{pg_class} +begin; select * from pg_class; commit;|{pg_catalog.pg_class} WARNING: CDB_QueryTables cannot explain query: select * from test (42P01: relation "test" does not exist) ERROR: relation "test" does not exist -WITH a AS (select * from pg_class) select * from a|{pg_class} +WITH a AS (select * from pg_class) select * from a|{pg_catalog.pg_class} +CREATE SCHEMA +CREATE TABLE +INSERT 0 1 +select * from sc.test|{sc.test}