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 35f3a5dd4..7db4b0bed 100644 --- a/ee/scripts/helm/db/init_dbs/postgresql/init_schema.sql +++ b/ee/scripts/helm/db/init_dbs/postgresql/init_schema.sql @@ -1,7 +1,9 @@ BEGIN; --- Schemas and functions definitions: + CREATE SCHEMA IF NOT EXISTS events_common; CREATE SCHEMA IF NOT EXISTS events; +CREATE EXTENSION IF NOT EXISTS pg_trgm; +CREATE EXTENSION IF NOT EXISTS pgcrypto; CREATE OR REPLACE FUNCTION openreplay_version() RETURNS text AS @@ -9,7 +11,6 @@ $$ SELECT 'v1.4.0-ee' $$ LANGUAGE sql IMMUTABLE; --- --- accounts.sql --- CREATE OR REPLACE FUNCTION generate_api_key(length integer) RETURNS text AS $$ @@ -29,7 +30,7 @@ begin end; $$ LANGUAGE plpgsql; --- --- events.sql --- + CREATE OR REPLACE FUNCTION events.funnel(steps integer[], m integer) RETURNS boolean AS $$ @@ -54,13 +55,14 @@ BEGIN END; $$ LANGUAGE plpgsql IMMUTABLE; --- --- integrations.sql --- + CREATE OR REPLACE FUNCTION notify_integration() RETURNS trigger AS $$ BEGIN IF NEW IS NULL THEN - PERFORM pg_notify('integration', (row_to_json(OLD)::text || '{"options": null, "request_data": null}'::text)); + PERFORM pg_notify('integration', + (row_to_json(OLD)::text || '{"options": null, "request_data": null}'::text)); ELSIF (OLD IS NULL) OR (OLD.options <> NEW.options) THEN PERFORM pg_notify('integration', row_to_json(NEW)::text); END IF; @@ -68,7 +70,7 @@ BEGIN END; $$ LANGUAGE plpgsql; --- --- alerts.sql --- + CREATE OR REPLACE FUNCTION notify_alert() RETURNS trigger AS $$ @@ -85,7 +87,6 @@ BEGIN END ; $$ LANGUAGE plpgsql; --- --- projects.sql --- CREATE OR REPLACE FUNCTION notify_project() RETURNS trigger AS $$ @@ -95,28 +96,51 @@ BEGIN END; $$ LANGUAGE plpgsql; --- All tables and types: + DO $$ BEGIN - IF EXISTS(SELECT - FROM information_schema.tables - WHERE table_schema = 'public' - AND table_name = 'tenants') THEN - raise notice 'DB exists, skipping creation query'; + IF (with to_check (name) as ( + values ('alerts'), + ('announcements'), + ('assigned_sessions'), + ('autocomplete'), + ('basic_authentication'), + ('errors'), + ('funnels'), + ('integrations'), + ('issues'), + ('jira_cloud'), + ('jobs'), + ('metric_series'), + ('metrics'), + ('notifications'), + ('oauth_authentication'), + ('projects'), + ('roles'), + ('roles_projects'), + ('searches'), + ('sessions'), + ('tenants'), + ('traces'), + ('user_favorite_errors'), + ('user_favorite_sessions'), + ('user_viewed_errors'), + ('user_viewed_sessions'), + ('users'), + ('webhooks') + ) + select bool_and(exists(select * + from information_schema.tables t + where table_schema = 'public' + AND table_name = to_check.name)) as all_present + from to_check) THEN + raise notice 'All public schema tables exists'; ELSE - raise notice 'Creating DB'; + raise notice 'Some or all public schema tables are missing, creating missing tables'; --- --- public.sql --- - - CREATE EXTENSION IF NOT EXISTS pg_trgm; - CREATE EXTENSION IF NOT EXISTS pgcrypto; - - --- --- accounts.sql --- - - CREATE TABLE tenants + CREATE TABLE IF NOT EXISTS tenants ( tenant_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, user_id text NOT NULL DEFAULT generate_api_key(20), @@ -135,7 +159,7 @@ $$ ); - CREATE TABLE roles + CREATE TABLE IF NOT EXISTS roles ( role_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, tenant_id integer NOT NULL REFERENCES tenants (tenant_id) ON DELETE CASCADE, @@ -148,9 +172,14 @@ $$ deleted_at timestamp NULL DEFAULT NULL ); - CREATE TYPE user_role AS ENUM ('owner', 'admin', 'member'); + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'user_role') THEN + CREATE TYPE user_role AS ENUM ('owner','admin','member'); + END IF; - CREATE TABLE users + + CREATE TABLE IF NOT EXISTS users ( user_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, tenant_id integer NOT NULL REFERENCES tenants (tenant_id) ON DELETE CASCADE, @@ -222,16 +251,16 @@ $$ }'::jsonb, api_key text UNIQUE default generate_api_key(20) not null, jwt_iat timestamp without time zone NULL DEFAULT NULL, - data jsonb NOT NULL DEFAULT '{}'::jsonb, + data jsonb NOT NULL DEFAULT'{}'::jsonb, weekly_report boolean NOT NULL DEFAULT TRUE, origin text NULL DEFAULT NULL, role_id integer REFERENCES roles (role_id) ON DELETE SET NULL, internal_id text NULL DEFAULT NULL ); - CREATE INDEX users_tenant_id_deleted_at_N_idx ON users (tenant_id) WHERE deleted_at ISNULL; + CREATE INDEX IF NOT EXISTS users_tenant_id_deleted_at_N_idx ON users (tenant_id) WHERE deleted_at ISNULL; - CREATE TABLE basic_authentication + CREATE TABLE IF NOT EXISTS basic_authentication ( user_id integer NOT NULL REFERENCES users (user_id) ON DELETE CASCADE, password text DEFAULT NULL, @@ -244,9 +273,13 @@ $$ UNIQUE (user_id) ); + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'oauth_provider') THEN + CREATE TYPE oauth_provider AS ENUM ('jira','github'); + END IF; - CREATE TYPE oauth_provider AS ENUM ('jira', 'github'); - CREATE TABLE oauth_authentication + CREATE TABLE IF NOT EXISTS oauth_authentication ( user_id integer NOT NULL REFERENCES users (user_id) ON DELETE CASCADE, provider oauth_provider NOT NULL, @@ -256,9 +289,7 @@ $$ ); --- --- projects.sql --- - - CREATE TABLE projects + CREATE TABLE IF NOT EXISTS projects ( project_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, project_key varchar(20) NOT NULL UNIQUE DEFAULT generate_api_key(20), @@ -279,35 +310,43 @@ $$ metadata_8 text DEFAULT NULL, metadata_9 text DEFAULT NULL, metadata_10 text DEFAULT NULL, - gdpr jsonb NOT NULL DEFAULT '{ + gdpr jsonb NOT NULL DEFAULT'{ "maskEmails": true, "sampleRate": 33, "maskNumbers": false, "defaultInputMode": "plain" - }'::jsonb -- ?????? + }'::jsonb ); - CREATE INDEX projects_project_key_idx ON public.projects (project_key); + + CREATE INDEX IF NOT EXISTS projects_project_key_idx ON public.projects (project_key); + DROP TRIGGER IF EXISTS on_insert_or_update ON projects; CREATE TRIGGER on_insert_or_update AFTER INSERT OR UPDATE ON projects FOR EACH ROW EXECUTE PROCEDURE notify_project(); - CREATE TABLE roles_projects + CREATE TABLE IF NOT EXISTS roles_projects ( role_id integer NOT NULL REFERENCES roles (role_id) ON DELETE CASCADE, project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE, CONSTRAINT roles_projects_pkey PRIMARY KEY (role_id, project_id) ); - CREATE INDEX roles_projects_role_id_idx ON roles_projects (role_id); - CREATE INDEX roles_projects_project_id_idx ON roles_projects (project_id); + CREATE INDEX IF NOT EXISTS roles_projects_role_id_idx ON roles_projects (role_id); + CREATE INDEX IF NOT EXISTS roles_projects_project_id_idx ON roles_projects (project_id); --- --- webhooks.sql --- - create type webhook_type as enum ('webhook', 'slack', 'email'); + BEGIN + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'webhook_type') THEN + create type webhook_type as enum ('webhook','slack','email'); + END IF; + END; - create table webhooks + + create table IF NOT EXISTS webhooks ( webhook_id integer generated by default as identity constraint webhooks_pkey @@ -325,10 +364,8 @@ $$ name varchar(100) ); --- --- notifications.sql --- - - CREATE TABLE notifications + CREATE TABLE IF NOT EXISTS notifications ( notification_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, tenant_id integer REFERENCES tenants (tenant_id) ON DELETE CASCADE, @@ -339,25 +376,24 @@ $$ button_url text NULL, image_url text NULL, created_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()), - options jsonb NOT NULL DEFAULT '{}'::jsonb, + options jsonb NOT NULL DEFAULT'{}'::jsonb, CONSTRAINT notification_tenant_xor_user CHECK ( tenant_id NOTNULL AND user_id ISNULL OR tenant_id ISNULL AND user_id NOTNULL ) ); - CREATE INDEX notifications_user_id_index ON notifications (user_id); - CREATE INDEX notifications_tenant_id_index ON notifications (tenant_id); - CREATE INDEX notifications_created_at_index ON notifications (created_at DESC); - CREATE INDEX notifications_created_at_epoch_idx ON notifications (CAST(EXTRACT(EPOCH FROM created_at) * 1000 AS BIGINT) DESC); + CREATE INDEX IF NOT EXISTS notifications_user_id_index ON notifications (user_id); + CREATE INDEX IF NOT EXISTS notifications_tenant_id_index ON notifications (tenant_id); + CREATE INDEX IF NOT EXISTS notifications_created_at_index ON notifications (created_at DESC); + CREATE INDEX IF NOT EXISTS notifications_created_at_epoch_idx ON notifications (CAST(EXTRACT(EPOCH FROM created_at) * 1000 AS BIGINT) DESC); - CREATE TABLE user_viewed_notifications + CREATE TABLE IF NOT EXISTS user_viewed_notifications ( user_id integer NOT NULL REFERENCES users (user_id) on delete cascade, notification_id integer NOT NULL REFERENCES notifications (notification_id) on delete cascade, constraint user_viewed_notifications_pkey primary key (user_id, notification_id) ); --- --- funnels.sql --- - CREATE TABLE funnels + CREATE TABLE IF NOT EXISTS funnels ( funnel_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE, @@ -369,14 +405,18 @@ $$ is_public boolean NOT NULL DEFAULT False ); - CREATE INDEX funnels_user_id_is_public_idx ON public.funnels (user_id, is_public); - CREATE INDEX funnels_project_id_idx ON public.funnels (project_id); + CREATE INDEX IF NOT EXISTS funnels_user_id_is_public_idx ON public.funnels (user_id, is_public); + CREATE INDEX IF NOT EXISTS funnels_project_id_idx ON public.funnels (project_id); --- --- announcements.sql --- + BEGIN + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'announcement_type') THEN + create type announcement_type as enum ('notification','alert'); + END IF; + END; - create type announcement_type as enum ('notification', 'alert'); - - create table announcements + create table IF NOT EXISTS announcements ( announcement_id serial not null constraint announcements_pk @@ -390,18 +430,25 @@ $$ type announcement_type default 'notification'::announcement_type not null ); --- --- integrations.sql --- + BEGIN + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'integration_provider') THEN + CREATE TYPE integration_provider AS ENUM ('bugsnag','cloudwatch','datadog','newrelic','rollbar','sentry','stackdriver','sumologic','elasticsearch'); --,'jira','github'); + END IF; + END; - CREATE TYPE integration_provider AS ENUM ('bugsnag', 'cloudwatch', 'datadog', 'newrelic', 'rollbar', 'sentry', 'stackdriver', 'sumologic', 'elasticsearch'); --, 'jira', 'github'); - CREATE TABLE integrations + CREATE TABLE IF NOT EXISTS integrations ( project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE, provider integration_provider NOT NULL, options jsonb NOT NULL, - request_data jsonb NOT NULL DEFAULT '{}'::jsonb, + request_data jsonb NOT NULL DEFAULT'{}'::jsonb, PRIMARY KEY (project_id, provider) ); + DROP TRIGGER IF EXISTS on_insert_or_update_or_delete ON integrations; + CREATE TRIGGER on_insert_or_update_or_delete AFTER INSERT OR UPDATE OR DELETE ON integrations @@ -409,7 +456,7 @@ $$ EXECUTE PROCEDURE notify_integration(); - create table jira_cloud + CREATE TABLE IF NOT EXISTS jira_cloud ( user_id integer not null constraint jira_cloud_pk @@ -422,32 +469,35 @@ $$ url text ); + BEGIN + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'issue_type') THEN + CREATE TYPE issue_type AS ENUM ( + 'click_rage', + 'dead_click', + 'excessive_scrolling', + 'bad_request', + 'missing_resource', + 'memory', + 'cpu', + 'slow_resource', + 'slow_page_load', + 'crash', + 'ml_cpu', + 'ml_memory', + 'ml_dead_click', + 'ml_click_rage', + 'ml_mouse_thrashing', + 'ml_excessive_scrolling', + 'ml_slow_resources', + 'custom', + 'js_exception' + ); + END IF; + END; --- --- issues.sql --- - - CREATE TYPE issue_type AS ENUM ( - 'click_rage', - 'dead_click', - 'excessive_scrolling', - 'bad_request', - 'missing_resource', - 'memory', - 'cpu', - 'slow_resource', - 'slow_page_load', - 'crash', - 'ml_cpu', - 'ml_memory', - 'ml_dead_click', - 'ml_click_rage', - 'ml_mouse_thrashing', - 'ml_excessive_scrolling', - 'ml_slow_resources', - 'custom', - 'js_exception' - ); - - CREATE TABLE issues + CREATE TABLE IF NOT EXISTS issues ( issue_id text NOT NULL PRIMARY KEY, project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE, @@ -455,16 +505,26 @@ $$ context_string text NOT NULL, context jsonb DEFAULT NULL ); - CREATE INDEX issues_issue_id_type_idx ON issues (issue_id, type); - CREATE INDEX issues_context_string_gin_idx ON public.issues USING GIN (context_string gin_trgm_ops); - CREATE INDEX issues_project_id_issue_id_idx ON public.issues (project_id, issue_id); - CREATE INDEX issues_project_id_idx ON issues (project_id); + CREATE INDEX IF NOT EXISTS issues_issue_id_type_idx ON issues (issue_id, type); + CREATE INDEX IF NOT EXISTS issues_context_string_gin_idx ON public.issues USING GIN (context_string gin_trgm_ops); + CREATE INDEX IF NOT EXISTS issues_project_id_issue_id_idx ON public.issues (project_id, issue_id); + CREATE INDEX IF NOT EXISTS issues_project_id_idx ON issues (project_id); --- --- errors.sql --- - - CREATE TYPE error_source AS ENUM ('js_exception', 'bugsnag', 'cloudwatch', 'datadog', 'newrelic', 'rollbar', 'sentry', 'stackdriver', 'sumologic'); - CREATE TYPE error_status AS ENUM ('unresolved', 'resolved', 'ignored'); - CREATE TABLE errors + BEGIN + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'error_source') THEN + CREATE TYPE error_source AS ENUM ('js_exception','bugsnag','cloudwatch','datadog','newrelic','rollbar','sentry','stackdriver','sumologic'); + END IF; + END; + BEGIN + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'error_status') THEN + CREATE TYPE error_status AS ENUM ('unresolved','resolved','ignored'); + END IF; + END; + CREATE TABLE IF NOT EXISTS errors ( error_id text NOT NULL PRIMARY KEY, project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE, @@ -477,40 +537,54 @@ $$ stacktrace jsonb, --to save the stacktrace and not query S3 another time stacktrace_parsed_at timestamp ); - CREATE INDEX errors_project_id_source_idx ON errors (project_id, source); - CREATE INDEX errors_message_gin_idx ON public.errors USING GIN (message gin_trgm_ops); - CREATE INDEX errors_name_gin_idx ON public.errors USING GIN (name gin_trgm_ops); - CREATE INDEX errors_project_id_idx ON public.errors (project_id); - CREATE INDEX errors_project_id_status_idx ON public.errors (project_id, status); - CREATE INDEX errors_project_id_error_id_js_exception_idx ON public.errors (project_id, error_id) WHERE source = 'js_exception'; - CREATE INDEX errors_project_id_error_id_idx ON public.errors (project_id, error_id); - CREATE INDEX errors_project_id_error_id_integration_idx ON public.errors (project_id, error_id) WHERE source != 'js_exception'; - CREATE INDEX errors_error_id_idx ON errors (error_id); - CREATE INDEX errors_parent_error_id_idx ON errors (parent_error_id); + CREATE INDEX IF NOT EXISTS errors_project_id_source_idx ON errors (project_id, source); + CREATE INDEX IF NOT EXISTS errors_message_gin_idx ON public.errors USING GIN (message gin_trgm_ops); + CREATE INDEX IF NOT EXISTS errors_name_gin_idx ON public.errors USING GIN (name gin_trgm_ops); + CREATE INDEX IF NOT EXISTS errors_project_id_idx ON public.errors (project_id); + CREATE INDEX IF NOT EXISTS errors_project_id_status_idx ON public.errors (project_id, status); + CREATE INDEX IF NOT EXISTS errors_project_id_error_id_js_exception_idx ON public.errors (project_id, error_id) WHERE source = 'js_exception'; + CREATE INDEX IF NOT EXISTS errors_project_id_error_id_idx ON public.errors (project_id, error_id); + CREATE INDEX IF NOT EXISTS errors_project_id_error_id_integration_idx ON public.errors (project_id, error_id) WHERE source != 'js_exception'; + CREATE INDEX IF NOT EXISTS errors_error_id_idx ON errors (error_id); + CREATE INDEX IF NOT EXISTS errors_parent_error_id_idx ON errors (parent_error_id); - CREATE TABLE user_favorite_errors + CREATE TABLE IF NOT EXISTS user_favorite_errors ( user_id integer NOT NULL REFERENCES users (user_id) ON DELETE CASCADE, error_id text NOT NULL REFERENCES errors (error_id) ON DELETE CASCADE, PRIMARY KEY (user_id, error_id) ); - CREATE TABLE user_viewed_errors + CREATE TABLE IF NOT EXISTS user_viewed_errors ( user_id integer NOT NULL REFERENCES users (user_id) ON DELETE CASCADE, error_id text NOT NULL REFERENCES errors (error_id) ON DELETE CASCADE, PRIMARY KEY (user_id, error_id) ); - CREATE INDEX user_viewed_errors_user_id_idx ON public.user_viewed_errors (user_id); - CREATE INDEX user_viewed_errors_error_id_idx ON public.user_viewed_errors (error_id); - - --- --- sessions.sql --- - CREATE TYPE device_type AS ENUM ('desktop', 'tablet', 'mobile', 'other'); - CREATE TYPE country AS ENUM ('UN', 'RW', 'SO', 'YE', 'IQ', 'SA', 'IR', 'CY', 'TZ', 'SY', 'AM', 'KE', 'CD', 'DJ', 'UG', 'CF', 'SC', 'JO', 'LB', 'KW', 'OM', 'QA', 'BH', 'AE', 'IL', 'TR', 'ET', 'ER', 'EG', 'SD', 'GR', 'BI', 'EE', 'LV', 'AZ', 'LT', 'SJ', 'GE', 'MD', 'BY', 'FI', 'AX', 'UA', 'MK', 'HU', 'BG', 'AL', 'PL', 'RO', 'XK', 'ZW', 'ZM', 'KM', 'MW', 'LS', 'BW', 'MU', 'SZ', 'RE', 'ZA', 'YT', 'MZ', 'MG', 'AF', 'PK', 'BD', 'TM', 'TJ', 'LK', 'BT', 'IN', 'MV', 'IO', 'NP', 'MM', 'UZ', 'KZ', 'KG', 'TF', 'HM', 'CC', 'PW', 'VN', 'TH', 'ID', 'LA', 'TW', 'PH', 'MY', 'CN', 'HK', 'BN', 'MO', 'KH', 'KR', 'JP', 'KP', 'SG', 'CK', 'TL', 'RU', 'MN', 'AU', 'CX', 'MH', 'FM', 'PG', 'SB', 'TV', 'NR', 'VU', 'NC', 'NF', 'NZ', 'FJ', 'LY', 'CM', 'SN', 'CG', 'PT', 'LR', 'CI', 'GH', 'GQ', 'NG', 'BF', 'TG', 'GW', 'MR', 'BJ', 'GA', 'SL', 'ST', 'GI', 'GM', 'GN', 'TD', 'NE', 'ML', 'EH', 'TN', 'ES', 'MA', 'MT', 'DZ', 'FO', 'DK', 'IS', 'GB', 'CH', 'SE', 'NL', 'AT', 'BE', 'DE', 'LU', 'IE', 'MC', 'FR', 'AD', 'LI', 'JE', 'IM', 'GG', 'SK', 'CZ', 'NO', 'VA', 'SM', 'IT', 'SI', 'ME', 'HR', 'BA', 'AO', 'NA', 'SH', 'BV', 'BB', 'CV', 'GY', 'GF', 'SR', 'PM', 'GL', 'PY', 'UY', 'BR', 'FK', 'GS', 'JM', 'DO', 'CU', 'MQ', 'BS', 'BM', 'AI', 'TT', 'KN', 'DM', 'AG', 'LC', 'TC', 'AW', 'VG', 'VC', 'MS', 'MF', 'BL', 'GP', 'GD', 'KY', 'BZ', 'SV', 'GT', 'HN', 'NI', 'CR', 'VE', 'EC', 'CO', 'PA', 'HT', 'AR', 'CL', 'BO', 'PE', 'MX', 'PF', 'PN', 'KI', 'TK', 'TO', 'WF', 'WS', 'NU', 'MP', 'GU', 'PR', 'VI', 'UM', 'AS', 'CA', 'US', 'PS', 'RS', 'AQ', 'SX', 'CW', 'BQ', 'SS'); - CREATE TYPE platform AS ENUM ('web','ios','android'); - - CREATE TABLE sessions + CREATE INDEX IF NOT EXISTS user_viewed_errors_user_id_idx ON public.user_viewed_errors (user_id); + CREATE INDEX IF NOT EXISTS user_viewed_errors_error_id_idx ON public.user_viewed_errors (error_id); + BEGIN + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'platform') THEN + CREATE TYPE platform AS ENUM ('web','ios','android'); + END IF; + END; + BEGIN + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'device_type') THEN + CREATE TYPE device_type AS ENUM ('desktop','tablet','mobile','other'); + END IF; + END; + BEGIN + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'country') THEN + CREATE TYPE country AS ENUM ('UN','RW','SO','YE','IQ','SA','IR','CY','TZ','SY','AM','KE','CD','DJ','UG','CF','SC','JO','LB','KW','OM','QA','BH','AE','IL','TR','ET','ER','EG','SD','GR','BI','EE','LV','AZ','LT','SJ','GE','MD','BY','FI','AX','UA','MK','HU','BG','AL','PL','RO','XK','ZW','ZM','KM','MW','LS','BW','MU','SZ','RE','ZA','YT','MZ','MG','AF','PK','BD','TM','TJ','LK','BT','IN','MV','IO','NP','MM','UZ','KZ','KG','TF','HM','CC','PW','VN','TH','ID','LA','TW','PH','MY','CN','HK','BN','MO','KH','KR','JP','KP','SG','CK','TL','RU','MN','AU','CX','MH','FM','PG','SB','TV','NR','VU','NC','NF','NZ','FJ','LY','CM','SN','CG','PT','LR','CI','GH','GQ','NG','BF','TG','GW','MR','BJ','GA','SL','ST','GI','GM','GN','TD','NE','ML','EH','TN','ES','MA','MT','DZ','FO','DK','IS','GB','CH','SE','NL','AT','BE','DE','LU','IE','MC','FR','AD','LI','JE','IM','GG','SK','CZ','NO','VA','SM','IT','SI','ME','HR','BA','AO','NA','SH','BV','BB','CV','GY','GF','SR','PM','GL','PY','UY','BR','FK','GS','JM','DO','CU','MQ','BS','BM','AI','TT','KN','DM','AG','LC','TC','AW','VG','VC','MS','MF','BL','GP','GD','KY','BZ','SV','GT','HN','NI','CR','VE','EC','CO','PA','HT','AR','CL','BO','PE','MX','PF','PN','KI','TK','TO','WF','WS','NU','MP','GU','PR','VI','UM','AS','CA','US','PS','RS','AQ','SX','CW','BQ','SS'); + END IF; + END; + CREATE TABLE IF NOT EXISTS sessions ( session_id bigint PRIMARY KEY, project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE, @@ -552,157 +626,262 @@ $$ metadata_8 text DEFAULT NULL, metadata_9 text DEFAULT NULL, metadata_10 text DEFAULT NULL --- , --- rehydration_id integer REFERENCES rehydrations(rehydration_id) ON DELETE SET NULL ); - CREATE INDEX sessions_project_id_start_ts_idx ON sessions (project_id, start_ts); - CREATE INDEX sessions_project_id_user_id_idx ON sessions (project_id, user_id); - CREATE INDEX sessions_project_id_user_anonymous_id_idx ON sessions (project_id, user_anonymous_id); - CREATE INDEX sessions_project_id_user_device_idx ON sessions (project_id, user_device); - CREATE INDEX sessions_project_id_user_country_idx ON sessions (project_id, user_country); - CREATE INDEX sessions_project_id_user_browser_idx ON sessions (project_id, user_browser); - CREATE INDEX sessions_project_id_metadata_1_idx ON sessions (project_id, metadata_1); - CREATE INDEX sessions_project_id_metadata_2_idx ON sessions (project_id, metadata_2); - CREATE INDEX sessions_project_id_metadata_3_idx ON sessions (project_id, metadata_3); - CREATE INDEX sessions_project_id_metadata_4_idx ON sessions (project_id, metadata_4); - CREATE INDEX sessions_project_id_metadata_5_idx ON sessions (project_id, metadata_5); - CREATE INDEX sessions_project_id_metadata_6_idx ON sessions (project_id, metadata_6); - CREATE INDEX sessions_project_id_metadata_7_idx ON sessions (project_id, metadata_7); - CREATE INDEX sessions_project_id_metadata_8_idx ON sessions (project_id, metadata_8); - CREATE INDEX sessions_project_id_metadata_9_idx ON sessions (project_id, metadata_9); - CREATE INDEX sessions_project_id_metadata_10_idx ON sessions (project_id, metadata_10); - CREATE INDEX sessions_project_id_watchdogs_score_idx ON sessions (project_id, watchdogs_score DESC); - CREATE INDEX sessions_platform_idx ON public.sessions (platform); + CREATE INDEX IF NOT EXISTS sessions_project_id_start_ts_idx ON sessions (project_id, start_ts); + CREATE INDEX IF NOT EXISTS sessions_project_id_user_id_idx ON sessions (project_id, user_id); + CREATE INDEX IF NOT EXISTS sessions_project_id_user_anonymous_id_idx ON sessions (project_id, user_anonymous_id); + CREATE INDEX IF NOT EXISTS sessions_project_id_user_device_idx ON sessions (project_id, user_device); + CREATE INDEX IF NOT EXISTS sessions_project_id_user_country_idx ON sessions (project_id, user_country); + CREATE INDEX IF NOT EXISTS sessions_project_id_user_browser_idx ON sessions (project_id, user_browser); + CREATE INDEX IF NOT EXISTS sessions_project_id_metadata_1_idx ON sessions (project_id, metadata_1); + CREATE INDEX IF NOT EXISTS sessions_project_id_metadata_2_idx ON sessions (project_id, metadata_2); + CREATE INDEX IF NOT EXISTS sessions_project_id_metadata_3_idx ON sessions (project_id, metadata_3); + CREATE INDEX IF NOT EXISTS sessions_project_id_metadata_4_idx ON sessions (project_id, metadata_4); + CREATE INDEX IF NOT EXISTS sessions_project_id_metadata_5_idx ON sessions (project_id, metadata_5); + CREATE INDEX IF NOT EXISTS sessions_project_id_metadata_6_idx ON sessions (project_id, metadata_6); + CREATE INDEX IF NOT EXISTS sessions_project_id_metadata_7_idx ON sessions (project_id, metadata_7); + CREATE INDEX IF NOT EXISTS sessions_project_id_metadata_8_idx ON sessions (project_id, metadata_8); + CREATE INDEX IF NOT EXISTS sessions_project_id_metadata_9_idx ON sessions (project_id, metadata_9); + CREATE INDEX IF NOT EXISTS sessions_project_id_metadata_10_idx ON sessions (project_id, metadata_10); + CREATE INDEX IF NOT EXISTS sessions_project_id_watchdogs_score_idx ON sessions (project_id, watchdogs_score DESC); + CREATE INDEX IF NOT EXISTS sessions_platform_idx ON public.sessions (platform); - CREATE INDEX sessions_metadata1_gin_idx ON public.sessions USING GIN (metadata_1 gin_trgm_ops); - CREATE INDEX sessions_metadata2_gin_idx ON public.sessions USING GIN (metadata_2 gin_trgm_ops); - CREATE INDEX sessions_metadata3_gin_idx ON public.sessions USING GIN (metadata_3 gin_trgm_ops); - CREATE INDEX sessions_metadata4_gin_idx ON public.sessions USING GIN (metadata_4 gin_trgm_ops); - CREATE INDEX sessions_metadata5_gin_idx ON public.sessions USING GIN (metadata_5 gin_trgm_ops); - CREATE INDEX sessions_metadata6_gin_idx ON public.sessions USING GIN (metadata_6 gin_trgm_ops); - CREATE INDEX sessions_metadata7_gin_idx ON public.sessions USING GIN (metadata_7 gin_trgm_ops); - CREATE INDEX sessions_metadata8_gin_idx ON public.sessions USING GIN (metadata_8 gin_trgm_ops); - CREATE INDEX sessions_metadata9_gin_idx ON public.sessions USING GIN (metadata_9 gin_trgm_ops); - CREATE INDEX sessions_metadata10_gin_idx ON public.sessions USING GIN (metadata_10 gin_trgm_ops); - CREATE INDEX sessions_user_os_gin_idx ON public.sessions USING GIN (user_os gin_trgm_ops); - CREATE INDEX sessions_user_browser_gin_idx ON public.sessions USING GIN (user_browser gin_trgm_ops); - CREATE INDEX sessions_user_device_gin_idx ON public.sessions USING GIN (user_device gin_trgm_ops); - CREATE INDEX sessions_user_id_gin_idx ON public.sessions USING GIN (user_id gin_trgm_ops); - CREATE INDEX sessions_user_anonymous_id_gin_idx ON public.sessions USING GIN (user_anonymous_id gin_trgm_ops); - CREATE INDEX sessions_user_country_gin_idx ON public.sessions (project_id, user_country); - CREATE INDEX sessions_start_ts_idx ON public.sessions (start_ts) WHERE duration > 0; - CREATE INDEX sessions_project_id_idx ON public.sessions (project_id) WHERE duration > 0; - CREATE INDEX sessions_session_id_project_id_start_ts_idx ON sessions (session_id, project_id, start_ts) WHERE duration > 0; - CREATE INDEX sessions_session_id_project_id_start_ts_durationNN_idx ON sessions (session_id, project_id, start_ts) WHERE duration IS NOT NULL; - CREATE INDEX sessions_user_id_useridNN_idx ON sessions (user_id) WHERE user_id IS NOT NULL; - CREATE INDEX sessions_uid_projectid_startts_sessionid_uidNN_durGTZ_idx ON sessions (user_id, project_id, start_ts, session_id) WHERE user_id IS NOT NULL AND duration > 0; - CREATE INDEX sessions_utm_source_gin_idx ON public.sessions USING GIN (utm_source gin_trgm_ops); - CREATE INDEX sessions_utm_medium_gin_idx ON public.sessions USING GIN (utm_medium gin_trgm_ops); - CREATE INDEX sessions_utm_campaign_gin_idx ON public.sessions USING GIN (utm_campaign gin_trgm_ops); - - ALTER TABLE public.sessions - ADD CONSTRAINT web_browser_constraint CHECK ( - (sessions.platform = 'web' AND sessions.user_browser NOTNULL) OR - (sessions.platform != 'web' AND sessions.user_browser ISNULL)); - - ALTER TABLE public.sessions - ADD CONSTRAINT web_user_browser_version_constraint CHECK ( sessions.platform = 'web' OR sessions.user_browser_version ISNULL); - - ALTER TABLE public.sessions - ADD CONSTRAINT web_user_agent_constraint CHECK ( - (sessions.platform = 'web' AND sessions.user_agent NOTNULL) OR - (sessions.platform != 'web' AND sessions.user_agent ISNULL)); - - - CREATE TABLE user_viewed_sessions + CREATE INDEX IF NOT EXISTS sessions_metadata1_gin_idx ON public.sessions USING GIN (metadata_1 gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_metadata2_gin_idx ON public.sessions USING GIN (metadata_2 gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_metadata3_gin_idx ON public.sessions USING GIN (metadata_3 gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_metadata4_gin_idx ON public.sessions USING GIN (metadata_4 gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_metadata5_gin_idx ON public.sessions USING GIN (metadata_5 gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_metadata6_gin_idx ON public.sessions USING GIN (metadata_6 gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_metadata7_gin_idx ON public.sessions USING GIN (metadata_7 gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_metadata8_gin_idx ON public.sessions USING GIN (metadata_8 gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_metadata9_gin_idx ON public.sessions USING GIN (metadata_9 gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_metadata10_gin_idx ON public.sessions USING GIN (metadata_10 gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_user_os_gin_idx ON public.sessions USING GIN (user_os gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_user_browser_gin_idx ON public.sessions USING GIN (user_browser gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_user_device_gin_idx ON public.sessions USING GIN (user_device gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_user_id_gin_idx ON public.sessions USING GIN (user_id gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_user_anonymous_id_gin_idx ON public.sessions USING GIN (user_anonymous_id gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_user_country_gin_idx ON public.sessions (project_id, user_country); + CREATE INDEX IF NOT EXISTS sessions_start_ts_idx ON public.sessions (start_ts) WHERE duration > 0; + CREATE INDEX IF NOT EXISTS sessions_project_id_idx ON public.sessions (project_id) WHERE duration > 0; + CREATE INDEX IF NOT EXISTS sessions_session_id_project_id_start_ts_idx ON sessions (session_id, project_id, start_ts) WHERE duration > 0; + CREATE INDEX IF NOT EXISTS sessions_session_id_project_id_start_ts_durationNN_idx ON sessions (session_id, project_id, start_ts) WHERE duration IS NOT NULL; + CREATE INDEX IF NOT EXISTS sessions_user_id_useridNN_idx ON sessions (user_id) WHERE user_id IS NOT NULL; + CREATE INDEX IF NOT EXISTS sessions_uid_projectid_startts_sessionid_uidNN_durGTZ_idx ON sessions (user_id, project_id, start_ts, session_id) WHERE user_id IS NOT NULL AND duration > 0; + CREATE INDEX IF NOT EXISTS sessions_utm_source_gin_idx ON public.sessions USING GIN (utm_source gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_utm_medium_gin_idx ON public.sessions USING GIN (utm_medium gin_trgm_ops); + CREATE INDEX IF NOT EXISTS sessions_utm_campaign_gin_idx ON public.sessions USING GIN (utm_campaign gin_trgm_ops); + BEGIN + ALTER TABLE public.sessions + ADD CONSTRAINT web_browser_constraint CHECK ( + (sessions.platform = 'web' AND sessions.user_browser NOTNULL) OR + (sessions.platform != 'web' AND sessions.user_browser ISNULL)); + EXCEPTION + WHEN duplicate_object THEN RAISE NOTICE 'Table constraint exists'; + END; + BEGIN + ALTER TABLE public.sessions + ADD CONSTRAINT web_user_browser_version_constraint CHECK ( + sessions.platform = 'web' OR sessions.user_browser_version ISNULL); + EXCEPTION + WHEN duplicate_object THEN RAISE NOTICE 'Table constraint exists'; + END; + BEGIN + ALTER TABLE public.sessions + ADD CONSTRAINT web_user_agent_constraint CHECK ( + (sessions.platform = 'web' AND sessions.user_agent NOTNULL) OR + (sessions.platform != 'web' AND sessions.user_agent ISNULL)); + EXCEPTION + WHEN duplicate_object THEN RAISE NOTICE 'Table constraint already exists'; + END; + CREATE TABLE IF NOT EXISTS user_viewed_sessions ( user_id integer NOT NULL REFERENCES users (user_id) ON DELETE CASCADE, session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, PRIMARY KEY (user_id, session_id) ); - CREATE TABLE user_favorite_sessions + CREATE TABLE IF NOT EXISTS user_favorite_sessions ( user_id integer NOT NULL REFERENCES users (user_id) ON DELETE CASCADE, session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, PRIMARY KEY (user_id, session_id) ); - CREATE INDEX user_favorite_sessions_user_id_session_id_idx ON user_favorite_sessions (user_id, session_id); + CREATE INDEX IF NOT EXISTS user_favorite_sessions_user_id_session_id_idx ON user_favorite_sessions (user_id, session_id); --- --- assignments.sql --- - create table assigned_sessions + CREATE TABLE IF NOT EXISTS assigned_sessions ( session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, issue_id text NOT NULL, provider oauth_provider NOT NULL, created_by integer NOT NULL, created_at timestamp default timezone('utc'::text, now()) NOT NULL, - provider_data jsonb default '{}'::jsonb NOT NULL + provider_data jsonb default'{}'::jsonb NOT NULL ); - CREATE INDEX assigned_sessions_session_id_idx ON assigned_sessions (session_id); + CREATE INDEX IF NOT EXISTS assigned_sessions_session_id_idx ON assigned_sessions (session_id); --- --- events_common.sql --- - CREATE SCHEMA IF NOT EXISTS events_common; - - CREATE TYPE events_common.custom_level AS ENUM ('info','error'); - - CREATE TABLE events_common.customs + CREATE TABLE IF NOT EXISTS autocomplete ( - session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, - timestamp bigint NOT NULL, - seq_index integer NOT NULL, - name text NOT NULL, - payload jsonb NOT NULL, - level events_common.custom_level NOT NULL DEFAULT 'info', - PRIMARY KEY (session_id, timestamp, seq_index) + value text NOT NULL, + type text NOT NULL, + project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE ); - CREATE INDEX customs_name_idx ON events_common.customs (name); - CREATE INDEX customs_name_gin_idx ON events_common.customs USING GIN (name gin_trgm_ops); - CREATE INDEX customs_timestamp_idx ON events_common.customs (timestamp); + CREATE unique index IF NOT EXISTS autocomplete_unique ON autocomplete (project_id, value, type); + CREATE index IF NOT EXISTS autocomplete_project_id_idx ON autocomplete (project_id); + CREATE INDEX IF NOT EXISTS autocomplete_type_idx ON public.autocomplete (type); + CREATE INDEX IF NOT EXISTS autocomplete_value_gin_idx ON public.autocomplete USING GIN (value gin_trgm_ops); - CREATE TABLE events_common.issues + BEGIN + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'job_status') THEN + CREATE TYPE job_status AS ENUM ('scheduled','running','cancelled','failed','completed'); + END IF; + END; + BEGIN + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'job_action') THEN + CREATE TYPE job_action AS ENUM ('delete_user_data'); + END IF; + END; + CREATE TABLE IF NOT EXISTS jobs ( - session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, - timestamp bigint NOT NULL, - seq_index integer NOT NULL, - issue_id text NOT NULL REFERENCES issues (issue_id) ON DELETE CASCADE, - payload jsonb DEFAULT NULL, - PRIMARY KEY (session_id, timestamp, seq_index) + job_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, + description text NOT NULL, + status job_status NOT NULL, + project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE, + action job_action NOT NULL, + reference_id text NOT NULL, + created_at timestamp default timezone('utc'::text, now()) NOT NULL, + updated_at timestamp default timezone('utc'::text, now()) NULL, + start_at timestamp NOT NULL, + errors text NULL ); - CREATE INDEX issues_issue_id_timestamp_idx ON events_common.issues (issue_id, timestamp); - CREATE INDEX issues_timestamp_idx ON events_common.issues (timestamp); + CREATE INDEX IF NOT EXISTS jobs_status_idx ON jobs (status); + CREATE INDEX IF NOT EXISTS jobs_start_at_idx ON jobs (start_at); + CREATE INDEX IF NOT EXISTS jobs_project_id_idx ON jobs (project_id); - CREATE TABLE events_common.requests + CREATE TABLE IF NOT EXISTS traces ( - session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, - timestamp bigint NOT NULL, - seq_index integer NOT NULL, - url text NOT NULL, - duration integer NOT NULL, - success boolean NOT NULL, - PRIMARY KEY (session_id, timestamp, seq_index) + user_id integer NULL REFERENCES users (user_id) ON DELETE CASCADE, + tenant_id integer NOT NULL REFERENCES tenants (tenant_id) ON DELETE CASCADE, + created_at bigint NOT NULL DEFAULT (EXTRACT(EPOCH FROM now() at time zone 'utc') * 1000)::bigint, + auth text NULL, + action text NOT NULL, + method text NOT NULL, + path_format text NOT NULL, + endpoint text NOT NULL, + payload jsonb NULL, + parameters jsonb NULL, + status int NULL ); - CREATE INDEX requests_url_idx ON events_common.requests (url); - CREATE INDEX requests_duration_idx ON events_common.requests (duration); - CREATE INDEX requests_url_gin_idx ON events_common.requests USING GIN (url gin_trgm_ops); - CREATE INDEX requests_timestamp_idx ON events_common.requests (timestamp); - CREATE INDEX requests_url_gin_idx2 ON events_common.requests USING GIN (RIGHT(url, length(url) - (CASE - WHEN url LIKE 'http://%' - THEN 7 - WHEN url LIKE 'https://%' - THEN 8 - ELSE 0 END)) - gin_trgm_ops); - CREATE INDEX requests_timestamp_session_id_failed_idx ON events_common.requests (timestamp, session_id) WHERE success = FALSE; + CREATE INDEX IF NOT EXISTS traces_user_id_idx ON traces (user_id); + CREATE INDEX IF NOT EXISTS traces_tenant_id_idx ON traces (tenant_id); --- --- events.sql --- - CREATE SCHEMA IF NOT EXISTS events; + 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, + user_id integer REFERENCES users (user_id) ON DELETE SET NULL, + name text NOT NULL, + is_public boolean NOT NULL DEFAULT FALSE, + created_at timestamp default timezone('utc'::text, now()) not null, + deleted_at timestamp + ); + 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 + ( + series_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, + metric_id integer REFERENCES metrics (metric_id) ON DELETE CASCADE, + index integer NOT NULL, + name text NULL, + filter jsonb NOT NULL, + created_at timestamp DEFAULT timezone('utc'::text, now()) NOT NULL, + deleted_at timestamp + ); + CREATE INDEX IF NOT EXISTS metric_series_metric_id_idx ON public.metric_series (metric_id); - CREATE TABLE events.pages + CREATE TABLE IF NOT EXISTS searches + ( + search_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 CASCADE, + name text not null, + filter jsonb not null, + created_at timestamp default timezone('utc'::text, now()) not null, + deleted_at timestamp, + is_public boolean NOT NULL DEFAULT False + ); + + CREATE INDEX IF NOT EXISTS searches_user_id_is_public_idx ON public.searches (user_id, is_public); + CREATE INDEX IF NOT EXISTS searches_project_id_idx ON public.searches (project_id); + + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'alert_detection_method') THEN + CREATE TYPE alert_detection_method AS ENUM ('threshold', 'change'); + END IF; + CREATE TABLE IF NOT EXISTS alerts + ( + alert_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, + project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE, + series_id integer NULL REFERENCES metric_series (series_id) ON DELETE CASCADE, + name text NOT NULL, + description text NULL DEFAULT NULL, + active boolean NOT NULL DEFAULT TRUE, + detection_method alert_detection_method NOT NULL, + query jsonb NOT NULL, + deleted_at timestamp NULL DEFAULT NULL, + created_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()), + options jsonb NOT NULL DEFAULT'{ + "renotifyInterval": 1440 + }'::jsonb + ); + CREATE INDEX IF NOT EXISTS alerts_project_id_idx ON alerts (project_id); + CREATE INDEX IF NOT EXISTS alerts_series_id_idx ON alerts (series_id); + + DROP TRIGGER IF EXISTS on_insert_or_update_or_delete ON alerts; + + CREATE TRIGGER on_insert_or_update_or_delete + AFTER INSERT OR UPDATE OR DELETE + ON alerts + FOR EACH ROW + EXECUTE PROCEDURE notify_alert(); + + RAISE NOTICE 'Created missing public schema tables'; + END IF; + END; + +$$ +LANGUAGE plpgsql; + + +DO +$$ + BEGIN + IF (with to_check (name) as ( + values ('clicks'), + ('errors'), + ('graphql'), + ('inputs'), + ('pages'), + ('performance'), + ('resources'), + ('state_actions') + ) + select bool_and(exists(select * + from information_schema.tables t + where table_schema = 'events' + AND table_name = to_check.name)) as all_present + from to_check) THEN + raise notice 'All events schema tables exists'; + ELSE + CREATE TABLE IF NOT EXISTS events.pages ( session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, message_id bigint NOT NULL, @@ -725,48 +904,49 @@ $$ ttfb integer DEFAULT NULL, PRIMARY KEY (session_id, message_id) ); - CREATE INDEX pages_session_id_idx ON events.pages (session_id); - CREATE INDEX pages_base_path_gin_idx ON events.pages USING GIN (base_path gin_trgm_ops); - CREATE INDEX pages_base_referrer_gin_idx ON events.pages USING GIN (base_referrer gin_trgm_ops); - CREATE INDEX pages_timestamp_idx ON events.pages (timestamp); - CREATE INDEX pages_session_id_timestamp_idx ON events.pages (session_id, timestamp); - CREATE INDEX pages_base_path_gin_idx2 ON events.pages USING GIN (RIGHT(base_path, length(base_path) - 1) gin_trgm_ops); - CREATE INDEX pages_base_path_idx ON events.pages (base_path); - CREATE INDEX pages_base_path_idx2 ON events.pages (RIGHT(base_path, length(base_path) - 1)); - CREATE INDEX pages_base_referrer_idx ON events.pages (base_referrer); - CREATE INDEX pages_base_referrer_gin_idx2 ON events.pages USING GIN (RIGHT(base_referrer, - length(base_referrer) - (CASE - WHEN base_referrer LIKE 'http://%' - THEN 7 - WHEN base_referrer LIKE 'https://%' - THEN 8 - ELSE 0 END)) - gin_trgm_ops); - CREATE INDEX pages_response_time_idx ON events.pages (response_time); - CREATE INDEX pages_response_end_idx ON events.pages (response_end); - CREATE INDEX pages_path_gin_idx ON events.pages USING GIN (path gin_trgm_ops); - CREATE INDEX pages_path_idx ON events.pages (path); - CREATE INDEX pages_visually_complete_idx ON events.pages (visually_complete) WHERE visually_complete > 0; - CREATE INDEX pages_dom_building_time_idx ON events.pages (dom_building_time) WHERE dom_building_time > 0; - CREATE INDEX pages_load_time_idx ON events.pages (load_time) WHERE load_time > 0; - CREATE INDEX pages_first_contentful_paint_time_idx ON events.pages (first_contentful_paint_time) WHERE first_contentful_paint_time > 0; - CREATE INDEX pages_dom_content_loaded_time_idx ON events.pages (dom_content_loaded_time) WHERE dom_content_loaded_time > 0; - CREATE INDEX pages_first_paint_time_idx ON events.pages (first_paint_time) WHERE first_paint_time > 0; - CREATE INDEX pages_ttfb_idx ON events.pages (ttfb) WHERE ttfb > 0; - CREATE INDEX pages_time_to_interactive_idx ON events.pages (time_to_interactive) WHERE time_to_interactive > 0; - CREATE INDEX pages_session_id_timestamp_loadgt0NN_idx ON events.pages (session_id, timestamp) WHERE load_time > 0 AND load_time IS NOT NULL; - CREATE INDEX pages_session_id_timestamp_visualgt0nn_idx ON events.pages (session_id, timestamp) WHERE visually_complete > 0 AND visually_complete IS NOT NULL; - CREATE INDEX pages_timestamp_metgt0_idx ON events.pages (timestamp) WHERE response_time > 0 OR - first_paint_time > 0 OR - dom_content_loaded_time > 0 OR - ttfb > 0 OR - time_to_interactive > 0; - CREATE INDEX 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 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 pages_base_path_session_id_timestamp_idx ON events.pages (base_path, session_id, timestamp); - CREATE INDEX pages_base_path_base_pathLNGT2_idx ON events.pages (base_path) WHERE length(base_path) > 2; + CREATE INDEX IF NOT EXISTS pages_session_id_idx ON events.pages (session_id); + CREATE INDEX IF NOT EXISTS pages_base_path_gin_idx ON events.pages USING GIN (base_path gin_trgm_ops); + CREATE INDEX IF NOT EXISTS pages_base_referrer_gin_idx ON events.pages USING GIN (base_referrer gin_trgm_ops); + CREATE INDEX IF NOT EXISTS pages_timestamp_idx ON events.pages (timestamp); + CREATE INDEX IF NOT EXISTS pages_session_id_timestamp_idx ON events.pages (session_id, timestamp); + CREATE INDEX IF NOT EXISTS pages_base_path_gin_idx2 ON events.pages USING GIN (RIGHT(base_path, length(base_path) - 1) gin_trgm_ops); + CREATE INDEX IF NOT EXISTS pages_base_path_idx ON events.pages (base_path); + CREATE INDEX IF NOT EXISTS pages_base_path_idx2 ON events.pages (RIGHT(base_path, length(base_path) - 1)); + CREATE INDEX IF NOT EXISTS pages_base_referrer_idx ON events.pages (base_referrer); + CREATE INDEX IF NOT EXISTS pages_base_referrer_gin_idx2 ON events.pages USING GIN (RIGHT(base_referrer, + length(base_referrer) - + (CASE + WHEN base_referrer LIKE 'http://%' + THEN 7 + WHEN base_referrer LIKE 'https://%' + THEN 8 + ELSE 0 END)) + gin_trgm_ops); + CREATE INDEX IF NOT EXISTS pages_response_time_idx ON events.pages (response_time); + CREATE INDEX IF NOT EXISTS pages_response_end_idx ON events.pages (response_end); + CREATE INDEX IF NOT EXISTS pages_path_gin_idx ON events.pages USING GIN (path gin_trgm_ops); + CREATE INDEX IF NOT EXISTS pages_path_idx ON events.pages (path); + CREATE INDEX IF NOT EXISTS pages_visually_complete_idx ON events.pages (visually_complete) WHERE visually_complete > 0; + CREATE INDEX IF NOT EXISTS pages_dom_building_time_idx ON events.pages (dom_building_time) WHERE dom_building_time > 0; + CREATE INDEX IF NOT EXISTS pages_load_time_idx ON events.pages (load_time) WHERE load_time > 0; + CREATE INDEX IF NOT EXISTS pages_first_contentful_paint_time_idx ON events.pages (first_contentful_paint_time) WHERE first_contentful_paint_time > 0; + CREATE INDEX IF NOT EXISTS pages_dom_content_loaded_time_idx ON events.pages (dom_content_loaded_time) WHERE dom_content_loaded_time > 0; + CREATE INDEX IF NOT EXISTS pages_first_paint_time_idx ON events.pages (first_paint_time) WHERE first_paint_time > 0; + CREATE INDEX IF NOT EXISTS pages_ttfb_idx ON events.pages (ttfb) WHERE ttfb > 0; + CREATE INDEX IF NOT EXISTS pages_time_to_interactive_idx ON events.pages (time_to_interactive) WHERE time_to_interactive > 0; + 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 + ttfb > 0 OR + 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); + CREATE INDEX IF NOT EXISTS pages_base_path_base_pathLNGT2_idx ON events.pages (base_path) WHERE length(base_path) > 2; - CREATE TABLE events.clicks + CREATE TABLE IF NOT EXISTS events.clicks ( session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, message_id bigint NOT NULL, @@ -776,18 +956,18 @@ $$ selector text DEFAULT '' NOT NULL, PRIMARY KEY (session_id, message_id) ); - CREATE INDEX clicks_session_id_idx ON events.clicks (session_id); - CREATE INDEX clicks_label_idx ON events.clicks (label); - CREATE INDEX clicks_label_gin_idx ON events.clicks USING GIN (label gin_trgm_ops); - CREATE INDEX clicks_timestamp_idx ON events.clicks (timestamp); - CREATE INDEX clicks_label_session_id_timestamp_idx ON events.clicks (label, session_id, timestamp); - CREATE INDEX clicks_url_idx ON events.clicks (url); - CREATE INDEX clicks_url_gin_idx ON events.clicks USING GIN (url gin_trgm_ops); - CREATE INDEX clicks_url_session_id_timestamp_selector_idx ON events.clicks (url, session_id, timestamp, selector); - CREATE INDEX clicks_session_id_timestamp_idx ON events.clicks (session_id, timestamp); + CREATE INDEX IF NOT EXISTS clicks_session_id_idx ON events.clicks (session_id); + CREATE INDEX IF NOT EXISTS clicks_label_idx ON events.clicks (label); + CREATE INDEX IF NOT EXISTS clicks_label_gin_idx ON events.clicks USING GIN (label gin_trgm_ops); + CREATE INDEX IF NOT EXISTS clicks_timestamp_idx ON events.clicks (timestamp); + CREATE INDEX IF NOT EXISTS clicks_label_session_id_timestamp_idx ON events.clicks (label, session_id, timestamp); + CREATE INDEX IF NOT EXISTS clicks_url_idx ON events.clicks (url); + CREATE INDEX IF NOT EXISTS clicks_url_gin_idx ON events.clicks USING GIN (url gin_trgm_ops); + CREATE INDEX IF NOT EXISTS clicks_url_session_id_timestamp_selector_idx ON events.clicks (url, session_id, timestamp, selector); + CREATE INDEX IF NOT EXISTS clicks_session_id_timestamp_idx ON events.clicks (session_id, timestamp); - CREATE TABLE events.inputs + CREATE TABLE IF NOT EXISTS events.inputs ( session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, message_id bigint NOT NULL, @@ -796,14 +976,14 @@ $$ value text DEFAULT NULL, PRIMARY KEY (session_id, message_id) ); - CREATE INDEX inputs_session_id_idx ON events.inputs (session_id); - CREATE INDEX inputs_label_value_idx ON events.inputs (label, value); - CREATE INDEX inputs_label_gin_idx ON events.inputs USING GIN (label gin_trgm_ops); - CREATE INDEX inputs_label_idx ON events.inputs (label); - CREATE INDEX inputs_timestamp_idx ON events.inputs (timestamp); - CREATE INDEX inputs_label_session_id_timestamp_idx ON events.inputs (label, session_id, timestamp); + CREATE INDEX IF NOT EXISTS inputs_session_id_idx ON events.inputs (session_id); + CREATE INDEX IF NOT EXISTS inputs_label_value_idx ON events.inputs (label, value); + CREATE INDEX IF NOT EXISTS inputs_label_gin_idx ON events.inputs USING GIN (label gin_trgm_ops); + CREATE INDEX IF NOT EXISTS inputs_label_idx ON events.inputs (label); + CREATE INDEX IF NOT EXISTS inputs_timestamp_idx ON events.inputs (timestamp); + CREATE INDEX IF NOT EXISTS inputs_label_session_id_timestamp_idx ON events.inputs (label, session_id, timestamp); - CREATE TABLE events.errors + CREATE TABLE IF NOT EXISTS events.errors ( session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, message_id bigint NOT NULL, @@ -811,16 +991,16 @@ $$ error_id text NOT NULL REFERENCES errors (error_id) ON DELETE CASCADE, PRIMARY KEY (session_id, message_id) ); - CREATE INDEX errors_session_id_idx ON events.errors (session_id); - CREATE INDEX errors_timestamp_idx ON events.errors (timestamp); - CREATE INDEX errors_session_id_timestamp_error_id_idx ON events.errors (session_id, timestamp, error_id); - CREATE INDEX errors_error_id_timestamp_idx ON events.errors (error_id, timestamp); - CREATE INDEX errors_timestamp_error_id_session_id_idx ON events.errors (timestamp, error_id, session_id); - CREATE INDEX errors_error_id_timestamp_session_id_idx ON events.errors (error_id, timestamp, session_id); - CREATE INDEX errors_error_id_idx ON events.errors (error_id); + CREATE INDEX IF NOT EXISTS errors_session_id_idx ON events.errors (session_id); + CREATE INDEX IF NOT EXISTS errors_timestamp_idx ON events.errors (timestamp); + CREATE INDEX IF NOT EXISTS errors_session_id_timestamp_error_id_idx ON events.errors (session_id, timestamp, error_id); + CREATE INDEX IF NOT EXISTS errors_error_id_timestamp_idx ON events.errors (error_id, timestamp); + CREATE INDEX IF NOT EXISTS errors_timestamp_error_id_session_id_idx ON events.errors (timestamp, error_id, session_id); + CREATE INDEX IF NOT EXISTS errors_error_id_timestamp_session_id_idx ON events.errors (error_id, timestamp, session_id); + CREATE INDEX IF NOT EXISTS errors_error_id_idx ON events.errors (error_id); - CREATE TABLE events.graphql + CREATE TABLE IF NOT EXISTS events.graphql ( session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, message_id bigint NOT NULL, @@ -828,11 +1008,11 @@ $$ name text NOT NULL, PRIMARY KEY (session_id, message_id) ); - CREATE INDEX graphql_name_idx ON events.graphql (name); - CREATE INDEX graphql_name_gin_idx ON events.graphql USING GIN (name gin_trgm_ops); - CREATE INDEX graphql_timestamp_idx ON events.graphql (timestamp); + CREATE INDEX IF NOT EXISTS graphql_name_idx ON events.graphql (name); + CREATE INDEX IF NOT EXISTS graphql_name_gin_idx ON events.graphql USING GIN (name gin_trgm_ops); + CREATE INDEX IF NOT EXISTS graphql_timestamp_idx ON events.graphql (timestamp); - CREATE TABLE events.state_actions + CREATE TABLE IF NOT EXISTS events.state_actions ( session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, message_id bigint NOT NULL, @@ -840,13 +1020,21 @@ $$ name text NOT NULL, PRIMARY KEY (session_id, message_id) ); - CREATE INDEX state_actions_name_idx ON events.state_actions (name); - CREATE INDEX state_actions_name_gin_idx ON events.state_actions USING GIN (name gin_trgm_ops); - CREATE INDEX state_actions_timestamp_idx ON events.state_actions (timestamp); + CREATE INDEX IF NOT EXISTS state_actions_name_idx ON events.state_actions (name); + CREATE INDEX IF NOT EXISTS state_actions_name_gin_idx ON events.state_actions USING GIN (name gin_trgm_ops); + CREATE INDEX IF NOT EXISTS state_actions_timestamp_idx ON events.state_actions (timestamp); - CREATE TYPE events.resource_type AS ENUM ('other', 'script', 'stylesheet', 'fetch', 'img', 'media'); - CREATE TYPE events.resource_method AS ENUM ('GET' , 'HEAD' , 'POST' , 'PUT' , 'DELETE' , 'CONNECT' , 'OPTIONS' , 'TRACE' , 'PATCH' ); - CREATE TABLE events.resources + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'resource_type') THEN + CREATE TYPE events.resource_type AS ENUM ('other', 'script', 'stylesheet', 'fetch', 'img', 'media'); + END IF; + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'resource_method') THEN + CREATE TYPE events.resource_method AS ENUM ('GET' , 'HEAD' , 'POST' , 'PUT' , 'DELETE' , 'CONNECT' , 'OPTIONS' , 'TRACE' , 'PATCH' ); + END IF; + CREATE TABLE IF NOT EXISTS events.resources ( session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, message_id bigint NOT NULL, @@ -865,28 +1053,28 @@ $$ decoded_body_size integer NULL, PRIMARY KEY (session_id, message_id) ); - CREATE INDEX resources_session_id_idx ON events.resources (session_id); - CREATE INDEX resources_status_idx ON events.resources (status); - CREATE INDEX resources_type_idx ON events.resources (type); - CREATE INDEX resources_duration_durationgt0_idx ON events.resources (duration) WHERE duration > 0; - CREATE INDEX resources_url_host_idx ON events.resources (url_host); - CREATE INDEX resources_timestamp_idx ON events.resources (timestamp); - CREATE INDEX resources_success_idx ON events.resources (success); + CREATE INDEX IF NOT EXISTS resources_session_id_idx ON events.resources (session_id); + CREATE INDEX IF NOT EXISTS resources_status_idx ON events.resources (status); + CREATE INDEX IF NOT EXISTS resources_type_idx ON events.resources (type); + CREATE INDEX IF NOT EXISTS resources_duration_durationgt0_idx ON events.resources (duration) WHERE duration > 0; + CREATE INDEX IF NOT EXISTS resources_url_host_idx ON events.resources (url_host); + CREATE INDEX IF NOT EXISTS resources_timestamp_idx ON events.resources (timestamp); + CREATE INDEX IF NOT EXISTS resources_success_idx ON events.resources (success); - CREATE INDEX resources_url_gin_idx ON events.resources USING GIN (url gin_trgm_ops); - CREATE INDEX resources_url_idx ON events.resources (url); - CREATE INDEX resources_url_hostpath_gin_idx ON events.resources USING GIN (url_hostpath gin_trgm_ops); - CREATE INDEX resources_url_hostpath_idx ON events.resources (url_hostpath); - CREATE INDEX resources_timestamp_type_durationgt0NN_idx ON events.resources (timestamp, type) WHERE duration > 0 AND duration IS NOT NULL; - CREATE INDEX resources_session_id_timestamp_idx ON events.resources (session_id, timestamp); - CREATE INDEX resources_session_id_timestamp_type_idx ON events.resources (session_id, timestamp, type); - CREATE INDEX resources_timestamp_type_durationgt0NN_noFetch_idx ON events.resources (timestamp, type) WHERE duration > 0 AND duration IS NOT NULL AND type != 'fetch'; - CREATE INDEX resources_session_id_timestamp_url_host_fail_idx ON events.resources (session_id, timestamp, url_host) WHERE success = FALSE; - CREATE INDEX resources_session_id_timestamp_url_host_firstparty_idx ON events.resources (session_id, timestamp, url_host) WHERE type IN ('fetch', 'script'); - CREATE INDEX resources_session_id_timestamp_duration_durationgt0NN_img_idx ON events.resources (session_id, timestamp, duration) WHERE duration > 0 AND duration IS NOT NULL AND type = 'img'; - CREATE INDEX resources_timestamp_session_id_idx ON events.resources (timestamp, session_id); + CREATE INDEX IF NOT EXISTS resources_url_gin_idx ON events.resources USING GIN (url gin_trgm_ops); + CREATE INDEX IF NOT EXISTS resources_url_idx ON events.resources (url); + CREATE INDEX IF NOT EXISTS resources_url_hostpath_gin_idx ON events.resources USING GIN (url_hostpath gin_trgm_ops); + CREATE INDEX IF NOT EXISTS resources_url_hostpath_idx ON events.resources (url_hostpath); + CREATE INDEX IF NOT EXISTS resources_timestamp_type_durationgt0NN_idx ON events.resources (timestamp, type) WHERE duration > 0 AND duration IS NOT NULL; + CREATE INDEX IF NOT EXISTS resources_session_id_timestamp_idx ON events.resources (session_id, timestamp); + CREATE INDEX IF NOT EXISTS resources_session_id_timestamp_type_idx ON events.resources (session_id, timestamp, type); + CREATE INDEX IF NOT EXISTS resources_timestamp_type_durationgt0NN_noFetch_idx ON events.resources (timestamp, type) WHERE duration > 0 AND duration IS NOT NULL AND type != 'fetch'; + CREATE INDEX IF NOT EXISTS resources_session_id_timestamp_url_host_fail_idx ON events.resources (session_id, timestamp, url_host) WHERE success = FALSE; + CREATE INDEX IF NOT EXISTS resources_session_id_timestamp_url_host_firstparty_idx ON events.resources (session_id, timestamp, url_host) WHERE type IN ('fetch', 'script'); + CREATE INDEX IF NOT EXISTS resources_session_id_timestamp_duration_durationgt0NN_img_idx ON events.resources (session_id, timestamp, duration) WHERE duration > 0 AND duration IS NOT NULL AND type = 'img'; + CREATE INDEX IF NOT EXISTS resources_timestamp_session_id_idx ON events.resources (timestamp, session_id); - CREATE TABLE events.performance + CREATE TABLE IF NOT EXISTS events.performance ( session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, timestamp bigint NOT NULL, @@ -905,132 +1093,93 @@ $$ max_used_js_heap_size bigint NOT NULL, PRIMARY KEY (session_id, message_id) ); - CREATE INDEX performance_session_id_idx ON events.performance (session_id); - CREATE INDEX performance_timestamp_idx ON events.performance (timestamp); - CREATE INDEX performance_session_id_timestamp_idx ON events.performance (session_id, timestamp); - CREATE INDEX performance_avg_cpu_gt0_idx ON events.performance (avg_cpu) WHERE avg_cpu > 0; - CREATE INDEX performance_avg_used_js_heap_size_gt0_idx ON events.performance (avg_used_js_heap_size) WHERE avg_used_js_heap_size > 0; - --- --- autocomplete.sql --- - - CREATE TABLE autocomplete - ( - value text NOT NULL, - type text NOT NULL, - project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE - ); - - CREATE unique index autocomplete_unique ON autocomplete (project_id, value, type); - CREATE index autocomplete_project_id_idx ON autocomplete (project_id); - CREATE INDEX autocomplete_type_idx ON public.autocomplete (type); - CREATE INDEX autocomplete_value_gin_idx ON public.autocomplete USING GIN (value gin_trgm_ops); - --- --- jobs.sql --- - CREATE TYPE job_status AS ENUM ('scheduled','running','cancelled','failed','completed'); - CREATE TYPE job_action AS ENUM ('delete_user_data'); - CREATE TABLE jobs - ( - job_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, - description text NOT NULL, - status job_status NOT NULL, - project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE, - action job_action NOT NULL, - reference_id text NOT NULL, - created_at timestamp default timezone('utc'::text, now()) NOT NULL, - updated_at timestamp default timezone('utc'::text, now()) NULL, - start_at timestamp NOT NULL, - errors text NULL - ); - CREATE INDEX jobs_status_idx ON jobs (status); - CREATE INDEX jobs_start_at_idx ON jobs (start_at); - CREATE INDEX jobs_project_id_idx ON jobs (project_id); - - - CREATE TABLE traces - ( - user_id integer NULL REFERENCES users (user_id) ON DELETE CASCADE, - tenant_id integer NOT NULL REFERENCES tenants (tenant_id) ON DELETE CASCADE, - created_at bigint NOT NULL DEFAULT (EXTRACT(EPOCH FROM now() at time zone 'utc') * 1000)::bigint, - auth text NULL, - action text NOT NULL, - method text NOT NULL, - path_format text NOT NULL, - endpoint text NOT NULL, - payload jsonb NULL, - parameters jsonb NULL, - status int NULL - ); - CREATE INDEX traces_user_id_idx ON traces (user_id); - CREATE INDEX traces_tenant_id_idx ON traces (tenant_id); - - CREATE TABLE metrics - ( - metric_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, - project_id integer NOT 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, - created_at timestamp default timezone('utc'::text, now()) not null, - deleted_at timestamp - ); - CREATE INDEX metrics_user_id_is_public_idx ON public.metrics (user_id, is_public); - CREATE TABLE metric_series - ( - series_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, - metric_id integer REFERENCES metrics (metric_id) ON DELETE CASCADE, - index integer NOT NULL, - name text NULL, - filter jsonb NOT NULL, - created_at timestamp DEFAULT timezone('utc'::text, now()) NOT NULL, - deleted_at timestamp - ); - CREATE INDEX metric_series_metric_id_idx ON public.metric_series (metric_id); - - CREATE TABLE searches - ( - search_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 CASCADE, - name text not null, - filter jsonb not null, - created_at timestamp default timezone('utc'::text, now()) not null, - deleted_at timestamp, - is_public boolean NOT NULL DEFAULT False - ); - - CREATE INDEX searches_user_id_is_public_idx ON public.searches (user_id, is_public); - CREATE INDEX searches_project_id_idx ON public.searches (project_id); - - CREATE TYPE alert_detection_method AS ENUM ('threshold', 'change'); - - CREATE TABLE alerts - ( - alert_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY, - project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE, - series_id integer NULL REFERENCES metric_series (series_id) ON DELETE CASCADE, - name text NOT NULL, - description text NULL DEFAULT NULL, - active boolean NOT NULL DEFAULT TRUE, - detection_method alert_detection_method NOT NULL, - query jsonb NOT NULL, - deleted_at timestamp NULL DEFAULT NULL, - created_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()), - options jsonb NOT NULL DEFAULT '{ - "renotifyInterval": 1440 - }'::jsonb - ); - CREATE INDEX alerts_project_id_idx ON alerts (project_id); - CREATE INDEX alerts_series_id_idx ON alerts (series_id); - CREATE TRIGGER on_insert_or_update_or_delete - AFTER INSERT OR UPDATE OR DELETE - ON alerts - FOR EACH ROW - EXECUTE PROCEDURE notify_alert(); - - raise notice 'DB created'; + CREATE INDEX IF NOT EXISTS performance_session_id_idx ON events.performance (session_id); + CREATE INDEX IF NOT EXISTS performance_timestamp_idx ON events.performance (timestamp); + CREATE INDEX IF NOT EXISTS performance_session_id_timestamp_idx ON events.performance (session_id, timestamp); + CREATE INDEX IF NOT EXISTS performance_avg_cpu_gt0_idx ON events.performance (avg_cpu) WHERE avg_cpu > 0; + CREATE INDEX IF NOT EXISTS performance_avg_used_js_heap_size_gt0_idx ON events.performance (avg_used_js_heap_size) WHERE avg_used_js_heap_size > 0; END IF; END; - $$ LANGUAGE plpgsql; + + +DO +$$ + BEGIN + IF (with to_check (name) as ( + values ('customs'), + ('issues'), + ('requests') + ) + select bool_and(exists(select * + from information_schema.tables t + where table_schema = 'events_common' + AND table_name = to_check.name)) as all_present + from to_check) THEN + raise notice 'All events_common schema tables exists'; + ELSE + IF NOT EXISTS(SELECT * + FROM pg_type typ + WHERE typ.typname = 'custom_level') THEN + CREATE TYPE events_common.custom_level AS ENUM ('info','error'); + END IF; + CREATE TABLE IF NOT EXISTS events_common.customs + ( + session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, + timestamp bigint NOT NULL, + seq_index integer NOT NULL, + name text NOT NULL, + payload jsonb NOT NULL, + level events_common.custom_level NOT NULL DEFAULT 'info', + PRIMARY KEY (session_id, timestamp, seq_index) + ); + CREATE INDEX IF NOT EXISTS customs_name_idx ON events_common.customs (name); + CREATE INDEX IF NOT EXISTS customs_name_gin_idx ON events_common.customs USING GIN (name gin_trgm_ops); + CREATE INDEX IF NOT EXISTS customs_timestamp_idx ON events_common.customs (timestamp); + + + CREATE TABLE IF NOT EXISTS events_common.issues + ( + session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, + timestamp bigint NOT NULL, + seq_index integer NOT NULL, + issue_id text NOT NULL REFERENCES issues (issue_id) ON DELETE CASCADE, + payload jsonb DEFAULT NULL, + PRIMARY KEY (session_id, timestamp, seq_index) + ); + CREATE INDEX IF NOT EXISTS issues_issue_id_timestamp_idx ON events_common.issues (issue_id, timestamp); + CREATE INDEX IF NOT EXISTS issues_timestamp_idx ON events_common.issues (timestamp); + + + CREATE TABLE IF NOT EXISTS events_common.requests + ( + session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE, + timestamp bigint NOT NULL, + seq_index integer NOT NULL, + url text NOT NULL, + duration integer NOT NULL, + success boolean NOT NULL, + PRIMARY KEY (session_id, timestamp, seq_index) + ); + CREATE INDEX IF NOT EXISTS requests_url_idx ON events_common.requests (url); + CREATE INDEX IF NOT EXISTS requests_duration_idx ON events_common.requests (duration); + CREATE INDEX IF NOT EXISTS requests_url_gin_idx ON events_common.requests USING GIN (url gin_trgm_ops); + CREATE INDEX IF NOT EXISTS requests_timestamp_idx ON events_common.requests (timestamp); + CREATE INDEX IF NOT EXISTS requests_url_gin_idx2 ON events_common.requests USING GIN (RIGHT(url, + length(url) - + (CASE + WHEN url LIKE 'http://%' + THEN 7 + WHEN url LIKE 'https://%' + THEN 8 + ELSE 0 END)) + gin_trgm_ops); + CREATE INDEX IF NOT EXISTS requests_timestamp_session_id_failed_idx ON events_common.requests (timestamp, session_id) WHERE success = FALSE; + END IF; + END; +$$ +LANGUAGE plpgsql; + + COMMIT; \ No newline at end of file