refactor(DB): track auto-captured properties
This commit is contained in:
parent
17b72d4242
commit
ed66b30b7d
4 changed files with 24 additions and 12 deletions
|
|
@ -54,24 +54,27 @@ CREATE TABLE IF NOT EXISTS product_analytics.event_properties
|
||||||
event_name String,
|
event_name String,
|
||||||
property_name String,
|
property_name String,
|
||||||
value_type String,
|
value_type String,
|
||||||
|
auto_captured BOOL,
|
||||||
|
|
||||||
_timestamp DateTime DEFAULT now()
|
_timestamp DateTime DEFAULT now()
|
||||||
) ENGINE = ReplacingMergeTree(_timestamp)
|
) ENGINE = ReplacingMergeTree(_timestamp)
|
||||||
ORDER BY (project_id, event_name, property_name, value_type);
|
ORDER BY (project_id, event_name, property_name, value_type, auto_captured);
|
||||||
|
|
||||||
CREATE MATERIALIZED VIEW IF NOT EXISTS product_analytics.event_properties_extractor_mv
|
CREATE MATERIALIZED VIEW IF NOT EXISTS product_analytics.event_properties_extractor_mv
|
||||||
TO product_analytics.event_properties AS
|
TO product_analytics.event_properties AS
|
||||||
SELECT project_id,
|
SELECT project_id,
|
||||||
`$event_name` AS event_name,
|
`$event_name` AS event_name,
|
||||||
property_name,
|
property_name,
|
||||||
toString(JSONType(JSONExtractRaw(toString(`$properties`), property_name))) AS value_type
|
toString(JSONType(JSONExtractRaw(toString(`$properties`), property_name))) AS value_type,
|
||||||
|
`$auto_captured` AS auto_captured
|
||||||
FROM product_analytics.events
|
FROM product_analytics.events
|
||||||
ARRAY JOIN JSONExtractKeys(toString(`$properties`)) as property_name
|
ARRAY JOIN JSONExtractKeys(toString(`$properties`)) as property_name
|
||||||
UNION DISTINCT
|
UNION DISTINCT
|
||||||
SELECT project_id,
|
SELECT project_id,
|
||||||
`$event_name` AS event_name,
|
`$event_name` AS event_name,
|
||||||
property_name,
|
property_name,
|
||||||
toString(JSONType(JSONExtractRaw(toString(`properties`), property_name))) AS value_type
|
toString(JSONType(JSONExtractRaw(toString(`properties`), property_name))) AS value_type,
|
||||||
|
`$auto_captured` AS auto_captured
|
||||||
FROM product_analytics.events
|
FROM product_analytics.events
|
||||||
ARRAY JOIN JSONExtractKeys(toString(`properties`)) as property_name;
|
ARRAY JOIN JSONExtractKeys(toString(`properties`)) as property_name;
|
||||||
|
|
||||||
|
|
|
||||||
|
|
@ -676,10 +676,11 @@ CREATE TABLE IF NOT EXISTS product_analytics.event_properties
|
||||||
event_name String,
|
event_name String,
|
||||||
property_name String,
|
property_name String,
|
||||||
value_type String,
|
value_type String,
|
||||||
|
auto_captured BOOL,
|
||||||
|
|
||||||
_timestamp DateTime DEFAULT now()
|
_timestamp DateTime DEFAULT now()
|
||||||
) ENGINE = ReplacingMergeTree(_timestamp)
|
) ENGINE = ReplacingMergeTree(_timestamp)
|
||||||
ORDER BY (project_id, event_name, property_name, value_type);
|
ORDER BY (project_id, event_name, property_name, value_type, auto_captured);
|
||||||
|
|
||||||
-- ----------------- This is experimental, if it doesn't work, we need to do it in db worker -------------
|
-- ----------------- This is experimental, if it doesn't work, we need to do it in db worker -------------
|
||||||
-- Incremental materialized view to fill event_properties using $properties & properties
|
-- Incremental materialized view to fill event_properties using $properties & properties
|
||||||
|
|
@ -688,14 +689,16 @@ CREATE MATERIALIZED VIEW IF NOT EXISTS product_analytics.event_properties_extrac
|
||||||
SELECT project_id,
|
SELECT project_id,
|
||||||
`$event_name` AS event_name,
|
`$event_name` AS event_name,
|
||||||
property_name,
|
property_name,
|
||||||
toString(JSONType(JSONExtractRaw(toString(`$properties`), property_name))) AS value_type
|
toString(JSONType(JSONExtractRaw(toString(`$properties`), property_name))) AS value_type,
|
||||||
|
`$auto_captured` AS auto_captured
|
||||||
FROM product_analytics.events
|
FROM product_analytics.events
|
||||||
ARRAY JOIN JSONExtractKeys(toString(`$properties`)) as property_name
|
ARRAY JOIN JSONExtractKeys(toString(`$properties`)) as property_name
|
||||||
UNION DISTINCT
|
UNION DISTINCT
|
||||||
SELECT project_id,
|
SELECT project_id,
|
||||||
`$event_name` AS event_name,
|
`$event_name` AS event_name,
|
||||||
property_name,
|
property_name,
|
||||||
toString(JSONType(JSONExtractRaw(toString(`properties`), property_name))) AS value_type
|
toString(JSONType(JSONExtractRaw(toString(`properties`), property_name))) AS value_type,
|
||||||
|
`$auto_captured` AS auto_captured
|
||||||
FROM product_analytics.events
|
FROM product_analytics.events
|
||||||
ARRAY JOIN JSONExtractKeys(toString(`properties`)) as property_name;
|
ARRAY JOIN JSONExtractKeys(toString(`properties`)) as property_name;
|
||||||
-- -------- END ---------
|
-- -------- END ---------
|
||||||
|
|
|
||||||
|
|
@ -65,24 +65,27 @@ CREATE TABLE IF NOT EXISTS product_analytics.event_properties
|
||||||
event_name String,
|
event_name String,
|
||||||
property_name String,
|
property_name String,
|
||||||
value_type String,
|
value_type String,
|
||||||
|
auto_captured BOOL,
|
||||||
|
|
||||||
_timestamp DateTime DEFAULT now()
|
_timestamp DateTime DEFAULT now()
|
||||||
) ENGINE = ReplacingMergeTree(_timestamp)
|
) ENGINE = ReplacingMergeTree(_timestamp)
|
||||||
ORDER BY (project_id, event_name, property_name, value_type);
|
ORDER BY (project_id, event_name, property_name, value_type, auto_captured);
|
||||||
|
|
||||||
CREATE MATERIALIZED VIEW IF NOT EXISTS product_analytics.event_properties_extractor_mv
|
CREATE MATERIALIZED VIEW IF NOT EXISTS product_analytics.event_properties_extractor_mv
|
||||||
TO product_analytics.event_properties AS
|
TO product_analytics.event_properties AS
|
||||||
SELECT project_id,
|
SELECT project_id,
|
||||||
`$event_name` AS event_name,
|
`$event_name` AS event_name,
|
||||||
property_name,
|
property_name,
|
||||||
toString(JSONType(JSONExtractRaw(toString(`$properties`), property_name))) AS value_type
|
toString(JSONType(JSONExtractRaw(toString(`$properties`), property_name))) AS value_type,
|
||||||
|
`$auto_captured` AS auto_captured
|
||||||
FROM product_analytics.events
|
FROM product_analytics.events
|
||||||
ARRAY JOIN JSONExtractKeys(toString(`$properties`)) as property_name
|
ARRAY JOIN JSONExtractKeys(toString(`$properties`)) as property_name
|
||||||
UNION DISTINCT
|
UNION DISTINCT
|
||||||
SELECT project_id,
|
SELECT project_id,
|
||||||
`$event_name` AS event_name,
|
`$event_name` AS event_name,
|
||||||
property_name,
|
property_name,
|
||||||
toString(JSONType(JSONExtractRaw(toString(`properties`), property_name))) AS value_type
|
toString(JSONType(JSONExtractRaw(toString(`properties`), property_name))) AS value_type,
|
||||||
|
`$auto_captured` AS auto_captured
|
||||||
FROM product_analytics.events
|
FROM product_analytics.events
|
||||||
ARRAY JOIN JSONExtractKeys(toString(`properties`)) as property_name;
|
ARRAY JOIN JSONExtractKeys(toString(`properties`)) as property_name;
|
||||||
|
|
||||||
|
|
|
||||||
|
|
@ -573,10 +573,11 @@ CREATE TABLE IF NOT EXISTS product_analytics.event_properties
|
||||||
event_name String,
|
event_name String,
|
||||||
property_name String,
|
property_name String,
|
||||||
value_type String,
|
value_type String,
|
||||||
|
auto_captured BOOL,
|
||||||
|
|
||||||
_timestamp DateTime DEFAULT now()
|
_timestamp DateTime DEFAULT now()
|
||||||
) ENGINE = ReplacingMergeTree(_timestamp)
|
) ENGINE = ReplacingMergeTree(_timestamp)
|
||||||
ORDER BY (project_id, event_name, property_name, value_type);
|
ORDER BY (project_id, event_name, property_name, value_type, auto_captured);
|
||||||
|
|
||||||
-- ----------------- This is experimental, if it doesn't work, we need to do it in db worker -------------
|
-- ----------------- This is experimental, if it doesn't work, we need to do it in db worker -------------
|
||||||
-- Incremental materialized view to fill event_properties using $properties & properties
|
-- Incremental materialized view to fill event_properties using $properties & properties
|
||||||
|
|
@ -585,14 +586,16 @@ CREATE MATERIALIZED VIEW IF NOT EXISTS product_analytics.event_properties_extrac
|
||||||
SELECT project_id,
|
SELECT project_id,
|
||||||
`$event_name` AS event_name,
|
`$event_name` AS event_name,
|
||||||
property_name,
|
property_name,
|
||||||
toString(JSONType(JSONExtractRaw(toString(`$properties`), property_name))) AS value_type
|
toString(JSONType(JSONExtractRaw(toString(`$properties`), property_name))) AS value_type,
|
||||||
|
`$auto_captured` AS auto_captured
|
||||||
FROM product_analytics.events
|
FROM product_analytics.events
|
||||||
ARRAY JOIN JSONExtractKeys(toString(`$properties`)) as property_name
|
ARRAY JOIN JSONExtractKeys(toString(`$properties`)) as property_name
|
||||||
UNION DISTINCT
|
UNION DISTINCT
|
||||||
SELECT project_id,
|
SELECT project_id,
|
||||||
`$event_name` AS event_name,
|
`$event_name` AS event_name,
|
||||||
property_name,
|
property_name,
|
||||||
toString(JSONType(JSONExtractRaw(toString(`properties`), property_name))) AS value_type
|
toString(JSONType(JSONExtractRaw(toString(`properties`), property_name))) AS value_type,
|
||||||
|
`$auto_captured` AS auto_captured
|
||||||
FROM product_analytics.events
|
FROM product_analytics.events
|
||||||
ARRAY JOIN JSONExtractKeys(toString(`properties`)) as property_name;
|
ARRAY JOIN JSONExtractKeys(toString(`properties`)) as property_name;
|
||||||
-- -------- END ---------
|
-- -------- END ---------
|
||||||
|
|
|
||||||
Loading…
Add table
Reference in a new issue