From 9971f132fb041d0b0a4d76505e5f0852bf536abf Mon Sep 17 00:00:00 2001 From: Pierre-Yves Chibon Date: Tue, 9 Feb 2021 17:20:54 +0100 Subject: [PATCH] Restructure migration_timescaledb With this restructuration we adjust the FK before we make the messages2 table a hypertable. Fingers crossed that'll help Signed-off-by: Pierre-Yves Chibon --- scripts/migration_timescaledb.sql | 72 ++++++++++++++++++------------- 1 file changed, 42 insertions(+), 30 deletions(-) diff --git a/scripts/migration_timescaledb.sql b/scripts/migration_timescaledb.sql index cc5f521..26f12bc 100644 --- a/scripts/migration_timescaledb.sql +++ b/scripts/migration_timescaledb.sql @@ -37,6 +37,9 @@ CREATE SEQUENCE public.messages2_id_seq NO MAXVALUE CACHE 1; +ALTER TABLE messages2 + ADD CONSTRAINT messages2_pkey PRIMARY KEY (id, "timestamp"); + ALTER TABLE public.messages2 OWNER TO datanommer; ALTER TABLE public.messages2_id_seq OWNER TO datanommer; -- ALTER SEQUENCE public.messages2_id_seq OWNED BY public.messages2.id; @@ -44,6 +47,36 @@ ALTER TABLE ONLY public.messages2 ALTER COLUMN id SET DEFAULT nextval('public.me GRANT SELECT ON TABLE public.messages2 TO datagrepper; GRANT SELECT ON SEQUENCE public.messages2_id_seq TO datagrepper; +-- user_messages2 +CREATE TABLE user_messages2 (LIKE user_messages INCLUDING DEFAULTS INCLUDING ALL); +ALTER TABLE user_messages ADD "timestamp" timestamp without time zone; +ALTER TABLE user_messages2 ALTER "timestamp" SET NOT NULL; +ALTER TABLE user_messages2 DROP CONSTRAINT user_messages2_pkey; +ALTER TABLE user_messages2 + ADD CONSTRAINT user_messages2_pkey PRIMARY KEY (username, msg, "timestamp"); +ALTER TABLE user_messages2 + ADD CONSTRAINT user_messages2_username_fkey + FOREIGN KEY (username) REFERENCES "user"(name) MATCH FULL; +ALTER TABLE user_messages2 + ADD CONSTRAINT user_messages2_msg_fkey + FOREIGN KEY (msg, "timestamp") REFERENCES messages2(id, "timestamp") MATCH FULL; + + +-- package_messages2 +CREATE TABLE package_messages2 (LIKE package_messages INCLUDING DEFAULTS INCLUDING ALL); +ALTER TABLE package_messages2 ADD "timestamp" timestamp without time zone; +ALTER TABLE package_messages2 ALTER "timestamp" SET NOT NULL; +ALTER TABLE package_messages2 DROP CONSTRAINT package_messages2_pkey; +ALTER TABLE package_messages2 + ADD CONSTRAINT package_messages2_pkey PRIMARY KEY (package, msg, "timestamp"); +ALTER TABLE package_messages2 + ADD CONSTRAINT package_messages_package_fkey + FOREIGN KEY (package) REFERENCES package(name) MATCH FULL; +ALTER TABLE package_messages2 + ADD CONSTRAINT package_messages2_msg_fkey + FOREIGN KEY (msg, "timestamp") REFERENCES messages2(id, "timestamp") MATCH FULL; + + -- Convert the timestamp to the hypertable SELECT create_hypertable('messages2', 'timestamp'); @@ -53,6 +86,15 @@ SELECT create_hypertable('messages2', 'timestamp'); INSERT INTO messages2 (i,"timestamp",certificate,signature,topic,_msg,category,source_name,source_version,msg_id,_headers,username,crypto) SELECT i,"timestamp",certificate,signature,topic,_msg,category,source_name,source_version,msg_id,_headers,username,crypto FROM messages ORDER BY messages.id; +INSERT INTO user_messages2 (username, msg,"timestamp") +SELECT user_messages.username, user_messages.msg, messages2.timestamp + from user_messages, messages2 where messages2.id = user_messages.msg; + +INSERT INTO package_messages2 (package, msg,"timestamp") +SELECT package_messages.package, package_messages.msg, messages2.timestamp + from package_messages, messages2 where messages2.id = package_messages2.msg; + + -- Create the indexes ones the data is in CREATE INDEX index_msg2_category ON public.messages2 USING btree (category); @@ -64,44 +106,14 @@ CREATE INDEX messages2_datanommer_timestamp_topic_idx ON public.messages2 USING -- Adjust user_messages -ALTER TABLE user_messages DROP CONSTRAINT user_messages_msg_fkey; -ALTER TABLE user_messages ADD "timestamp" timestamp without time zone; UPDATE user_messages SET "timestamp" = messages2.timestamp FROM messages2 WHERE messages2.id = user_messages.msg; -ALTER TABLE user_messages ADD "timestamp" timestamp without time zone; -UPDATE user_messages -SET "timestamp" = messages2.timestamp -FROM messages2 -WHERE user_messages.timestamp is NULL AND messages2.id = user_messages.msg; - -ALTER TABLE user_messages ALTER "timestamp" SET NOT NULL; - -ALTER TABLE user_messages - ADD CONSTRAINT user_messages_msg_fkey - FOREIGN KEY (msg, "timestamp") REFERENCES messages2(id, "timestamp") MATCH FULL; - - -- Adjust package_messages -ALTER TABLE package_messages DROP CONSTRAINT package_messages_msg_fkey; - -ALTER TABLE package_messages ADD "timestamp" timestamp without time zone; UPDATE package_messages SET "timestamp" = messages2.timestamp FROM messages2 WHERE messages2.id = package_messages.msg; - -ALTER TABLE user_messages ADD "timestamp" timestamp without time zone; -UPDATE user_messages -SET "timestamp" = messages2.timestamp -FROM messages2 -WHERE user_messages.timestamp is NULL AND messages2.id = user_messages.msg; - -ALTER TABLE user_messages ALTER "timestamp" SET NOT NULL; - -ALTER TABLE package_messages - ADD CONSTRAINT package_messages_msg_fkey - FOREIGN KEY (msg, "timestamp") REFERENCES messages2(id, "timestamp") MATCH FULL;