feat(DB): changed sessions structure

feat(DB): changed performance structure
This commit is contained in:
Taha Yassine Kraiem 2022-08-29 16:55:44 +01:00
parent a4cdf69ae4
commit 4c444e0ed9
5 changed files with 38 additions and 10 deletions

View file

@ -1,10 +1,10 @@
CREATE TABLE IF NOT EXISTS experimental.sessions
(
session_id UInt64,
project_id UInt16,
session_id UInt64,
project_id UInt16,
tracker_version LowCardinality(String),
rev_id LowCardinality(Nullable(String)),
user_uuid UUID,
user_uuid UUID,
user_os LowCardinality(String),
user_os_version LowCardinality(Nullable(String)),
user_browser LowCardinality(String),
@ -12,11 +12,11 @@ CREATE TABLE IF NOT EXISTS experimental.sessions
user_device Nullable(String),
user_device_type Enum8('other'=0, 'desktop'=1, 'mobile'=2),
user_country Enum8('UN'=-128, 'RW'=-127, 'SO'=-126, 'YE'=-125, 'IQ'=-124, 'SA'=-123, 'IR'=-122, 'CY'=-121, 'TZ'=-120, 'SY'=-119, 'AM'=-118, 'KE'=-117, 'CD'=-116, 'DJ'=-115, 'UG'=-114, 'CF'=-113, 'SC'=-112, 'JO'=-111, 'LB'=-110, 'KW'=-109, 'OM'=-108, 'QA'=-107, 'BH'=-106, 'AE'=-105, 'IL'=-104, 'TR'=-103, 'ET'=-102, 'ER'=-101, 'EG'=-100, 'SD'=-99, 'GR'=-98, 'BI'=-97, 'EE'=-96, 'LV'=-95, 'AZ'=-94, 'LT'=-93, 'SJ'=-92, 'GE'=-91, 'MD'=-90, 'BY'=-89, 'FI'=-88, 'AX'=-87, 'UA'=-86, 'MK'=-85, 'HU'=-84, 'BG'=-83, 'AL'=-82, 'PL'=-81, 'RO'=-80, 'XK'=-79, 'ZW'=-78, 'ZM'=-77, 'KM'=-76, 'MW'=-75, 'LS'=-74, 'BW'=-73, 'MU'=-72, 'SZ'=-71, 'RE'=-70, 'ZA'=-69, 'YT'=-68, 'MZ'=-67, 'MG'=-66, 'AF'=-65, 'PK'=-64, 'BD'=-63, 'TM'=-62, 'TJ'=-61, 'LK'=-60, 'BT'=-59, 'IN'=-58, 'MV'=-57, 'IO'=-56, 'NP'=-55, 'MM'=-54, 'UZ'=-53, 'KZ'=-52, 'KG'=-51, 'TF'=-50, 'HM'=-49, 'CC'=-48, 'PW'=-47, 'VN'=-46, 'TH'=-45, 'ID'=-44, 'LA'=-43, 'TW'=-42, 'PH'=-41, 'MY'=-40, 'CN'=-39, 'HK'=-38, 'BN'=-37, 'MO'=-36, 'KH'=-35, 'KR'=-34, 'JP'=-33, 'KP'=-32, 'SG'=-31, 'CK'=-30, 'TL'=-29, 'RU'=-28, 'MN'=-27, 'AU'=-26, 'CX'=-25, 'MH'=-24, 'FM'=-23, 'PG'=-22, 'SB'=-21, 'TV'=-20, 'NR'=-19, 'VU'=-18, 'NC'=-17, 'NF'=-16, 'NZ'=-15, 'FJ'=-14, 'LY'=-13, 'CM'=-12, 'SN'=-11, 'CG'=-10, 'PT'=-9, 'LR'=-8, 'CI'=-7, 'GH'=-6, 'GQ'=-5, 'NG'=-4, 'BF'=-3, 'TG'=-2, 'GW'=-1, 'MR'=0, 'BJ'=1, 'GA'=2, 'SL'=3, 'ST'=4, 'GI'=5, 'GM'=6, 'GN'=7, 'TD'=8, 'NE'=9, 'ML'=10, 'EH'=11, 'TN'=12, 'ES'=13, 'MA'=14, 'MT'=15, 'DZ'=16, 'FO'=17, 'DK'=18, 'IS'=19, 'GB'=20, 'CH'=21, 'SE'=22, 'NL'=23, 'AT'=24, 'BE'=25, 'DE'=26, 'LU'=27, 'IE'=28, 'MC'=29, 'FR'=30, 'AD'=31, 'LI'=32, 'JE'=33, 'IM'=34, 'GG'=35, 'SK'=36, 'CZ'=37, 'NO'=38, 'VA'=39, 'SM'=40, 'IT'=41, 'SI'=42, 'ME'=43, 'HR'=44, 'BA'=45, 'AO'=46, 'NA'=47, 'SH'=48, 'BV'=49, 'BB'=50, 'CV'=51, 'GY'=52, 'GF'=53, 'SR'=54, 'PM'=55, 'GL'=56, 'PY'=57, 'UY'=58, 'BR'=59, 'FK'=60, 'GS'=61, 'JM'=62, 'DO'=63, 'CU'=64, 'MQ'=65, 'BS'=66, 'BM'=67, 'AI'=68, 'TT'=69, 'KN'=70, 'DM'=71, 'AG'=72, 'LC'=73, 'TC'=74, 'AW'=75, 'VG'=76, 'VC'=77, 'MS'=78, 'MF'=79, 'BL'=80, 'GP'=81, 'GD'=82, 'KY'=83, 'BZ'=84, 'SV'=85, 'GT'=86, 'HN'=87, 'NI'=88, 'CR'=89, 'VE'=90, 'EC'=91, 'CO'=92, 'PA'=93, 'HT'=94, 'AR'=95, 'CL'=96, 'BO'=97, 'PE'=98, 'MX'=99, 'PF'=100, 'PN'=101, 'KI'=102, 'TK'=103, 'TO'=104, 'WF'=105, 'WS'=106, 'NU'=107, 'MP'=108, 'GU'=109, 'PR'=110, 'VI'=111, 'UM'=112, 'AS'=113, 'CA'=114, 'US'=115, 'PS'=116, 'RS'=117, 'AQ'=118, 'SX'=119, 'CW'=120, 'BQ'=121, 'SS'=122),
datetime DateTime,
duration UInt32,
pages_count UInt16,
events_count UInt16,
errors_count UInt16,
datetime DateTime,
duration UInt32,
pages_count UInt16,
events_count UInt16,
errors_count UInt16,
utm_source Nullable(String),
utm_medium Nullable(String),
utm_campaign Nullable(String),
@ -33,8 +33,8 @@ CREATE TABLE IF NOT EXISTS experimental.sessions
metadata_10 Nullable(String),
issue_types Array(LowCardinality(String)),
referrer Nullable(String),
base_referrer Nullable(String),
_timestamp DateTime DEFAULT now()
base_referrer Nullable(String) MATERIALIZED lower(concat(domain(referrer), path(referrer))),
_timestamp DateTime DEFAULT now()
) ENGINE = ReplacingMergeTree(_timestamp)
PARTITION BY toYYYYMMDD(datetime)
ORDER BY (project_id, datetime, session_id)

