Add a migration_timescaledb script
This script contains the steps followed to install, configure, enable, activate and convert the datanommer database to timescaledb Signed-off-by: Pierre-Yves Chibon <pingou@pingoured.fr>
This commit is contained in:
parent
6b128c08b6
commit
72b02b0ad8
1 changed files with 77 additions and 0 deletions
77
scripts/migration_timescaledb.sql
Normal file
77
scripts/migration_timescaledb.sql
Normal file
|
@ -0,0 +1,77 @@
|
|||
-- 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);
|
||||
|
||||
|
||||
ALTER TABLE user_messages DROP CONSTRAINT user_messages_msg_fkey;
|
||||
ALTER TABLE user_messages ADD CO
|
||||
|
||||
ALTER TABLE package_messages DROP CONSTRAINT package_messages_msg_fkey;
|
||||
ALTER TABLE package_messages ADD CONSTRAINT package_messages_msg_fkey FOREIGN KEY (msg) REFERENCES messages2(id);
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
|
||||
DROP TABLE messages_010g , messages_020g, messages_030g, messages_040g, messages_050g,
|
||||
messages_060g, messages_070g, messages_080g, messages_090g, messages_100g,
|
||||
messages_110g, messages_120g, messages_130g, messages_140g, messages_150g,
|
||||
messages_160g, messages_170g, messages_180g, messages_190g, messages_200g,
|
||||
messages_210g, messages_220g
|
Loading…
Add table
Add a link
Reference in a new issue