From 4af13b64af18c16cb4feb0740e8b74b56fc0ab1e Mon Sep 17 00:00:00 2001 From: rjshrjndrn Date: Tue, 20 Aug 2024 17:28:41 +0200 Subject: [PATCH] spot: db change from dev --- .../db/init_dbs/postgresql/1.20.0/1.20.0.sql | 51 +++++++++++++++++++ .../db/init_dbs/postgresql/init_schema.sql | 47 +++++++++++------ .../rollback_dbs/postgresql/1.20.0/1.20.0.sql | 34 +++++++++++++ 3 files changed, 117 insertions(+), 15 deletions(-) create mode 100644 scripts/schema/db/init_dbs/postgresql/1.20.0/1.20.0.sql create mode 100644 scripts/schema/db/rollback_dbs/postgresql/1.20.0/1.20.0.sql diff --git a/scripts/schema/db/init_dbs/postgresql/1.20.0/1.20.0.sql b/scripts/schema/db/init_dbs/postgresql/1.20.0/1.20.0.sql new file mode 100644 index 000000000..5b62e277b --- /dev/null +++ b/scripts/schema/db/init_dbs/postgresql/1.20.0/1.20.0.sql @@ -0,0 +1,51 @@ +\set previous_version 'v1.19.0' +\set next_version 'v1.20.0' +SELECT openreplay_version() AS current_version, + openreplay_version() = :'previous_version' AS valid_previous, + openreplay_version() = :'next_version' AS is_next +\gset + +\if :valid_previous +\echo valid previous DB version :'previous_version', starting DB upgrade to :'next_version' +BEGIN; +SELECT format($fn_def$ +CREATE OR REPLACE FUNCTION openreplay_version() + RETURNS text AS +$$ +SELECT '%1$s' +$$ LANGUAGE sql IMMUTABLE; +$fn_def$, :'next_version') +\gexec + +-- +ALTER TABLE IF EXISTS events.clicks + ALTER COLUMN normalized_x SET DATA TYPE decimal, + ALTER COLUMN normalized_y SET DATA TYPE decimal; + +ALTER TABLE IF EXISTS public.users + ADD COLUMN IF NOT EXISTS spot_jwt_iat timestamp without time zone NULL DEFAULT NULL, + ADD COLUMN IF NOT EXISTS spot_jwt_refresh_jti integer NULL DEFAULT NULL, + ADD COLUMN IF NOT EXISTS spot_jwt_refresh_iat timestamp without time zone NULL DEFAULT NULL; + +CREATE SCHEMA IF NOT EXISTS or_cache; +CREATE TABLE IF NOT EXISTS or_cache.autocomplete_top_values +( + project_id integer NOT NULL REFERENCES public.projects (project_id) ON DELETE CASCADE, + event_type text NOT NULL, + event_key text NULL, + result jsonb NULL, + execution_time integer NULL, + created_at timestamp DEFAULT timezone('utc'::text, now()) NOT NULL, + UNIQUE NULLS NOT DISTINCT (project_id, event_type, event_key) +); + +ALTER TABLE IF EXISTS public.tenants + ADD COLUMN IF NOT EXISTS scope text NOT NULL DEFAULT 'full'; + +COMMIT; + +\elif :is_next +\echo new version detected :'next_version', nothing to do +\else +\warn skipping DB upgrade of :'next_version', expected previous version :'previous_version', found :'current_version' +\endif diff --git a/scripts/schema/db/init_dbs/postgresql/init_schema.sql b/scripts/schema/db/init_dbs/postgresql/init_schema.sql index ec1bb4730..15cc114de 100644 --- a/scripts/schema/db/init_dbs/postgresql/init_schema.sql +++ b/scripts/schema/db/init_dbs/postgresql/init_schema.sql @@ -17,6 +17,7 @@ BEGIN; CREATE SCHEMA IF NOT EXISTS events_common; CREATE SCHEMA IF NOT EXISTS events; CREATE SCHEMA IF NOT EXISTS events_ios; +CREATE SCHEMA IF NOT EXISTS or_cache; CREATE EXTENSION IF NOT EXISTS pg_trgm; CREATE EXTENSION IF NOT EXISTS pgcrypto; @@ -102,27 +103,31 @@ CREATE TABLE public.tenants t_sessions bigint NOT NULL DEFAULT 0, t_users integer NOT NULL DEFAULT 1, t_integrations integer NOT NULL DEFAULT 0, - last_telemetry bigint NOT NULL DEFAULT CAST(EXTRACT(epoch FROM date_trunc('day', now())) * 1000 AS BIGINT) - CONSTRAINT onerow_uni CHECK (tenant_id = 1) + last_telemetry bigint NOT NULL DEFAULT CAST(EXTRACT(epoch FROM date_trunc('day', now())) * 1000 AS BIGINT), + scope text NOT NULL DEFAULT 'full', + CONSTRAINT onerow_uni CHECK (tenant_id = 1) ); CREATE TYPE user_role AS ENUM ('owner', 'admin', 'member'); CREATE TABLE public.users ( - user_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, - email text NOT NULL UNIQUE, - role user_role NOT NULL DEFAULT 'member', - name text NOT NULL, - created_at timestamp without time zone NOT NULL DEFAULT (now() at time zone 'utc'), - deleted_at timestamp without time zone NULL DEFAULT NULL, - api_key text UNIQUE DEFAULT generate_api_key(20) NOT NULL, - jwt_iat timestamp without time zone NULL DEFAULT NULL, - jwt_refresh_jti integer NULL DEFAULT NULL, - jwt_refresh_iat timestamp without time zone NULL DEFAULT NULL, - data jsonb NOT NULL DEFAULT '{}'::jsonb, - weekly_report boolean NOT NULL DEFAULT TRUE, - settings jsonb DEFAULT NULL + user_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, + email text NOT NULL UNIQUE, + role user_role NOT NULL DEFAULT 'member', + name text NOT NULL, + created_at timestamp without time zone NOT NULL DEFAULT (now() at time zone 'utc'), + deleted_at timestamp without time zone NULL DEFAULT NULL, + api_key text UNIQUE DEFAULT generate_api_key(20) NOT NULL, + jwt_iat timestamp without time zone NULL DEFAULT NULL, + jwt_refresh_jti integer NULL DEFAULT NULL, + jwt_refresh_iat timestamp without time zone NULL DEFAULT NULL, + spot_jwt_iat timestamp without time zone NULL DEFAULT NULL, + spot_jwt_refresh_jti integer NULL DEFAULT NULL, + spot_jwt_refresh_iat timestamp without time zone NULL DEFAULT NULL, + data jsonb NOT NULL DEFAULT '{}'::jsonb, + weekly_report boolean NOT NULL DEFAULT TRUE, + settings jsonb DEFAULT NULL ); CREATE TABLE public.basic_authentication @@ -1187,4 +1192,16 @@ CREATE TABLE public.projects_conditions filters jsonb NOT NULL DEFAULT '[]'::jsonb ); +CREATE TABLE or_cache.autocomplete_top_values +( + project_id integer NOT NULL REFERENCES public.projects (project_id) ON DELETE CASCADE, + event_type text NOT NULL, + event_key text NULL, + result jsonb NULL, + execution_time integer NULL, + created_at timestamp DEFAULT timezone('utc'::text, now()) NOT NULL, + UNIQUE NULLS NOT DISTINCT (project_id, event_type, event_key) +); + + COMMIT; \ No newline at end of file diff --git a/scripts/schema/db/rollback_dbs/postgresql/1.20.0/1.20.0.sql b/scripts/schema/db/rollback_dbs/postgresql/1.20.0/1.20.0.sql new file mode 100644 index 000000000..685d4a9fd --- /dev/null +++ b/scripts/schema/db/rollback_dbs/postgresql/1.20.0/1.20.0.sql @@ -0,0 +1,34 @@ +\set previous_version 'v1.20.0' +\set next_version 'v1.19.0' +SELECT openreplay_version() AS current_version, + openreplay_version() = :'previous_version' AS valid_previous, + openreplay_version() = :'next_version' AS is_next +\gset + +\if :valid_previous +\echo valid previous DB version :'previous_version', starting DB downgrade to :'next_version' +BEGIN; +SELECT format($fn_def$ +CREATE OR REPLACE FUNCTION openreplay_version() + RETURNS text AS +$$ +SELECT '%1$s' +$$ LANGUAGE sql IMMUTABLE; +$fn_def$, :'next_version') +\gexec + +-- +ALTER TABLE IF EXISTS public.users + DROP COLUMN IF EXISTS spot_jwt_iat, + DROP COLUMN IF EXISTS spot_jwt_refresh_jti, + DROP COLUMN IF EXISTS spot_jwt_refresh_iat; + +DROP SCHEMA or_cache CASCADE; + +COMMIT; + +\elif :is_next +\echo new version detected :'next_version', nothing to do +\else +\warn skipping DB downgrade of :'next_version', expected previous version :'previous_version', found :'current_version' +\endif \ No newline at end of file