From 5315ac66c3871ce4d2d04fd60911d5017071f76b Mon Sep 17 00:00:00 2001 From: Taha Yassine Kraiem Date: Mon, 26 Sep 2022 17:17:29 +0200 Subject: [PATCH] feat(chalice): optimized telemetry --- api/chalicelib/core/telemetry.py | 10 +++++++--- ee/api/chalicelib/core/telemetry.py | 19 ++++++++++--------- .../db/init_dbs/postgresql/1.8.2/1.8.2.sql | 10 ++++++++++ .../db/init_dbs/postgresql/init_schema.sql | 5 +++-- .../db/init_dbs/postgresql/1.8.2/1.8.2.sql | 10 ++++++++++ .../db/init_dbs/postgresql/init_schema.sql | 5 +++-- 6 files changed, 43 insertions(+), 16 deletions(-) create mode 100644 ee/scripts/helm/db/init_dbs/postgresql/1.8.2/1.8.2.sql create mode 100644 scripts/helm/db/init_dbs/postgresql/1.8.2/1.8.2.sql diff --git a/api/chalicelib/core/telemetry.py b/api/chalicelib/core/telemetry.py index 8098c9cd7..50fdc3c11 100644 --- a/api/chalicelib/core/telemetry.py +++ b/api/chalicelib/core/telemetry.py @@ -20,15 +20,19 @@ def process_data(data): def compute(): - with pg_client.PostgresClient() as cur: + with pg_client.PostgresClient(long_query=True) as cur: cur.execute( f"""UPDATE public.tenants SET t_integrations = COALESCE((SELECT COUNT(DISTINCT provider) FROM public.integrations) + (SELECT COUNT(*) FROM public.webhooks WHERE type = 'slack') + (SELECT COUNT(*) FROM public.jira_cloud), 0), t_projects=COALESCE((SELECT COUNT(*) FROM public.projects WHERE deleted_at ISNULL), 0), - t_sessions=COALESCE((SELECT COUNT(*) FROM public.sessions), 0), - t_users=COALESCE((SELECT COUNT(*) FROM public.users WHERE deleted_at ISNULL), 0) + t_sessions=t_sessions + COALESCE((SELECT COUNT(*) + FROM public.sessions + WHERE start_ts >= (SELECT last_telemetry FROM tenants) + AND start_ts <=CAST(EXTRACT(epoch FROM date_trunc('day', now())) * 1000 AS BIGINT)), 0), + t_users=COALESCE((SELECT COUNT(*) FROM public.users WHERE deleted_at ISNULL), 0), + last_telemetry=CAST(EXTRACT(epoch FROM date_trunc('day', now())) * 1000 AS BIGINT) RETURNING name,t_integrations,t_projects,t_sessions,t_users,tenant_key,opt_out, (SELECT openreplay_version()) AS version_number,(SELECT email FROM public.users WHERE role = 'owner' LIMIT 1);""" ) diff --git a/ee/api/chalicelib/core/telemetry.py b/ee/api/chalicelib/core/telemetry.py index a002f8501..889c1b8f6 100644 --- a/ee/api/chalicelib/core/telemetry.py +++ b/ee/api/chalicelib/core/telemetry.py @@ -20,7 +20,7 @@ def process_data(data): def compute(): - with pg_client.PostgresClient() as cur: + with pg_client.PostgresClient(long_query=True) as cur: cur.execute( f"""UPDATE public.tenants SET t_integrations = COALESCE((SELECT COUNT(DISTINCT provider) @@ -39,17 +39,18 @@ def compute(): FROM public.projects WHERE deleted_at ISNULL AND projects.tenant_id = all_tenants.tenant_id), 0), - t_sessions=COALESCE((SELECT COUNT(*) - FROM public.sessions - INNER JOIN public.projects USING (project_id) - WHERE projects.tenant_id = all_tenants.tenant_id), 0), + t_sessions=t_sessions + COALESCE((SELECT COUNT(*) + FROM public.sessions INNER JOIN public.projects USING (project_id) + WHERE projects.tenant_id = all_tenants.tenant_id + AND start_ts >= (SELECT last_telemetry FROM tenants) + AND start_ts <=CAST(EXTRACT(epoch FROM date_trunc('day', now())) * 1000 AS BIGINT)), 0), t_users=COALESCE((SELECT COUNT(*) FROM public.users WHERE deleted_at ISNULL - AND users.tenant_id = all_tenants.tenant_id), 0) - FROM ( - SELECT tenant_id - FROM public.tenants + AND users.tenant_id = all_tenants.tenant_id), 0), + last_telemetry=CAST(EXTRACT(epoch FROM date_trunc('day', now())) * 1000 AS BIGINT) + FROM (SELECT tenant_id + FROM public.tenants ) AS all_tenants WHERE tenants.tenant_id = all_tenants.tenant_id RETURNING name,t_integrations,t_projects,t_sessions,t_users,tenant_key,opt_out, diff --git a/ee/scripts/helm/db/init_dbs/postgresql/1.8.2/1.8.2.sql b/ee/scripts/helm/db/init_dbs/postgresql/1.8.2/1.8.2.sql new file mode 100644 index 000000000..4eb88bd9e --- /dev/null +++ b/ee/scripts/helm/db/init_dbs/postgresql/1.8.2/1.8.2.sql @@ -0,0 +1,10 @@ +BEGIN; +CREATE OR REPLACE FUNCTION openreplay_version() + RETURNS text AS +$$ +SELECT 'v1.8.2-ee' +$$ LANGUAGE sql IMMUTABLE; + +ALTER TABLE IF EXISTS public.tenants + ADD COLUMN IF NOT EXISTS last_telemetry bigint NOT NULL DEFAULT CAST(EXTRACT(epoch FROM date_trunc('day', now())) * 1000 AS BIGINT); +COMMIT; \ No newline at end of file diff --git a/ee/scripts/helm/db/init_dbs/postgresql/init_schema.sql b/ee/scripts/helm/db/init_dbs/postgresql/init_schema.sql index 723b8eb09..2be29136b 100644 --- a/ee/scripts/helm/db/init_dbs/postgresql/init_schema.sql +++ b/ee/scripts/helm/db/init_dbs/postgresql/init_schema.sql @@ -153,7 +153,8 @@ $$ t_projects integer NOT NULL DEFAULT 1, t_sessions bigint NOT NULL DEFAULT 0, t_users integer NOT NULL DEFAULT 1, - t_integrations integer NOT NULL DEFAULT 0 + t_integrations integer NOT NULL DEFAULT 0, + last_telemetry bigint NOT NULL DEFAULT CAST(EXTRACT(epoch FROM date_trunc('day', now())) * 1000 AS BIGINT) ); @@ -223,7 +224,7 @@ $$ provider_user_id text NOT NULL, token text NOT NULL ); - CREATE UNIQUE INDEX IF NOT EXISTS oauth_authentication_unique_user_id_provider_idx ON oauth_authentication(user_id,provider); + CREATE UNIQUE INDEX IF NOT EXISTS oauth_authentication_unique_user_id_provider_idx ON oauth_authentication (user_id, provider); CREATE TABLE IF NOT EXISTS projects ( diff --git a/scripts/helm/db/init_dbs/postgresql/1.8.2/1.8.2.sql b/scripts/helm/db/init_dbs/postgresql/1.8.2/1.8.2.sql new file mode 100644 index 000000000..57deb548d --- /dev/null +++ b/scripts/helm/db/init_dbs/postgresql/1.8.2/1.8.2.sql @@ -0,0 +1,10 @@ +BEGIN; +CREATE OR REPLACE FUNCTION openreplay_version() + RETURNS text AS +$$ +SELECT 'v1.8.2' +$$ LANGUAGE sql IMMUTABLE; + +ALTER TABLE IF EXISTS public.tenants + ADD COLUMN IF NOT EXISTS last_telemetry bigint NOT NULL DEFAULT CAST(EXTRACT(epoch FROM date_trunc('day', now())) * 1000 AS BIGINT); +COMMIT; \ No newline at end of file diff --git a/scripts/helm/db/init_dbs/postgresql/init_schema.sql b/scripts/helm/db/init_dbs/postgresql/init_schema.sql index 94bfa04e2..ad435348e 100644 --- a/scripts/helm/db/init_dbs/postgresql/init_schema.sql +++ b/scripts/helm/db/init_dbs/postgresql/init_schema.sql @@ -128,7 +128,8 @@ $$ t_sessions bigint NOT NULL DEFAULT 0, t_users integer NOT NULL DEFAULT 1, t_integrations integer NOT NULL DEFAULT 0, - CONSTRAINT onerow_uni CHECK (tenant_id = 1) + last_telemetry bigint NOT NULL DEFAULT CAST(EXTRACT(epoch FROM date_trunc('day', now())) * 1000 AS BIGINT) + CONSTRAINT onerow_uni CHECK (tenant_id = 1) ); CREATE TYPE user_role AS ENUM ('owner', 'admin', 'member'); @@ -167,7 +168,7 @@ $$ provider_user_id text NOT NULL, token text NOT NULL ); - CREATE UNIQUE INDEX oauth_authentication_unique_user_id_provider_idx ON oauth_authentication(user_id,provider); + CREATE UNIQUE INDEX oauth_authentication_unique_user_id_provider_idx ON oauth_authentication (user_id, provider); -- --- projects.sql ---