114 lines
No EOL
4.9 KiB
PL/PgSQL
114 lines
No EOL
4.9 KiB
PL/PgSQL
BEGIN;
|
|
CREATE OR REPLACE FUNCTION openreplay_version()
|
|
RETURNS text AS
|
|
$$
|
|
SELECT 'v1.9.5-ee'
|
|
$$ LANGUAGE sql IMMUTABLE;
|
|
|
|
CREATE TABLE IF NOT EXISTS assist_records
|
|
(
|
|
record_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,
|
|
session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE SET NULL,
|
|
created_at bigint NOT NULL DEFAULT (EXTRACT(EPOCH FROM now() at time zone 'utc') * 1000)::bigint,
|
|
deleted_at timestamp without time zone NULL DEFAULT NULL,
|
|
name text NOT NULL,
|
|
file_key text NOT NULL,
|
|
duration integer NOT NULL
|
|
);
|
|
|
|
ALTER TYPE webhook_type ADD VALUE IF NOT EXISTS 'msteams';
|
|
|
|
DO
|
|
$$
|
|
BEGIN
|
|
IF EXISTS(SELECT column_name
|
|
FROM information_schema.columns
|
|
WHERE table_name = 'metrics'
|
|
and column_name = 'is_predefined') THEN
|
|
|
|
-- 1. pre transform structure
|
|
ALTER TABLE IF EXISTS metrics
|
|
ALTER COLUMN metric_type TYPE text,
|
|
ALTER COLUMN metric_type SET DEFAULT 'timeseries',
|
|
ALTER COLUMN view_type TYPE text,
|
|
ALTER COLUMN view_type SET DEFAULT 'lineChart',
|
|
ADD COLUMN IF NOT EXISTS thumbnail text,
|
|
ADD COLUMN IF NOT EXISTS o_metric_id INTEGER,
|
|
ADD COLUMN IF NOT EXISTS o_widget_id INTEGER;
|
|
|
|
-- 2. insert predefined metrics related to dashboards as custom metrics
|
|
INSERT INTO metrics(project_id, user_id, name, metric_type, view_type, metric_of, metric_value,
|
|
metric_format,
|
|
default_config, o_metric_id, o_widget_id)
|
|
SELECT dashboards.project_id,
|
|
dashboard_widgets.user_id,
|
|
metrics.name,
|
|
left(category, 1) || right(replace(initcap(category), ' ', ''), -1) AS metric_type,
|
|
'chart' AS view_type,
|
|
left(predefined_key, 1) || right(replace(initcap(predefined_key), '_', ''), -1) AS metric_of,
|
|
metric_value,
|
|
metric_format,
|
|
default_config,
|
|
metrics.metric_id,
|
|
dashboard_widgets.widget_id
|
|
FROM metrics
|
|
INNER JOIN dashboard_widgets USING (metric_id)
|
|
INNER JOIN dashboards USING (dashboard_id)
|
|
WHERE is_predefined;
|
|
|
|
-- 3. update widgets
|
|
UPDATE dashboard_widgets
|
|
SET metric_id=metrics.metric_id
|
|
FROM metrics
|
|
WHERE metrics.o_widget_id IS NOT NULL
|
|
AND dashboard_widgets.widget_id = metrics.o_widget_id;
|
|
|
|
-- 4. delete predefined metrics
|
|
DELETE
|
|
FROM metrics
|
|
WHERE is_predefined;
|
|
|
|
ALTER TABLE IF EXISTS metrics
|
|
DROP COLUMN IF EXISTS active,
|
|
DROP COLUMN IF EXISTS is_predefined,
|
|
DROP COLUMN IF EXISTS is_template,
|
|
DROP COLUMN IF EXISTS category,
|
|
DROP COLUMN IF EXISTS o_metric_id,
|
|
DROP COLUMN IF EXISTS o_widget_id,
|
|
DROP CONSTRAINT IF EXISTS null_project_id_for_template_only,
|
|
DROP CONSTRAINT IF EXISTS metrics_unique_key;
|
|
|
|
END IF;
|
|
END;
|
|
$$
|
|
LANGUAGE plpgsql;
|
|
|
|
DROP TYPE IF EXISTS metric_type;
|
|
DROP TYPE IF EXISTS metric_view_type;
|
|
|
|
ALTER TABLE IF EXISTS events.clicks
|
|
ADD COLUMN IF NOT EXISTS path text;
|
|
|
|
DROP INDEX IF EXISTS events.inputs_label_value_idx;
|
|
DROP INDEX IF EXISTS events.inputs_label_idx;
|
|
DROP INDEX IF EXISTS events.pages_base_path_idx2;
|
|
DROP INDEX IF EXISTS events.pages_base_referrer_gin_idx2;
|
|
DROP INDEX IF EXISTS events.resources_url_gin_idx;
|
|
DROP INDEX IF EXISTS events.resources_url_idx;
|
|
DROP INDEX IF EXISTS events.resources_url_hostpath_idx;
|
|
DROP INDEX IF EXISTS events.resources_session_id_timestamp_idx;
|
|
DROP INDEX IF EXISTS events.resources_duration_durationgt0_idx;
|
|
DROP INDEX IF EXISTS events.state_actions_name_idx;
|
|
DROP INDEX IF EXISTS events_common.requests_query_nn_idx;
|
|
DROP INDEX IF EXISTS events_common.requests_host_nn_idx;
|
|
DROP INDEX IF EXISTS public.sessions_user_country_gin_idx;
|
|
DROP INDEX IF EXISTS public.sessions_user_browser_gin_idx;
|
|
DROP INDEX IF EXISTS public.sessions_user_os_gin_idx;
|
|
|
|
COMMIT;
|
|
|
|
CREATE INDEX CONCURRENTLY IF NOT EXISTS clicks_selector_idx ON events.clicks (selector);
|
|
CREATE INDEX CONCURRENTLY IF NOT EXISTS clicks_path_idx ON events.clicks (path);
|
|
CREATE INDEX CONCURRENTLY IF NOT EXISTS clicks_path_gin_idx ON events.clicks USING GIN (path gin_trgm_ops); |