From 7e3597521c19b39bb367d7c13dc959a140ab8a2c Mon Sep 17 00:00:00 2001 From: Taha Yassine Kraiem Date: Wed, 6 Apr 2022 17:14:26 +0200 Subject: [PATCH] feat(db): dashboard schema for init file feat(db): dashboard schema for EE init file feat(db): dashboard schema for EE delta file --- .../db/init_dbs/postgresql/1.5.5/1.5.5.sql | 80 +++++++++++++++++++ .../db/init_dbs/postgresql/init_schema.sql | 80 +++++++++++++++++-- .../db/init_dbs/postgresql/init_schema.sql | 27 ++++++- 3 files changed, 177 insertions(+), 10 deletions(-) create mode 100644 ee/scripts/helm/db/init_dbs/postgresql/1.5.5/1.5.5.sql diff --git a/ee/scripts/helm/db/init_dbs/postgresql/1.5.5/1.5.5.sql b/ee/scripts/helm/db/init_dbs/postgresql/1.5.5/1.5.5.sql new file mode 100644 index 000000000..15d5f314b --- /dev/null +++ b/ee/scripts/helm/db/init_dbs/postgresql/1.5.5/1.5.5.sql @@ -0,0 +1,80 @@ +BEGIN; +CREATE OR REPLACE FUNCTION openreplay_version() + RETURNS text AS +$$ +SELECT 'v1.5.5-ee' +$$ LANGUAGE sql IMMUTABLE; + + +CREATE TABLE IF NOT EXISTS dashboards +( + dashboard_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, + project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE, + user_id integer NOT NULL REFERENCES users (user_id) ON DELETE SET NULL, + name text NOT NULL, + is_public boolean NOT NULL DEFAULT TRUE, + is_pinned boolean NOT NULL DEFAULT FALSE, + created_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()), + deleted_at timestamp NULL DEFAULT NULL +); + + +ALTER TABLE IF EXISTS metrics + DROP CONSTRAINT IF EXISTS null_project_id_for_template_only, + DROP CONSTRAINT IF EXISTS unique_key; + +ALTER TABLE IF EXISTS metrics + ADD COLUMN IF NOT EXISTS edited_at timestamp NULL DEFAULT NULL, + ADD COLUMN IF NOT EXISTS is_pinned boolean NOT NULL DEFAULT FALSE, + ADD COLUMN IF NOT EXISTS category text NULL DEFAULT 'custom', + ADD COLUMN IF NOT EXISTS is_predefined boolean NOT NULL DEFAULT FALSE, + ADD COLUMN IF NOT EXISTS is_template boolean NOT NULL DEFAULT FALSE, + ADD COLUMN IF NOT EXISTS key text NULL DEFAULT NULL, + ADD COLUMN IF NOT EXISTS config jsonb NOT NULL DEFAULT '{}'::jsonb, + ALTER COLUMN project_id DROP NOT NULL, + ADD CONSTRAINT null_project_id_for_template_only + CHECK ( (metrics.category != 'custom') != (metrics.project_id IS NOT NULL) ), + ADD CONSTRAINT unique_key UNIQUE (key); + + + +CREATE TABLE IF NOT EXISTS dashboard_widgets +( + widget_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, + dashboard_id integer NOT NULL REFERENCES dashboards (dashboard_id) ON DELETE CASCADE, + metric_id integer NOT NULL REFERENCES metrics (metric_id) ON DELETE CASCADE, + user_id integer NOT NULL REFERENCES users (user_id) ON DELETE SET NULL, + created_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()), + config jsonb NOT NULL DEFAULT '{}'::jsonb +); + + +INSERT INTO metrics (name, category, config, is_predefined, is_template, is_public, key) +VALUES ('sessions count', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'count_sessions'), + ('avg request load time', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_request_load_time'), + ('avg page load time', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_page_load_time'), + ('avg image load time', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_image_load_time'), + ('avg dom content load start', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_dom_content_load_start'), + ('avg first contentful pixel', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_first_contentful_pixel'), + ('avg visited pages count', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_visited_pages'), + ('avg session duration', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_session_duration'), + ('avg pages dom build time', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_pages_dom_buildtime'), + ('avg pages response time', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_pages_response_time'), + ('avg response time', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_response_time'), + ('avg first paint', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_first_paint'), + ('avg dom content loaded', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_dom_content_loaded'), + ('avg time till first bit', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_till_first_bit'), + ('avg time to interactive', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_time_to_interactive'), + ('requests count', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'count_requests'), + ('avg time to render', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_time_to_render'), + ('avg used js heap size', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_used_js_heap_size'), + ('avg cpu', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_cpu') +ON CONFLICT (key) DO UPDATE SET name=excluded.name, + category=excluded.category, + config=excluded.config, + is_predefined=excluded.is_predefined, + is_template=excluded.is_template, + is_public=excluded.is_public; + +COMMIT; +ALTER TYPE metric_view_type ADD VALUE IF NOT EXISTS 'areaChart'; \ No newline at end of file diff --git a/ee/scripts/helm/db/init_dbs/postgresql/init_schema.sql b/ee/scripts/helm/db/init_dbs/postgresql/init_schema.sql index 9adab50e0..506853ffc 100644 --- a/ee/scripts/helm/db/init_dbs/postgresql/init_schema.sql +++ b/ee/scripts/helm/db/init_dbs/postgresql/init_schema.sql @@ -7,7 +7,7 @@ CREATE EXTENSION IF NOT EXISTS pgcrypto; CREATE OR REPLACE FUNCTION openreplay_version() RETURNS text AS $$ -SELECT 'v1.5.4-ee' +SELECT 'v1.5.5-ee' $$ LANGUAGE sql IMMUTABLE; @@ -106,6 +106,8 @@ $$ ('assigned_sessions'), ('autocomplete'), ('basic_authentication'), + ('dashboards'), + ('dashboard_widgets'), ('errors'), ('funnels'), ('integrations'), @@ -787,22 +789,32 @@ $$ CREATE INDEX IF NOT EXISTS traces_tenant_id_idx ON traces (tenant_id); CREATE TYPE metric_type AS ENUM ('timeseries','table'); - CREATE TYPE metric_view_type AS ENUM ('lineChart','progress','table','pieChart'); + CREATE TYPE metric_view_type AS ENUM ('lineChart','progress','table','pieChart','areaChart'); CREATE TABLE IF NOT EXISTS metrics ( metric_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, - project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE, + project_id integer NULL REFERENCES projects (project_id) ON DELETE CASCADE, user_id integer REFERENCES users (user_id) ON DELETE SET NULL, name text NOT NULL, is_public boolean NOT NULL DEFAULT FALSE, active boolean NOT NULL DEFAULT TRUE, - created_at timestamp DEFAULT timezone('utc'::text, now()) not null, + created_at timestamp default timezone('utc'::text, now()) not null, deleted_at timestamp, + edited_at timestamp, metric_type metric_type NOT NULL DEFAULT 'timeseries', view_type metric_view_type NOT NULL DEFAULT 'lineChart', metric_of text NOT NULL DEFAULT 'sessionCount', metric_value text[] NOT NULL DEFAULT '{}'::text[], - metric_format text + metric_format text, + category text NULL DEFAULT 'custom', + is_pinned boolean NOT NULL DEFAULT FALSE, + is_predefined boolean NOT NULL DEFAULT FALSE, + is_template boolean NOT NULL DEFAULT FALSE, + key text NULL DEFAULT NULL, + config jsonb NOT NULL DEFAULT '{}'::jsonb, + CONSTRAINT null_project_id_for_template_only + CHECK ( (metrics.category != 'custom') != (metrics.project_id IS NOT NULL) ), + CONSTRAINT unique_key UNIQUE (key) ); CREATE INDEX IF NOT EXISTS metrics_user_id_is_public_idx ON public.metrics (user_id, is_public); CREATE TABLE IF NOT EXISTS metric_series @@ -817,6 +829,29 @@ $$ ); CREATE INDEX IF NOT EXISTS metric_series_metric_id_idx ON public.metric_series (metric_id); + + CREATE TABLE dashboards + ( + dashboard_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, + project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE, + user_id integer NOT NULL REFERENCES users (user_id) ON DELETE SET NULL, + name text NOT NULL, + is_public boolean NOT NULL DEFAULT TRUE, + is_pinned boolean NOT NULL DEFAULT FALSE, + created_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()), + deleted_at timestamp NULL DEFAULT NULL + ); + + CREATE TABLE dashboard_widgets + ( + widget_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, + dashboard_id integer NOT NULL REFERENCES dashboards (dashboard_id) ON DELETE CASCADE, + metric_id integer NOT NULL REFERENCES metrics (metric_id) ON DELETE CASCADE, + user_id integer NOT NULL REFERENCES users (user_id) ON DELETE SET NULL, + created_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()), + config jsonb NOT NULL DEFAULT '{}'::jsonb + ); + CREATE TABLE IF NOT EXISTS searches ( search_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, @@ -948,10 +983,13 @@ $$ CREATE INDEX IF NOT EXISTS pages_session_id_timestamp_loadgt0NN_idx ON events.pages (session_id, timestamp) WHERE load_time > 0 AND load_time IS NOT NULL; CREATE INDEX IF NOT EXISTS pages_session_id_timestamp_visualgt0nn_idx ON events.pages (session_id, timestamp) WHERE visually_complete > 0 AND visually_complete IS NOT NULL; CREATE INDEX IF NOT EXISTS pages_timestamp_metgt0_idx ON events.pages (timestamp) WHERE response_time > 0 OR - first_paint_time > 0 OR - dom_content_loaded_time > 0 OR + first_paint_time > + 0 OR + dom_content_loaded_time > + 0 OR ttfb > 0 OR - time_to_interactive > 0; + time_to_interactive > + 0; CREATE INDEX IF NOT EXISTS pages_session_id_speed_indexgt0nn_idx ON events.pages (session_id, speed_index) WHERE speed_index > 0 AND speed_index IS NOT NULL; CREATE INDEX IF NOT EXISTS pages_session_id_timestamp_dom_building_timegt0nn_idx ON events.pages (session_id, timestamp, dom_building_time) WHERE dom_building_time > 0 AND dom_building_time IS NOT NULL; CREATE INDEX IF NOT EXISTS pages_base_path_session_id_timestamp_idx ON events.pages (base_path, session_id, timestamp); @@ -1219,5 +1257,31 @@ $$ $$ LANGUAGE plpgsql; +INSERT INTO metrics (name, category, config, is_predefined, is_template, is_public, key) +VALUES ('sessions count', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'count_sessions'), + ('avg request load time', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_request_load_time'), + ('avg page load time', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_page_load_time'), + ('avg image load time', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_image_load_time'), + ('avg dom content load start', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_dom_content_load_start'), + ('avg first contentful pixel', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_first_contentful_pixel'), + ('avg visited pages count', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_visited_pages'), + ('avg session duration', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_session_duration'), + ('avg pages dom build time', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_pages_dom_buildtime'), + ('avg pages response time', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_pages_response_time'), + ('avg response time', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_response_time'), + ('avg first paint', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_first_paint'), + ('avg dom content loaded', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_dom_content_loaded'), + ('avg time till first bit', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_till_first_bit'), + ('avg time to interactive', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_time_to_interactive'), + ('requests count', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'count_requests'), + ('avg time to render', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_time_to_render'), + ('avg used js heap size', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_used_js_heap_size'), + ('avg cpu', 'overview', '{"col":1,"row":1,"position":0}', true, true, true, 'avg_cpu') +ON CONFLICT (key) DO UPDATE SET name=excluded.name, + category=excluded.category, + config=excluded.config, + is_predefined=excluded.is_predefined, + is_template=excluded.is_template, + is_public=excluded.is_public; COMMIT; \ No newline at end of file diff --git a/scripts/helm/db/init_dbs/postgresql/init_schema.sql b/scripts/helm/db/init_dbs/postgresql/init_schema.sql index 5114d2433..8a0d2e807 100644 --- a/scripts/helm/db/init_dbs/postgresql/init_schema.sql +++ b/scripts/helm/db/init_dbs/postgresql/init_schema.sql @@ -6,7 +6,7 @@ CREATE SCHEMA IF NOT EXISTS events; CREATE OR REPLACE FUNCTION openreplay_version() RETURNS text AS $$ -SELECT 'v1.5.4' +SELECT 'v1.5.5' $$ LANGUAGE sql IMMUTABLE; -- --- accounts.sql --- @@ -960,7 +960,8 @@ $$ key text NULL DEFAULT NULL, config jsonb NOT NULL DEFAULT '{}'::jsonb, CONSTRAINT null_project_id_for_template_only - CHECK ( (metrics.category != 'custom') != (metrics.project_id IS NOT NULL) ) + CHECK ( (metrics.category != 'custom') != (metrics.project_id IS NOT NULL) ), + CONSTRAINT unique_key UNIQUE (key) ); CREATE INDEX metrics_user_id_is_public_idx ON public.metrics (user_id, is_public); @@ -976,6 +977,28 @@ $$ ); CREATE INDEX metric_series_metric_id_idx ON public.metric_series (metric_id); + CREATE TABLE dashboards + ( + dashboard_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, + project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE, + user_id integer NOT NULL REFERENCES users (user_id) ON DELETE SET NULL, + name text NOT NULL, + is_public boolean NOT NULL DEFAULT TRUE, + is_pinned boolean NOT NULL DEFAULT FALSE, + created_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()), + deleted_at timestamp NULL DEFAULT NULL + ); + + CREATE TABLE dashboard_widgets + ( + widget_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, + dashboard_id integer NOT NULL REFERENCES dashboards (dashboard_id) ON DELETE CASCADE, + metric_id integer NOT NULL REFERENCES metrics (metric_id) ON DELETE CASCADE, + user_id integer NOT NULL REFERENCES users (user_id) ON DELETE SET NULL, + created_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()), + config jsonb NOT NULL DEFAULT '{}'::jsonb + ); + CREATE TABLE searches (