Add querytables and cdb_tablemetadata for proper testing its integration
This commit is contained in:
parent
09527b6808
commit
673bd4f3f2
@ -78,6 +78,11 @@ if test x"$PREPARE_PGSQL" = xyes; then
|
|||||||
sed "s/:TESTPASS/${TESTPASS}/" |
|
sed "s/:TESTPASS/${TESTPASS}/" |
|
||||||
psql -v ON_ERROR_STOP=1 ${TEST_DB} || exit 1
|
psql -v ON_ERROR_STOP=1 ${TEST_DB} || exit 1
|
||||||
|
|
||||||
|
curl -L -s https://github.com/CartoDB/cartodb-postgresql/raw/cdb/scripts-available/CDB_QueryStatements.sql -o sql/CDB_QueryStatements.sql
|
||||||
|
curl -L -s https://github.com/CartoDB/cartodb-postgresql/raw/cdb/scripts-available/CDB_QueryTables.sql -o sql/CDB_QueryTables.sql
|
||||||
|
cat sql/CDB_QueryStatements.sql sql/CDB_QueryTables.sql |
|
||||||
|
psql -v ON_ERROR_STOP=1 ${TEST_DB} || exit 1
|
||||||
|
|
||||||
fi
|
fi
|
||||||
|
|
||||||
if test x"$PREPARE_REDIS" = xyes; then
|
if test x"$PREPARE_REDIS" = xyes; then
|
||||||
|
14
test/support/sql/CDB_QueryStatements.sql
Normal file
14
test/support/sql/CDB_QueryStatements.sql
Normal file
@ -0,0 +1,14 @@
|
|||||||
|
-- Return an array of statements found in the given query text
|
||||||
|
--
|
||||||
|
-- Regexp curtesy of Hubert Lubaczewski (depesz)
|
||||||
|
-- Implemented in plpython for performance reasons
|
||||||
|
--
|
||||||
|
CREATE OR REPLACE FUNCTION CDB_QueryStatements(query text)
|
||||||
|
RETURNS SETOF TEXT AS $$
|
||||||
|
import re
|
||||||
|
pat = re.compile( r'''((?:[^'"$;]+|"[^"]*"|'[^']*'|(\$[^$]*\$).*?\2)+)''', re.DOTALL )
|
||||||
|
for match in pat.findall(query):
|
||||||
|
cleaned = match[0].strip()
|
||||||
|
if ( cleaned ):
|
||||||
|
yield cleaned
|
||||||
|
$$ language 'plpythonu' IMMUTABLE STRICT;
|
67
test/support/sql/CDB_QueryTables.sql
Normal file
67
test/support/sql/CDB_QueryTables.sql
Normal file
@ -0,0 +1,67 @@
|
|||||||
|
-- Return an array of table names scanned by a given query
|
||||||
|
--
|
||||||
|
-- Requires PostgreSQL 9.x+
|
||||||
|
--
|
||||||
|
CREATE OR REPLACE FUNCTION CDB_QueryTables(query text)
|
||||||
|
RETURNS name[]
|
||||||
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
exp XML;
|
||||||
|
tables NAME[];
|
||||||
|
rec RECORD;
|
||||||
|
rec2 RECORD;
|
||||||
|
BEGIN
|
||||||
|
|
||||||
|
tables := '{}';
|
||||||
|
|
||||||
|
FOR rec IN SELECT CDB_QueryStatements(query) q LOOP
|
||||||
|
|
||||||
|
IF NOT ( rec.q ilike 'select %' or rec.q ilike 'with %' ) THEN
|
||||||
|
--RAISE WARNING 'Skipping %', rec.q;
|
||||||
|
CONTINUE;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
BEGIN
|
||||||
|
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 ?
|
||||||
|
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)::name as p, unnest(s)::name as sc from inp
|
||||||
|
LOOP
|
||||||
|
-- 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;
|
||||||
|
|
||||||
|
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
|
||||||
|
$$ LANGUAGE 'plpgsql' VOLATILE STRICT;
|
@ -177,3 +177,12 @@ CREATE TABLE test_table_private_1 (
|
|||||||
INSERT INTO test_table_private_1 SELECT * from test_table;
|
INSERT INTO test_table_private_1 SELECT * from test_table;
|
||||||
|
|
||||||
GRANT ALL ON TABLE test_table_private_1 TO :TESTUSER;
|
GRANT ALL ON TABLE test_table_private_1 TO :TESTUSER;
|
||||||
|
|
||||||
|
CREATE TABLE IF NOT EXISTS
|
||||||
|
CDB_TableMetadata (
|
||||||
|
tabname regclass not null primary key,
|
||||||
|
updated_at timestamp with time zone not null default now()
|
||||||
|
);
|
||||||
|
|
||||||
|
GRANT SELECT ON CDB_TableMetadata TO :PUBLICUSER;
|
||||||
|
GRANT SELECT ON CDB_TableMetadata TO :TESTUSER;
|
||||||
|
Loading…
Reference in New Issue
Block a user