feat(DB): backup data before upgrade
This commit is contained in:
parent
c9789ed99a
commit
13b4fc1c12
2 changed files with 289 additions and 3 deletions
|
|
@ -5,6 +5,148 @@ $$
|
|||
SELECT 'v1.10.0-ee'
|
||||
$$ LANGUAGE sql IMMUTABLE;
|
||||
|
||||
-- Backup dashboard & search data:
|
||||
DO
|
||||
$$
|
||||
BEGIN
|
||||
IF NOT (SELECT EXISTS(SELECT schema_name
|
||||
FROM information_schema.schemata
|
||||
WHERE schema_name = 'backup_v1_10_0')) THEN
|
||||
CREATE SCHEMA backup_v1_10_0;
|
||||
CREATE TABLE backup_v1_10_0.dashboards
|
||||
(
|
||||
dashboard_id integer,
|
||||
project_id integer,
|
||||
user_id integer,
|
||||
name text NOT NULL,
|
||||
description text NOT NULL DEFAULT '',
|
||||
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 backup_v1_10_0.dashboard_widgets
|
||||
(
|
||||
widget_id integer,
|
||||
dashboard_id integer,
|
||||
metric_id integer,
|
||||
user_id integer,
|
||||
created_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()),
|
||||
config jsonb NOT NULL DEFAULT '{}'::jsonb
|
||||
);
|
||||
CREATE TABLE backup_v1_10_0.searches
|
||||
(
|
||||
search_id integer,
|
||||
project_id integer,
|
||||
user_id integer,
|
||||
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 TABLE backup_v1_10_0.metrics
|
||||
(
|
||||
metric_id integer,
|
||||
project_id integer,
|
||||
user_id integer,
|
||||
name text NOT NULL,
|
||||
is_public boolean NOT NULL DEFAULT FALSE,
|
||||
active boolean NOT NULL DEFAULT TRUE,
|
||||
created_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()),
|
||||
deleted_at timestamp,
|
||||
edited_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()),
|
||||
metric_type text NOT NULL,
|
||||
view_type text NOT NULL,
|
||||
metric_of text NOT NULL DEFAULT 'sessionCount',
|
||||
metric_value text[] NOT NULL DEFAULT '{}'::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,
|
||||
predefined_key text NULL DEFAULT NULL,
|
||||
default_config jsonb NOT NULL
|
||||
);
|
||||
CREATE TABLE backup_v1_10_0.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
|
||||
);
|
||||
|
||||
INSERT INTO backup_v1_10_0.dashboards(dashboard_id, project_id, user_id, name, description, is_public,
|
||||
is_pinned,
|
||||
created_at, deleted_at)
|
||||
SELECT dashboard_id,
|
||||
project_id,
|
||||
user_id,
|
||||
name,
|
||||
description,
|
||||
is_public,
|
||||
is_pinned,
|
||||
created_at,
|
||||
deleted_at
|
||||
FROM public.dashboards
|
||||
ORDER BY dashboard_id;
|
||||
|
||||
INSERT INTO backup_v1_10_0.metrics(metric_id, project_id, user_id, name, is_public, active, created_at,
|
||||
deleted_at, edited_at, metric_type, view_type, metric_of, metric_value,
|
||||
metric_format, category, is_pinned, is_predefined, is_template,
|
||||
predefined_key, default_config)
|
||||
SELECT metric_id,
|
||||
project_id,
|
||||
user_id,
|
||||
name,
|
||||
is_public,
|
||||
active,
|
||||
created_at,
|
||||
deleted_at,
|
||||
edited_at,
|
||||
metric_type,
|
||||
view_type,
|
||||
metric_of,
|
||||
metric_value,
|
||||
metric_format,
|
||||
category,
|
||||
is_pinned,
|
||||
is_predefined,
|
||||
is_template,
|
||||
predefined_key,
|
||||
default_config
|
||||
FROM public.metrics
|
||||
ORDER BY metric_id;
|
||||
|
||||
INSERT INTO backup_v1_10_0.metric_series(series_id, metric_id, index, name, filter, created_at, deleted_at)
|
||||
SELECT series_id, metric_id, index, name, filter, created_at, deleted_at
|
||||
FROM public.metric_series
|
||||
ORDER BY series_id;
|
||||
|
||||
INSERT INTO backup_v1_10_0.dashboard_widgets(widget_id, dashboard_id, metric_id, user_id, created_at, config)
|
||||
SELECT widget_id, dashboard_id, metric_id, user_id, created_at, config
|
||||
FROM public.dashboard_widgets
|
||||
ORDER BY widget_id;
|
||||
|
||||
INSERT INTO backup_v1_10_0.searches(search_id, project_id, user_id, name, filter, created_at, deleted_at,
|
||||
is_public)
|
||||
SELECT search_id,
|
||||
project_id,
|
||||
user_id,
|
||||
name,
|
||||
filter,
|
||||
created_at,
|
||||
deleted_at,
|
||||
is_public
|
||||
FROM public.searches
|
||||
ORDER BY search_id;
|
||||
END IF;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS frontend_signals
|
||||
(
|
||||
project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE,
|
||||
|
|
@ -119,7 +261,8 @@ $$
|
|||
and column_name = 'is_predefined') THEN
|
||||
-- 0. change metric_of
|
||||
UPDATE metrics
|
||||
SET metric_of=coalesce(replace(get_global_key(metric_of), '"', ''),left(metric_of, 1) || right(replace(initcap(metric_of), '_', ''), -1))
|
||||
SET metric_of=coalesce(replace(get_global_key(metric_of), '"', ''),
|
||||
left(metric_of, 1) || right(replace(initcap(metric_of), '_', ''), -1))
|
||||
WHERE not is_predefined;
|
||||
|
||||
-- 1. pre transform structure
|
||||
|
|
|
|||
|
|
@ -5,6 +5,148 @@ $$
|
|||
SELECT 'v1.10.0'
|
||||
$$ LANGUAGE sql IMMUTABLE;
|
||||
|
||||
-- Backup dashboard & search data:
|
||||
DO
|
||||
$$
|
||||
BEGIN
|
||||
IF NOT (SELECT EXISTS(SELECT schema_name
|
||||
FROM information_schema.schemata
|
||||
WHERE schema_name = 'backup_v1_10_0')) THEN
|
||||
CREATE SCHEMA backup_v1_10_0;
|
||||
CREATE TABLE backup_v1_10_0.dashboards
|
||||
(
|
||||
dashboard_id integer,
|
||||
project_id integer,
|
||||
user_id integer,
|
||||
name text NOT NULL,
|
||||
description text NOT NULL DEFAULT '',
|
||||
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 backup_v1_10_0.dashboard_widgets
|
||||
(
|
||||
widget_id integer,
|
||||
dashboard_id integer,
|
||||
metric_id integer,
|
||||
user_id integer,
|
||||
created_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()),
|
||||
config jsonb NOT NULL DEFAULT '{}'::jsonb
|
||||
);
|
||||
CREATE TABLE backup_v1_10_0.searches
|
||||
(
|
||||
search_id integer,
|
||||
project_id integer,
|
||||
user_id integer,
|
||||
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 TABLE backup_v1_10_0.metrics
|
||||
(
|
||||
metric_id integer,
|
||||
project_id integer,
|
||||
user_id integer,
|
||||
name text NOT NULL,
|
||||
is_public boolean NOT NULL DEFAULT FALSE,
|
||||
active boolean NOT NULL DEFAULT TRUE,
|
||||
created_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()),
|
||||
deleted_at timestamp,
|
||||
edited_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()),
|
||||
metric_type text NOT NULL,
|
||||
view_type text NOT NULL,
|
||||
metric_of text NOT NULL DEFAULT 'sessionCount',
|
||||
metric_value text[] NOT NULL DEFAULT '{}'::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,
|
||||
predefined_key text NULL DEFAULT NULL,
|
||||
default_config jsonb NOT NULL
|
||||
);
|
||||
CREATE TABLE backup_v1_10_0.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
|
||||
);
|
||||
|
||||
INSERT INTO backup_v1_10_0.dashboards(dashboard_id, project_id, user_id, name, description, is_public,
|
||||
is_pinned,
|
||||
created_at, deleted_at)
|
||||
SELECT dashboard_id,
|
||||
project_id,
|
||||
user_id,
|
||||
name,
|
||||
description,
|
||||
is_public,
|
||||
is_pinned,
|
||||
created_at,
|
||||
deleted_at
|
||||
FROM public.dashboards
|
||||
ORDER BY dashboard_id;
|
||||
|
||||
INSERT INTO backup_v1_10_0.metrics(metric_id, project_id, user_id, name, is_public, active, created_at,
|
||||
deleted_at, edited_at, metric_type, view_type, metric_of, metric_value,
|
||||
metric_format, category, is_pinned, is_predefined, is_template,
|
||||
predefined_key, default_config)
|
||||
SELECT metric_id,
|
||||
project_id,
|
||||
user_id,
|
||||
name,
|
||||
is_public,
|
||||
active,
|
||||
created_at,
|
||||
deleted_at,
|
||||
edited_at,
|
||||
metric_type,
|
||||
view_type,
|
||||
metric_of,
|
||||
metric_value,
|
||||
metric_format,
|
||||
category,
|
||||
is_pinned,
|
||||
is_predefined,
|
||||
is_template,
|
||||
predefined_key,
|
||||
default_config
|
||||
FROM public.metrics
|
||||
ORDER BY metric_id;
|
||||
|
||||
INSERT INTO backup_v1_10_0.metric_series(series_id, metric_id, index, name, filter, created_at, deleted_at)
|
||||
SELECT series_id, metric_id, index, name, filter, created_at, deleted_at
|
||||
FROM public.metric_series
|
||||
ORDER BY series_id;
|
||||
|
||||
INSERT INTO backup_v1_10_0.dashboard_widgets(widget_id, dashboard_id, metric_id, user_id, created_at, config)
|
||||
SELECT widget_id, dashboard_id, metric_id, user_id, created_at, config
|
||||
FROM public.dashboard_widgets
|
||||
ORDER BY widget_id;
|
||||
|
||||
INSERT INTO backup_v1_10_0.searches(search_id, project_id, user_id, name, filter, created_at, deleted_at,
|
||||
is_public)
|
||||
SELECT search_id,
|
||||
project_id,
|
||||
user_id,
|
||||
name,
|
||||
filter,
|
||||
created_at,
|
||||
deleted_at,
|
||||
is_public
|
||||
FROM public.searches
|
||||
ORDER BY search_id;
|
||||
END IF;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
ALTER TYPE webhook_type ADD VALUE IF NOT EXISTS 'msteams';
|
||||
|
||||
UPDATE metrics
|
||||
|
|
@ -93,7 +235,8 @@ $$
|
|||
and column_name = 'is_predefined') THEN
|
||||
-- 0. change metric_of
|
||||
UPDATE metrics
|
||||
SET metric_of=coalesce(replace(get_global_key(metric_of), '"', ''),left(metric_of, 1) || right(replace(initcap(metric_of), '_', ''), -1))
|
||||
SET metric_of=coalesce(replace(get_global_key(metric_of), '"', ''),
|
||||
left(metric_of, 1) || right(replace(initcap(metric_of), '_', ''), -1))
|
||||
WHERE not is_predefined;
|
||||
|
||||
-- 1. pre transform structure
|
||||
|
|
@ -482,4 +625,4 @@ 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);
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS issues_project_id_issue_id_idx ON public.issues (project_id, issue_id);
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS issues_project_id_issue_id_idx ON public.issues (project_id, issue_id);
|
||||
|
|
|
|||
Loading…
Add table
Reference in a new issue