From 99dd7cefc7577b50ca9e0b698b652cc5e9a06481 Mon Sep 17 00:00:00 2001 From: Gonzalo Riestra Date: Wed, 6 Mar 2019 18:19:38 +0100 Subject: [PATCH] ghost tables functions using redis --- scripts-available/CDB_GhostTables.sql | 104 ++++++++++++++++++++++++ scripts-enabled/290-CDB_GhostTables.sql | 1 + test/CDB_GhostTables.sql | 44 ++++++++++ test/CDB_GhostTables_expect | 15 ++++ 4 files changed, 164 insertions(+) create mode 100644 scripts-available/CDB_GhostTables.sql create mode 120000 scripts-enabled/290-CDB_GhostTables.sql create mode 100644 test/CDB_GhostTables.sql create mode 100644 test/CDB_GhostTables_expect diff --git a/scripts-available/CDB_GhostTables.sql b/scripts-available/CDB_GhostTables.sql new file mode 100644 index 0000000..caf0258 --- /dev/null +++ b/scripts-available/CDB_GhostTables.sql @@ -0,0 +1,104 @@ +-- Table to store the transaction id from DDL events to avoid multiple executions +CREATE TABLE IF NOT EXISTS cartodb.cdb_ddl_execution(txid integer PRIMARY KEY); + +-- Enqueues a job to run Ghost tables linking process for the provided user_id +CREATE OR REPLACE FUNCTION _CDB_LinkGhostTables(user_id text) +RETURNS void +AS $$ + if not user_id: + return + + client = GD.get('redis', None) + + retry = 3 + error = '' + redis_host = '127.0.0.1' + redis_port = 6379 + redis_timeout = 5 + + while True: + + if not client: + try: + import redis + client = GD['redis'] = redis.Redis(host=redis_host, port=redis_port, socket_timeout=redis_timeout) + except Exception as err: + error = "client_error - %s" % str(err) + # NOTE: no retries on connection error + plpy.error('Ghost tables connection error: ' + str(err)) + break + + try: + job = '{{"class":"Resque::UserDBJobs::UserDBMaintenance::LinkGhostTables","args":["{}"]}}'.format(user_id) + client.rpush("resque:queue:user_dbs", job) + break + except Exception as err: + error = "request_error - %s" % str(err) + client = GD['redis'] = None # force reconnect + if not retry: + plpy.error('Ghost tables error: ' + str(err)) + break + retry -= 1 # try reconnecting +$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE; + +-- Enqueues a job to run Ghost tables linking process for the current user +CREATE OR REPLACE FUNCTION CDB_LinkGhostTables() +RETURNS void +AS $$ + DECLARE + user_id TEXT; + BEGIN + EXECUTE 'SELECT (regexp_match(session_user, ''[0-9a-f]{8}-[0-9a-f]{4}-[0-9a-f]{4}-[0-9a-f]{4}-[0-9a-f]{12}''))[1];' INTO user_id; + PERFORM _CDB_LinkGhostTables(user_id); + DELETE FROM cartodb.cdb_ddl_execution WHERE txid = txid_current(); + RAISE NOTICE '_CDB_LinkGhostTables(%) called', user_id; + END; +$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE SECURITY DEFINER; + +-- Trigger function to call CDB_LinkGhostTables() +CREATE OR REPLACE FUNCTION _CDB_LinkGhostTablesTrigger() +RETURNS trigger +AS $$ + BEGIN + PERFORM CDB_LinkGhostTables(); + RETURN NULL; + END; +$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE SECURITY DEFINER; + +-- Trigger to call CDB_LinkGhostTables() when adding a row in cartodb.cdb_ddl_execution +DROP TRIGGER IF EXISTS check_ddl_update ON cartodb.cdb_ddl_execution; +CREATE CONSTRAINT TRIGGER check_ddl_update +AFTER INSERT ON cartodb.cdb_ddl_execution +INITIALLY DEFERRED +FOR EACH ROW +EXECUTE PROCEDURE _CDB_LinkGhostTablesTrigger(); + +-- Event trigger to save the current transaction in cartodb.cdb_ddl_execution +CREATE OR REPLACE FUNCTION CDB_SaveDDLTransaction() +RETURNS event_trigger +AS $$ + BEGIN + INSERT INTO cartodb.cdb_ddl_execution VALUES (txid_current()) ON CONFLICT (txid) DO NOTHING; + END; +$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE SECURITY DEFINER; + +-- Creates the trigger on DDL events to link ghost tables +CREATE OR REPLACE FUNCTION CDB_EnableGhostTablesTrigger() +RETURNS void +AS $$ + BEGIN + CREATE EVENT TRIGGER link_ghost_tables + ON ddl_command_end + WHEN TAG IN ('CREATE TABLE', 'SELECT INTO', 'DROP TABLE', 'ALTER TABLE', 'CREATE TRIGGER', 'DROP TRIGGER') + EXECUTE PROCEDURE CDB_SaveDDLTransaction(); + END; +$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE; + +-- Drops the trigger on DDL events to link ghost tables +CREATE OR REPLACE FUNCTION CDB_DisableGhostTablesTrigger() +RETURNS void +AS $$ + BEGIN + DROP EVENT TRIGGER link_ghost_tables; + END; +$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE; diff --git a/scripts-enabled/290-CDB_GhostTables.sql b/scripts-enabled/290-CDB_GhostTables.sql new file mode 120000 index 0000000..9be6429 --- /dev/null +++ b/scripts-enabled/290-CDB_GhostTables.sql @@ -0,0 +1 @@ +../scripts-available/CDB_GhostTables.sql \ No newline at end of file diff --git a/test/CDB_GhostTables.sql b/test/CDB_GhostTables.sql new file mode 100644 index 0000000..64285b7 --- /dev/null +++ b/test/CDB_GhostTables.sql @@ -0,0 +1,44 @@ +-- Create user and enable Ghost tables trigger +\set QUIET on +CREATE ROLE "cartodb_user_b621f453-75ee-438f-acc9-8c5303f3d658_db" LOGIN; +CREATE SCHEMA fulano; +GRANT ALL ON SCHEMA fulano TO "cartodb_user_b621f453-75ee-438f-acc9-8c5303f3d658_db"; +GRANT USAGE ON SCHEMA cartodb TO "cartodb_user_b621f453-75ee-438f-acc9-8c5303f3d658_db"; +GRANT SELECT ON cartodb.cdb_ddl_execution TO "cartodb_user_b621f453-75ee-438f-acc9-8c5303f3d658_db"; +GRANT EXECUTE ON FUNCTION CDB_LinkGhostTables() TO "cartodb_user_b621f453-75ee-438f-acc9-8c5303f3d658_db"; +SELECT CDB_EnableGhostTablesTrigger(); +SET SESSION AUTHORIZATION "cartodb_user_b621f453-75ee-438f-acc9-8c5303f3d658_db"; +\set QUIET off + +SELECT CDB_LinkGhostTables(); -- _CDB_LinkGhostTables called + +BEGIN; +SELECT COUNT(*) FROM cartodb.cdb_ddl_execution; -- 0 +CREATE TABLE fulano.tmp(id INT); +SELECT COUNT(*) FROM cartodb.cdb_ddl_execution; -- 1 +END; -- _CDB_LinkGhostTables called + +-- Disable Ghost tables trigger +\set QUIET on +SET SESSION AUTHORIZATION postgres; +SELECT CDB_DisableGhostTablesTrigger(); +DROP TABLE fulano.tmp; +SET SESSION AUTHORIZATION "cartodb_user_b621f453-75ee-438f-acc9-8c5303f3d658_db"; +\set QUIET off + +BEGIN; +SELECT COUNT(*) FROM cartodb.cdb_ddl_execution; -- 0 +CREATE TABLE fulano.tmp(id INT); +SELECT COUNT(*) FROM cartodb.cdb_ddl_execution; -- 0 +END; -- _CDB_LinkGhostTables not called + +-- Clean test stuff +\set QUIET on +SET SESSION AUTHORIZATION postgres; +DROP TABLE fulano.tmp; +REVOKE EXECUTE ON FUNCTION CDB_LinkGhostTables() FROM "cartodb_user_b621f453-75ee-438f-acc9-8c5303f3d658_db"; +REVOKE SELECT ON cartodb.cdb_ddl_execution FROM "cartodb_user_b621f453-75ee-438f-acc9-8c5303f3d658_db"; +REVOKE USAGE ON SCHEMA cartodb FROM "cartodb_user_b621f453-75ee-438f-acc9-8c5303f3d658_db"; +REVOKE ALL ON SCHEMA fulano FROM "cartodb_user_b621f453-75ee-438f-acc9-8c5303f3d658_db"; +DROP ROLE "cartodb_user_b621f453-75ee-438f-acc9-8c5303f3d658_db"; +\set QUIET off diff --git a/test/CDB_GhostTables_expect b/test/CDB_GhostTables_expect new file mode 100644 index 0000000..8d79b24 --- /dev/null +++ b/test/CDB_GhostTables_expect @@ -0,0 +1,15 @@ + +NOTICE: _CDB_LinkGhostTables(b621f453-75ee-438f-acc9-8c5303f3d658) called + +BEGIN +0 +CREATE TABLE +1 +NOTICE: _CDB_LinkGhostTables(b621f453-75ee-438f-acc9-8c5303f3d658) called +COMMIT + +BEGIN +0 +CREATE TABLE +0 +COMMIT