View file

@ -28,6 +28,15 @@ LANGUAGE plpgsql;
ALTER TABLE IF EXISTS alerts
ADD COLUMN IF NOT EXISTS change alert_change_type NOT NULL DEFAULT 'change';
ALTER TABLE IF EXISTS sessions
ADD COLUMN IF NOT EXISTS referrer text NULL DEFAULT NULL,
ADD COLUMN IF NOT EXISTS base_referrer text NULL DEFAULT NULL;
ALTER TABLE IF EXISTS events.performance
ADD COLUMN IF NOT EXISTS host text NULL DEFAULT NULL,
ADD COLUMN IF NOT EXISTS path text NULL DEFAULT NULL,
ADD COLUMN IF NOT EXISTS query text NULL DEFAULT NULL;
COMMIT;
CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS autocomplete_unique_project_id_md5value_type_idx ON autocomplete (project_id, md5(value), type);

View file

@ -547,6 +547,8 @@ $$
utm_source text NULL DEFAULT NULL,
utm_medium text NULL DEFAULT NULL,
utm_campaign text NULL DEFAULT NULL,
referrer text NULL DEFAULT NULL,
base_referrer text NULL DEFAULT NULL,
metadata_1 text DEFAULT NULL,
metadata_2 text DEFAULT NULL,
metadata_3 text DEFAULT NULL,
@ -1092,6 +1094,9 @@ $$
session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE,
timestamp bigint NOT NULL,
message_id bigint NOT NULL,
host text NULL DEFAULT NULL,
path text NULL DEFAULT NULL,
query text NULL DEFAULT NULL,
min_fps smallint NOT NULL,
avg_fps smallint NOT NULL,
max_fps smallint NOT NULL,

View file

@ -28,6 +28,15 @@ LANGUAGE plpgsql;
ALTER TABLE IF EXISTS alerts
ADD COLUMN IF NOT EXISTS change alert_change_type NOT NULL DEFAULT 'change';
ALTER TABLE IF EXISTS sessions
ADD COLUMN IF NOT EXISTS referrer text NULL DEFAULT NULL,
ADD COLUMN IF NOT EXISTS base_referrer text NULL DEFAULT NULL;
ALTER TABLE IF EXISTS events.performance
ADD COLUMN IF NOT EXISTS host text NULL DEFAULT NULL,
ADD COLUMN IF NOT EXISTS path text NULL DEFAULT NULL,
ADD COLUMN IF NOT EXISTS query text NULL DEFAULT NULL;
COMMIT;
CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS autocomplete_unique_project_id_md5value_type_idx ON autocomplete (project_id, md5(value), type);

View file

@ -441,6 +441,8 @@ $$
utm_source text NULL DEFAULT NULL,
utm_medium text NULL DEFAULT NULL,
utm_campaign text NULL DEFAULT NULL,
referrer text NULL DEFAULT NULL,
base_referrer text NULL DEFAULT NULL,
metadata_1 text DEFAULT NULL,
metadata_2 text DEFAULT NULL,
metadata_3 text DEFAULT NULL,
@ -811,6 +813,9 @@ $$
session_id bigint NOT NULL REFERENCES sessions (session_id) ON DELETE CASCADE,
timestamp bigint NOT NULL,
message_id bigint NOT NULL,
host text NULL DEFAULT NULL,
path text NULL DEFAULT NULL,
query text NULL DEFAULT NULL,
min_fps smallint NOT NULL,
avg_fps smallint NOT NULL,
max_fps smallint NOT NULL,