-- 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 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; -- 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; -- 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_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;