feat(DB): migrate nested-saved search data
feat(DB): changed projects structure feat(chalice): changed event-filters keys
This commit is contained in:
parent
16a8cb5810
commit
e9498dd383
5 changed files with 320 additions and 61 deletions
|
|
@ -509,19 +509,19 @@ class HttpMethod(str, Enum):
|
|||
|
||||
|
||||
class FetchFilterType(str, Enum):
|
||||
_url = "FETCH_URL"
|
||||
_status_code = "FETCH_STATUS_CODE"
|
||||
_method = "FETCH_METHOD"
|
||||
_duration = "FETCH_DURATION"
|
||||
_request_body = "FETCH_REQUEST_BODY"
|
||||
_response_body = "FETCH_RESPONSE_BODY"
|
||||
_url = "fetchUrl" # FETCH_URL
|
||||
_status_code = "fetchStatusCode" # FETCH_STATUS_CODE
|
||||
_method = "fetchMethod" # FETCH_METHOD
|
||||
_duration = "fetchDuration" # FETCH_DURATION
|
||||
_request_body = "fetchRequestBody" # FETCH_REQUEST_BODY
|
||||
_response_body = "fetchResponseBody" # FETCH_RESPONSE_BODY
|
||||
|
||||
|
||||
class GraphqlFilterType(str, Enum):
|
||||
_name = "GRAPHQL_NAME"
|
||||
_method = "GRAPHQL_METHOD"
|
||||
_request_body = "GRAPHQL_REQUEST_BODY"
|
||||
_response_body = "GRAPHQL_RESPONSE_BODY"
|
||||
_name = "graphqlName" # GRAPHQL_NAME
|
||||
_method = "graphqlMethod" # GRAPHQL_METHOD
|
||||
_request_body = "graphqlRequestBody" # GRAPHQL_REQUEST_BODY
|
||||
_response_body = "graphqlResponseBody" # GRAPHQL_RESPONSE_BODY
|
||||
|
||||
|
||||
class IssueFilterType(str, Enum):
|
||||
|
|
|
|||
|
|
@ -131,6 +131,199 @@ DROP INDEX IF EXISTS public.sessions_user_browser_gin_idx;
|
|||
DROP INDEX IF EXISTS public.sessions_user_os_gin_idx;
|
||||
DROP INDEX IF EXISTS public.issues_context_string_gin_idx;
|
||||
|
||||
ALTER TABLE IF EXISTS projects
|
||||
ADD COLUMN IF NOT EXISTS beacon_size integer NOT NULL DEFAULT 0;
|
||||
|
||||
-- To migrate saved search data
|
||||
-- SET client_min_messages TO NOTICE;
|
||||
|
||||
-- SET client_min_messages TO NOTICE;
|
||||
CREATE OR REPLACE FUNCTION get_new_event_key(key text)
|
||||
RETURNS text AS
|
||||
$$
|
||||
DECLARE
|
||||
events_map CONSTANT JSONB := '{
|
||||
"CLICK": "click",
|
||||
"INPUT": "input",
|
||||
"LOCATION": "location",
|
||||
"CUSTOM": "custom",
|
||||
"REQUEST": "request",
|
||||
"FETCH": "fetch",
|
||||
"GRAPHQL": "graphql",
|
||||
"STATEACTION": "stateAction",
|
||||
"ERROR": "error",
|
||||
"CLICK_IOS": "clickIos",
|
||||
"INPUT_IOS": "inputIos",
|
||||
"VIEW_IOS": "viewIos",
|
||||
"CUSTOM_IOS": "customIos",
|
||||
"REQUEST_IOS": "requestIos",
|
||||
"ERROR_IOS": "errorIos",
|
||||
"DOM_COMPLETE": "domComplete",
|
||||
"LARGEST_CONTENTFUL_PAINT_TIME": "largestContentfulPaintTime",
|
||||
"TIME_BETWEEN_EVENTS": "timeBetweenEvents",
|
||||
"TTFB": "ttfb",
|
||||
"AVG_CPU_LOAD": "avgCpuLoad",
|
||||
"AVG_MEMORY_USAGE": "avgMemoryUsage",
|
||||
"FETCH_FAILED": "fetchFailed"
|
||||
}';
|
||||
BEGIN
|
||||
RETURN jsonb_extract_path(events_map, key);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_new_event_filter_key(key text)
|
||||
RETURNS text AS
|
||||
$$
|
||||
DECLARE
|
||||
event_filters_map CONSTANT JSONB := '{
|
||||
"FETCH_URL": "fetchUrl",
|
||||
"FETCH_STATUS_CODE": "fetchStatusCode",
|
||||
"FETCH_METHOD": "fetchMethod",
|
||||
"FETCH_DURATION": "fetchDuration",
|
||||
"FETCH_REQUEST_BODY": "fetchRequestBody",
|
||||
"FETCH_RESPONSE_BODY": "fetchResponseBody",
|
||||
"GRAPHQL_NAME": "graphqlName",
|
||||
"GRAPHQL_METHOD": "graphqlMethod",
|
||||
"GRAPHQL_REQUEST_BODY": "graphqlRequestBody",
|
||||
"GRAPHQL_RESPONSE_BODY": "graphqlResponseBody"
|
||||
}';
|
||||
BEGIN
|
||||
RETURN jsonb_extract_path(event_filters_map, key);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_new_filter_key(key text)
|
||||
RETURNS text AS
|
||||
$$
|
||||
DECLARE
|
||||
filters_map CONSTANT JSONB := '{
|
||||
"USEROS": "userOs",
|
||||
"USERBROWSER": "userBrowser",
|
||||
"USERDEVICE": "userDevice",
|
||||
"USERCOUNTRY": "userCountry",
|
||||
"USERID": "userId",
|
||||
"USERANONYMOUSID": "userAnonymousId",
|
||||
"REFERRER": "referrer",
|
||||
"REVID": "revId",
|
||||
"USEROS_IOS": "userOsIos",
|
||||
"USERDEVICE_IOS": "userDeviceIos",
|
||||
"USERCOUNTRY_IOS": "userCountryIos",
|
||||
"USERID_IOS": "userIdIos",
|
||||
"USERANONYMOUSID_IOS": "userAnonymousIdIos",
|
||||
"REVID_IOS": "revIdIos",
|
||||
"DURATION": "duration",
|
||||
"PLATFORM": "platform",
|
||||
"METADATA": "metadata",
|
||||
"ISSUE": "issue",
|
||||
"EVENTS_COUNT": "eventsCount",
|
||||
"UTM_SOURCE": "utmSource",
|
||||
"UTM_MEDIUM": "utmMedium",
|
||||
"UTM_CAMPAIGN": "utmCampaign"
|
||||
}';
|
||||
BEGIN
|
||||
RETURN jsonb_extract_path(filters_map, key);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
DO
|
||||
$$
|
||||
DECLARE
|
||||
row RECORD;
|
||||
events_att JSONB;
|
||||
event_filters_att JSONB;
|
||||
filters_att JSONB;
|
||||
element JSONB;
|
||||
s_element JSONB;
|
||||
new_value TEXT;
|
||||
new_events JSONB[];
|
||||
new_filters JSONB[];
|
||||
new_event_filters JSONB[];
|
||||
changed BOOLEAN;
|
||||
planned_update JSONB[];
|
||||
BEGIN
|
||||
planned_update := '{}'::jsonb[];
|
||||
FOR row IN SELECT * FROM searches
|
||||
LOOP
|
||||
-- Transform events attributes
|
||||
events_att := row.filter -> 'events';
|
||||
IF events_att IS NOT NULL THEN
|
||||
new_events := '{}'::jsonb[];
|
||||
FOR element IN SELECT jsonb_array_elements(events_att)
|
||||
LOOP
|
||||
changed := FALSE;
|
||||
new_value := get_new_event_key(element ->> 'type');
|
||||
if new_value IS NOT NULL THEN
|
||||
changed := TRUE;
|
||||
new_value := replace(new_value, '"', '');
|
||||
element := element || jsonb_build_object('type', new_value);
|
||||
END IF;
|
||||
-- Transform event's sub-filters attributes
|
||||
event_filters_att := element -> 'filters';
|
||||
new_event_filters := '{}'::jsonb[];
|
||||
IF event_filters_att IS NOT NULL AND jsonb_array_length(event_filters_att) > 0 THEN
|
||||
FOR s_element IN SELECT jsonb_array_elements(event_filters_att)
|
||||
LOOP
|
||||
new_value := get_new_event_filter_key(s_element ->> 'type');
|
||||
if new_value IS NOT NULL THEN
|
||||
changed := TRUE;
|
||||
new_value := replace(new_value, '"', '');
|
||||
s_element := s_element || jsonb_build_object('type', new_value);
|
||||
new_event_filters := array_append(new_event_filters, s_element);
|
||||
END IF;
|
||||
END LOOP;
|
||||
element := element || jsonb_build_object('filters', new_event_filters);
|
||||
END IF;
|
||||
IF changed THEN
|
||||
new_events := array_append(new_events, element);
|
||||
END IF;
|
||||
END LOOP;
|
||||
IF array_length(new_events, 1) > 0 THEN
|
||||
row.filter := row.filter || jsonb_build_object('events', new_events);
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- Transform filters attributes
|
||||
filters_att := row.filter -> 'filters';
|
||||
IF filters_att IS NOT NULL THEN
|
||||
new_filters := '{}'::jsonb;
|
||||
FOR element IN SELECT jsonb_array_elements(filters_att)
|
||||
LOOP
|
||||
new_value := get_new_filter_key(element ->> 'type');
|
||||
if new_value IS NOT NULL THEN
|
||||
new_value := replace(new_value, '"', '');
|
||||
element := element || jsonb_build_object('type', new_value);
|
||||
new_filters := array_append(new_filters, element);
|
||||
END IF;
|
||||
END LOOP;
|
||||
IF array_length(new_filters, 1) > 0 THEN
|
||||
row.filter := row.filter || jsonb_build_object('filters', new_filters);
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
IF array_length(new_events, 1) > 0 OR array_length(new_filters, 1) > 0 THEN
|
||||
planned_update := array_append(planned_update,
|
||||
jsonb_build_object('id', row.search_id, 'change', row.filter));
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
-- Update saved search
|
||||
IF array_length(planned_update, 1) > 0 THEN
|
||||
raise notice 'must update % elements',array_length(planned_update, 1);
|
||||
|
||||
UPDATE searches
|
||||
SET filter=changes.change -> 'change'
|
||||
FROM (SELECT unnest(planned_update)) AS changes(change)
|
||||
WHERE search_id = (changes.change -> 'id')::integer;
|
||||
raise notice 'update done';
|
||||
ELSE
|
||||
raise notice 'nothing to update';
|
||||
END IF;
|
||||
END ;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
COMMIT;
|
||||
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS clicks_selector_idx ON events.clicks (selector);
|
||||
|
|
|
|||
|
|
@ -257,7 +257,8 @@ $$
|
|||
"defaultInputMode": "plain"
|
||||
}'::jsonb,
|
||||
first_recorded_session_at timestamp without time zone NULL DEFAULT NULL,
|
||||
sessions_last_check_at timestamp without time zone NULL DEFAULT NULL
|
||||
sessions_last_check_at timestamp without time zone NULL DEFAULT NULL,
|
||||
beacon_size integer NOT NULL DEFAULT 0
|
||||
);
|
||||
|
||||
|
||||
|
|
|
|||
|
|
@ -107,19 +107,18 @@ DROP INDEX IF EXISTS public.sessions_user_browser_gin_idx;
|
|||
DROP INDEX IF EXISTS public.sessions_user_os_gin_idx;
|
||||
DROP INDEX IF EXISTS public.issues_context_string_gin_idx;
|
||||
|
||||
|
||||
ALTER TABLE IF EXISTS projects
|
||||
ADD COLUMN IF NOT EXISTS beacon_size integer NOT NULL DEFAULT 0;
|
||||
|
||||
-- To migrate saved search data
|
||||
-- SET client_min_messages TO NOTICE;
|
||||
DO
|
||||
|
||||
-- SET client_min_messages TO NOTICE;
|
||||
CREATE OR REPLACE FUNCTION get_new_event_key(key text)
|
||||
RETURNS text AS
|
||||
$$
|
||||
DECLARE
|
||||
row RECORD;
|
||||
events_att JSONB;
|
||||
filters_att JSONB;
|
||||
element JSONB;
|
||||
new_value TEXT;
|
||||
new_array JSONB[];
|
||||
changed BOOLEAN;
|
||||
planned_update JSONB[];
|
||||
DECLARE
|
||||
events_map CONSTANT JSONB := '{
|
||||
"CLICK": "click",
|
||||
"INPUT": "input",
|
||||
|
|
@ -144,6 +143,37 @@ $$
|
|||
"AVG_MEMORY_USAGE": "avgMemoryUsage",
|
||||
"FETCH_FAILED": "fetchFailed"
|
||||
}';
|
||||
BEGIN
|
||||
RETURN jsonb_extract_path(events_map, key);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_new_event_filter_key(key text)
|
||||
RETURNS text AS
|
||||
$$
|
||||
DECLARE
|
||||
event_filters_map CONSTANT JSONB := '{
|
||||
"FETCH_URL": "fetchUrl",
|
||||
"FETCH_STATUS_CODE": "fetchStatusCode",
|
||||
"FETCH_METHOD": "fetchMethod",
|
||||
"FETCH_DURATION": "fetchDuration",
|
||||
"FETCH_REQUEST_BODY": "fetchRequestBody",
|
||||
"FETCH_RESPONSE_BODY": "fetchResponseBody",
|
||||
"GRAPHQL_NAME": "graphqlName",
|
||||
"GRAPHQL_METHOD": "graphqlMethod",
|
||||
"GRAPHQL_REQUEST_BODY": "graphqlRequestBody",
|
||||
"GRAPHQL_RESPONSE_BODY": "graphqlResponseBody"
|
||||
}';
|
||||
BEGIN
|
||||
RETURN jsonb_extract_path(event_filters_map, key);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_new_filter_key(key text)
|
||||
RETURNS text AS
|
||||
$$
|
||||
DECLARE
|
||||
filters_map CONSTANT JSONB := '{
|
||||
"USEROS": "userOs",
|
||||
"USERBROWSER": "userBrowser",
|
||||
|
|
@ -168,74 +198,108 @@ $$
|
|||
"UTM_MEDIUM": "utmMedium",
|
||||
"UTM_CAMPAIGN": "utmCampaign"
|
||||
}';
|
||||
BEGIN
|
||||
RETURN jsonb_extract_path(filters_map, key);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
DO
|
||||
$$
|
||||
DECLARE
|
||||
row RECORD;
|
||||
events_att JSONB;
|
||||
event_filters_att JSONB;
|
||||
filters_att JSONB;
|
||||
element JSONB;
|
||||
s_element JSONB;
|
||||
new_value TEXT;
|
||||
new_events JSONB[];
|
||||
new_filters JSONB[];
|
||||
new_event_filters JSONB[];
|
||||
changed BOOLEAN;
|
||||
planned_update JSONB[];
|
||||
BEGIN
|
||||
planned_update := '{}'::jsonb[];
|
||||
FOR row IN SELECT * FROM _search
|
||||
FOR row IN SELECT * FROM searches
|
||||
LOOP
|
||||
raise notice 'original: %',row.filter -> 'events';
|
||||
changed := FALSE;
|
||||
-- Transform events attribute
|
||||
-- Transform events attributes
|
||||
events_att := row.filter -> 'events';
|
||||
IF events_att IS NOT NULL THEN
|
||||
new_array := '{}'::jsonb[];
|
||||
new_events := '{}'::jsonb[];
|
||||
FOR element IN SELECT jsonb_array_elements(events_att)
|
||||
LOOP
|
||||
new_value := jsonb_extract_path(events_map, element ->> 'type');
|
||||
if new_value IS NULL THEN
|
||||
raise exception 'event-type not found: %',element ->> 'type';
|
||||
END IF;
|
||||
changed := FALSE;
|
||||
new_value := get_new_event_key(element ->> 'type');
|
||||
if new_value IS NOT NULL THEN
|
||||
changed := TRUE;
|
||||
new_value := replace(new_value, '"', '');
|
||||
element := element || jsonb_build_object('type', new_value);
|
||||
new_array := array_append(new_array, element);
|
||||
END LOOP;
|
||||
IF array_length(new_array, 1) > 0 THEN
|
||||
END IF;
|
||||
-- Transform event's sub-filters attributes
|
||||
event_filters_att := element -> 'filters';
|
||||
new_event_filters := '{}'::jsonb[];
|
||||
IF event_filters_att IS NOT NULL AND jsonb_array_length(event_filters_att) > 0 THEN
|
||||
FOR s_element IN SELECT jsonb_array_elements(event_filters_att)
|
||||
LOOP
|
||||
new_value := get_new_event_filter_key(s_element ->> 'type');
|
||||
if new_value IS NOT NULL THEN
|
||||
changed := TRUE;
|
||||
row.filter := row.filter || jsonb_build_object('events', new_array);
|
||||
new_value := replace(new_value, '"', '');
|
||||
s_element := s_element || jsonb_build_object('type', new_value);
|
||||
new_event_filters := array_append(new_event_filters, s_element);
|
||||
END IF;
|
||||
END LOOP;
|
||||
element := element || jsonb_build_object('filters', new_event_filters);
|
||||
END IF;
|
||||
IF changed THEN
|
||||
new_events := array_append(new_events, element);
|
||||
END IF;
|
||||
END LOOP;
|
||||
IF array_length(new_events, 1) > 0 THEN
|
||||
row.filter := row.filter || jsonb_build_object('events', new_events);
|
||||
END IF;
|
||||
END IF;
|
||||
raise notice 'new : %',row.filter -> 'events';
|
||||
raise notice 'original: %',row.filter -> 'filters';
|
||||
-- Transform filters attribute
|
||||
|
||||
-- Transform filters attributes
|
||||
filters_att := row.filter -> 'filters';
|
||||
IF filters_att IS NOT NULL THEN
|
||||
new_array := '{}'::jsonb;
|
||||
new_filters := '{}'::jsonb;
|
||||
FOR element IN SELECT jsonb_array_elements(filters_att)
|
||||
LOOP
|
||||
new_value := jsonb_extract_path(filters_map, element ->> 'type');
|
||||
if new_value IS NULL THEN
|
||||
raise exception 'filter-type not found: %',element ->> 'type';
|
||||
END IF;
|
||||
new_value := get_new_filter_key(element ->> 'type');
|
||||
if new_value IS NOT NULL THEN
|
||||
new_value := replace(new_value, '"', '');
|
||||
element := element || jsonb_build_object('type', new_value);
|
||||
new_array := array_append(new_array, element);
|
||||
new_filters := array_append(new_filters, element);
|
||||
END IF;
|
||||
END LOOP;
|
||||
IF array_length(new_array, 1) > 0 THEN
|
||||
changed := TRUE;
|
||||
row.filter := row.filter || jsonb_build_object('filters', new_array);
|
||||
IF array_length(new_filters, 1) > 0 THEN
|
||||
row.filter := row.filter || jsonb_build_object('filters', new_filters);
|
||||
END IF;
|
||||
END IF;
|
||||
raise notice 'new : %',row.filter -> 'filters';
|
||||
raise notice 'changed: %',changed;
|
||||
raise notice '-------------------';
|
||||
IF changed THEN
|
||||
|
||||
IF array_length(new_events, 1) > 0 OR array_length(new_filters, 1) > 0 THEN
|
||||
planned_update := array_append(planned_update,
|
||||
jsonb_build_object('id', row._search_id, 'change', row.filter));
|
||||
jsonb_build_object('id', row.search_id, 'change', row.filter));
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
-- Update saved search
|
||||
IF array_length(planned_update, 1) > 0 THEN
|
||||
raise notice 'must update % elements',array_length(planned_update, 1);
|
||||
-- raise notice 'must update %',planned_update;
|
||||
UPDATE _search
|
||||
SET n_filter=changes.change -> 'change'
|
||||
|
||||
UPDATE searches
|
||||
SET filter=changes.change -> 'change'
|
||||
FROM (SELECT unnest(planned_update)) AS changes(change)
|
||||
WHERE _search_id = (changes.change -> 'id')::integer;
|
||||
WHERE search_id = (changes.change -> 'id')::integer;
|
||||
raise notice 'update done';
|
||||
ELSE
|
||||
raise notice 'nothing to update';
|
||||
END IF;
|
||||
END ;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
COMMIT;
|
||||
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS clicks_selector_idx ON events.clicks (selector);
|
||||
|
|
|
|||
|
|
@ -193,7 +193,8 @@ $$
|
|||
"defaultInputMode": "plain"
|
||||
}'::jsonb,
|
||||
first_recorded_session_at timestamp without time zone NULL DEFAULT NULL,
|
||||
sessions_last_check_at timestamp without time zone NULL DEFAULT NULL
|
||||
sessions_last_check_at timestamp without time zone NULL DEFAULT NULL,
|
||||
beacon_size integer NOT NULL DEFAULT 0
|
||||
);
|
||||
|
||||
CREATE INDEX projects_project_key_idx ON public.projects (project_key);
|
||||
|
|
|
|||
Loading…
Add table
Reference in a new issue