From 7a08a121f0d5176024e8204747c2ec6a157e81ef Mon Sep 17 00:00:00 2001 From: andreas-unleash Date: Thu, 22 Feb 2024 17:21:08 +0200 Subject: [PATCH] feat: create the project-metrics-summary-trends table (#6313) Adds a migration to create and fill the `project_metrics_summary_trends` This table is to be used in enterprise to update the metrics data daily per project (after the aggregation of the hourly data) Driving force for this was doing performance testing on the executive dashboard. This will allow to remove the expensive query to aggregate the data on demand and will drop the total response time from 2.5sec to 125ms (measurements done with 100 Projects, 10000 features and over 1M rows in `client_metrics_env_daily` Closes # [1-2080](https://linear.app/unleash/issue/1-2080/create-the-project-metrics-summary-trends-table) --------- Signed-off-by: andreas-unleash --- ...22123532-project-metrics-summary-trends.js | 42 +++++++++++++++++++ 1 file changed, 42 insertions(+) create mode 100644 src/migrations/20240222123532-project-metrics-summary-trends.js diff --git a/src/migrations/20240222123532-project-metrics-summary-trends.js b/src/migrations/20240222123532-project-metrics-summary-trends.js new file mode 100644 index 0000000000..009113feb0 --- /dev/null +++ b/src/migrations/20240222123532-project-metrics-summary-trends.js @@ -0,0 +1,42 @@ +exports.up = function (db, cb) { + db.runSql( + ` + CREATE TABLE IF NOT EXISTS project_client_metrics_trends + ( + project varchar NOT NULL references projects(id) ON DELETE CASCADE, + date date NOT NULL, + total_yes integer NOT NULL, + total_no integer NOT NULL, + total_apps integer NOT NULL, + total_flags integer NOT NULL, + total_environments integer NOT NULL, + PRIMARY KEY (project, date) + ); + + INSERT INTO project_client_metrics_trends (project, date, total_yes, total_no, total_apps, total_flags, total_environments) + SELECT + f.project, + cmed.date, + SUM(cmed.yes) AS total_yes, + SUM(cmed.no) AS total_no, + COUNT(DISTINCT cmed.app_name) AS total_apps, + COUNT(DISTINCT cmed.feature_name) AS total_flags, + COUNT(DISTINCT cmed.environment) AS total_environments + FROM + client_metrics_env_daily cmed + JOIN features f on f.name = cmed.feature_name + GROUP BY + f.project, cmed.date + `, + cb, + ); +}; + +exports.down = function (db, cb) { + db.runSql( + ` + DROP TABLE IF EXISTS project_client_metrics_trends + `, + cb, + ); +};