arc/scripts/migration_timescaledb.sql
Pierre-Yves Chibon 2060e10a2b Add unique constraing and fix ownership
Signed-off-by: Pierre-Yves Chibon <pingou@pingoured.fr>
2021-02-11 12:39:44 +01:00

117 lines
4.7 KiB
SQL

-- Sources
-- setting up/enabling: https://severalnines.com/database-blog/how-enable-timescaledb-existing-postgresql-database
-- migration: https://docs.timescale.com/latest/getting-started/migrating-data#same-db
-- dnf install timescaledb
-- vim /var/lib/pgsql/data/postgresql.conf
-- """
-- shared_preload_libraries = 'pg_stat_statements,timescaledb'
-- timescaledb.max_background_workers=4
-- """
-- systemctl restart postgresql
-- Check the extension is available
-- sudo -u postgres psql
\timing on
-- Check the extension is available
SELECT * FROM pg_available_extensions ORDER BY name;
-- Enable the extension on the datanommer database (\c datanommer)
CREATE EXTENSION IF NOT EXISTS timescaledb CASCADE;
-- Check that the extension is enabled
\dx
-- Create the messages2 table that will be have the timescaledb optimization
CREATE TABLE messages2 (LIKE messages INCLUDING DEFAULTS INCLUDING CONSTRAINTS EXCLUDING INDEXES);
CREATE SEQUENCE public.messages2_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
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;
ALTER TABLE ONLY public.messages2 ALTER COLUMN id SET DEFAULT nextval('public.messages2_id_seq'::regclass);
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 public.user_messages2
ADD CONSTRAINT user_messages2_user_msg_uniq
UNIQUE (username, "timestamp", msg);
ALTER TABLE public.user_messages2 OWNER TO datanommer;
-- 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 public.package_messages2
ADD CONSTRAINT package_messages2_pkg_msg_uniq
UNIQUE (package, "timestamp", msg);
ALTER TABLE public.package_messages2 OWNER TO datanommer;
-- Convert the timestamp to the hypertable
SELECT create_hypertable('messages2', 'timestamp');
-- Insert the data
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_messages.msg;
-- Create the indexes ones the data is in
CREATE INDEX index_msg2_category ON public.messages2 USING btree (category);
CREATE INDEX index_msg2_timestamp ON public.messages2 USING btree ("timestamp");
CREATE INDEX index_msg2_topic ON public.messages2 USING btree (topic);
CREATE INDEX messages2_datanommer_timestamp_category_idx ON public.messages2 USING btree ("timestamp" DESC, category);
CREATE INDEX messages2_datanommer_timestamp_topic_idx ON public.messages2 USING btree ("timestamp" DESC, topic);
-- -- Adjust user_messages2
-- ALTER TABLE user_messages2
-- ADD CONSTRAINT user_messages2_msg_fkey
-- FOREIGN KEY (msg, "timestamp") REFERENCES messages2(id, "timestamp") MATCH FULL;
-- -- Adjust package_messages2
-- ALTER TABLE package_messages2
-- ADD CONSTRAINT package_messages2_msg_fkey
-- FOREIGN KEY (msg, "timestamp") REFERENCES messages2(id, "timestamp") MATCH FULL;