From c6e2bab90fa51ca504465bce1d46c88c3b410d49 Mon Sep 17 00:00:00 2001 From: Kraiem Taha Yassine Date: Thu, 1 Jul 2021 12:20:25 +0200 Subject: [PATCH] Api metrics (#70) * feat(api): changed initial connetion pool s * feat(api): FOS metrics optimization feat(db): Indexes change & delta --- api/chalicelib/core/dashboard.py | 45 +++++++++++-------- api/db_changes.sql | 7 +++ .../db/init_dbs/postgresql/init_schema.sql | 5 +++ 3 files changed, 39 insertions(+), 18 deletions(-) create mode 100644 api/db_changes.sql diff --git a/api/chalicelib/core/dashboard.py b/api/chalicelib/core/dashboard.py index 6cfbad461..deef86e95 100644 --- a/api/chalicelib/core/dashboard.py +++ b/api/chalicelib/core/dashboard.py @@ -299,16 +299,22 @@ def get_page_metrics(project_id, startTimestamp=TimeUTC.now(delta_days=-1), results[key + "Progress"] = helper.__progress(old_val=previous[key], new_val=results[key]) return results - +@dev.timed def __get_page_metrics(cur, project_id, startTimestamp, endTimestamp, **args): pg_sub_query = __get_constraints(project_id=project_id, data=args) pg_query = f"""\ - SELECT - COALESCE(AVG(NULLIF(pages.dom_content_loaded_time ,0)),0) AS avg_dom_content_load_start, - COALESCE(AVG(NULLIF(pages.first_contentful_paint_time,0)),0) AS avg_first_contentful_pixel - FROM events.pages INNER JOIN public.sessions USING (session_id) - WHERE {" AND ".join(pg_sub_query)};""" + SELECT COALESCE((SELECT AVG(pages.dom_content_loaded_time) + FROM events.pages + INNER JOIN public.sessions USING (session_id) + WHERE {" AND ".join(pg_sub_query)} + AND pages.dom_content_loaded_time > 0 + ), 0) AS avg_dom_content_load_start, + COALESCE((SELECT AVG(pages.first_contentful_paint_time) + FROM events.pages + INNER JOIN public.sessions USING (session_id) + WHERE {" AND ".join(pg_sub_query)} + AND pages.first_contentful_paint_time > 0), 0) AS avg_first_contentful_pixel;""" params = {"project_id": project_id, "startTimestamp": startTimestamp, "endTimestamp": endTimestamp, **__get_constraint_values(args)} cur.execute(cur.mogrify(pg_query, params)) @@ -488,13 +494,13 @@ def get_performance(project_id, startTimestamp=TimeUTC.now(delta_days=-1), endTi with pg_client.PostgresClient() as cur: pg_query = f"""SELECT generated_timestamp AS timestamp, - COALESCE(AVG(NULLIF(resources.duration,0)),0) AS avg_image_load_time + COALESCE(AVG(resources.duration),0) AS avg_image_load_time FROM generate_series(%(startTimestamp)s, %(endTimestamp)s, %(step_size)s) AS generated_timestamp LEFT JOIN LATERAL ( SELECT resources.duration FROM events.resources INNER JOIN public.sessions USING (session_id) WHERE {" AND ".join(pg_sub_query_chart)} - AND resources.type = 'img' + AND resources.type = 'img' AND resources.duration>0 {(f' AND ({" OR ".join(img_constraints)})') if len(img_constraints) > 0 else ""} ) AS resources ON (TRUE) GROUP BY timestamp @@ -504,13 +510,13 @@ def get_performance(project_id, startTimestamp=TimeUTC.now(delta_days=-1), endTi images = helper.list_to_camel_case(rows) pg_query = f"""SELECT generated_timestamp AS timestamp, - COALESCE(AVG(NULLIF(resources.duration,0)),0) AS avg_request_load_time + COALESCE(AVG(resources.duration),0) AS avg_request_load_time FROM generate_series(%(startTimestamp)s, %(endTimestamp)s, %(step_size)s) AS generated_timestamp LEFT JOIN LATERAL ( SELECT resources.duration FROM events.resources INNER JOIN public.sessions USING (session_id) WHERE {" AND ".join(pg_sub_query_chart)} - AND resources.type = 'fetch' + AND resources.type = 'fetch' AND resources.duration>0 {(f' AND ({" OR ".join(request_constraints)})') if len(request_constraints) > 0 else ""} ) AS resources ON (TRUE) GROUP BY generated_timestamp @@ -521,16 +527,15 @@ def get_performance(project_id, startTimestamp=TimeUTC.now(delta_days=-1), endTi pg_query = f"""SELECT generated_timestamp AS timestamp, - COALESCE(AVG(NULLIF(pages.load_time ,0)),0) AS avg_page_load_time + COALESCE(AVG(pages.load_time),0) AS avg_page_load_time FROM generate_series(%(startTimestamp)s, %(endTimestamp)s, %(step_size)s) AS generated_timestamp LEFT JOIN LATERAL ( SELECT pages.load_time FROM events.pages INNER JOIN public.sessions USING (session_id) - WHERE {" AND ".join(pg_sub_query_chart)} + WHERE {" AND ".join(pg_sub_query_chart)} AND pages.load_time>0 {(f' AND ({" OR ".join(location_constraints)})') if len(location_constraints) > 0 else ""} ) AS pages ON (TRUE) GROUP BY generated_timestamp ORDER BY generated_timestamp;""" - cur.execute(cur.mogrify(pg_query, {**params, **location_constraints_vals, **__get_constraint_values(args)})) rows = cur.fetchall() pages = helper.list_to_camel_case(rows) @@ -1205,12 +1210,16 @@ def get_top_metrics(project_id, startTimestamp=TimeUTC.now(delta_days=-1), if value is not None: pg_sub_query.append("pages.path = %(value)s") with pg_client.PostgresClient() as cur: - pg_query = f"""SELECT (SELECT COALESCE(AVG(pages.response_time),0) FROM events.pages INNER JOIN public.sessions USING (session_id) WHERE {" AND ".join(pg_sub_query)} AND pages.response_time IS NOT NULL AND pages.response_time>0) AS avg_response_time, + pg_query = f"""SELECT (SELECT COALESCE(AVG(pages.response_time),0) FROM events.pages INNER JOIN public.sessions USING (session_id) WHERE {" AND ".join(pg_sub_query)} AND pages.response_time>0) AS avg_response_time, (SELECT COUNT(pages.session_id) FROM events.pages INNER JOIN public.sessions USING (session_id) WHERE {" AND ".join(pg_sub_query)}) AS count_requests, - (SELECT COALESCE(AVG(pages.first_paint_time),0) FROM events.pages INNER JOIN public.sessions USING (session_id) WHERE {" AND ".join(pg_sub_query)} AND pages.first_paint_time IS NOT NULL AND pages.first_paint_time>0) AS avg_first_paint, - (SELECT COALESCE(AVG(pages.dom_content_loaded_time),0) FROM events.pages INNER JOIN public.sessions USING (session_id) WHERE {" AND ".join(pg_sub_query)} AND pages.dom_content_loaded_time IS NOT NULL AND pages.dom_content_loaded_time>0) AS avg_dom_content_loaded, - (SELECT COALESCE(AVG(pages.ttfb),0) FROM events.pages INNER JOIN public.sessions USING (session_id) WHERE {" AND ".join(pg_sub_query)} AND pages.ttfb IS NOT NULL AND pages.ttfb>0) AS avg_till_first_bit, - (SELECT COALESCE(AVG(pages.time_to_interactive),0) FROM events.pages INNER JOIN public.sessions USING (session_id) WHERE {" AND ".join(pg_sub_query)} AND pages.time_to_interactive IS NOT NULL AND pages.time_to_interactive >0) AS avg_time_to_interactive;""" + (SELECT COALESCE(AVG(pages.first_paint_time),0) FROM events.pages INNER JOIN public.sessions USING (session_id) WHERE {" AND ".join(pg_sub_query)} AND pages.first_paint_time>0) AS avg_first_paint, + (SELECT COALESCE(AVG(pages.dom_content_loaded_time),0) FROM events.pages INNER JOIN public.sessions USING (session_id) WHERE {" AND ".join(pg_sub_query)} AND pages.dom_content_loaded_time>0) AS avg_dom_content_loaded, + (SELECT COALESCE(AVG(pages.ttfb),0) FROM events.pages INNER JOIN public.sessions USING (session_id) WHERE {" AND ".join(pg_sub_query)} AND pages.ttfb>0) AS avg_till_first_bit, + (SELECT COALESCE(AVG(pages.time_to_interactive),0) FROM events.pages INNER JOIN public.sessions USING (session_id) WHERE {" AND ".join(pg_sub_query)} AND pages.time_to_interactive >0) AS avg_time_to_interactive;""" + print(cur.mogrify(pg_query, {"project_id": project_id, + "startTimestamp": startTimestamp, + "endTimestamp": endTimestamp, + "value": value, **__get_constraint_values(args)})) cur.execute(cur.mogrify(pg_query, {"project_id": project_id, "startTimestamp": startTimestamp, "endTimestamp": endTimestamp, diff --git a/api/db_changes.sql b/api/db_changes.sql new file mode 100644 index 000000000..d9acf06fa --- /dev/null +++ b/api/db_changes.sql @@ -0,0 +1,7 @@ +BEGIN; +CREATE INDEX pages_first_contentful_paint_time_idx ON events.pages (first_contentful_paint_time) WHERE first_contentful_paint_time>0; +CREATE INDEX pages_dom_content_loaded_time_idx ON events.pages (dom_content_loaded_time) WHERE dom_content_loaded_time>0; +CREATE INDEX pages_first_paint_time_idx ON events.pages (first_paint_time) WHERE first_paint_time > 0; +CREATE INDEX pages_ttfb_idx ON events.pages (ttfb) WHERE ttfb > 0; +CREATE INDEX pages_time_to_interactive_idx ON events.pages (time_to_interactive) WHERE time_to_interactive > 0; +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 af1f70f99..b058f9dac 100644 --- a/scripts/helm/db/init_dbs/postgresql/init_schema.sql +++ b/scripts/helm/db/init_dbs/postgresql/init_schema.sql @@ -656,6 +656,11 @@ CREATE INDEX pages_path_idx ON events.pages (path); CREATE INDEX pages_visually_complete_idx ON events.pages (visually_complete) WHERE visually_complete > 0; CREATE INDEX pages_dom_building_time_idx ON events.pages (dom_building_time) WHERE dom_building_time > 0; CREATE INDEX pages_load_time_idx ON events.pages (load_time) WHERE load_time > 0; +CREATE INDEX pages_first_contentful_paint_time_idx ON events.pages (first_contentful_paint_time) WHERE first_contentful_paint_time>0; +CREATE INDEX pages_dom_content_loaded_time_idx ON events.pages (dom_content_loaded_time) WHERE dom_content_loaded_time>0; +CREATE INDEX pages_first_paint_time_idx ON events.pages (first_paint_time) WHERE first_paint_time > 0; +CREATE INDEX pages_ttfb_idx ON events.pages (ttfb) WHERE ttfb > 0; +CREATE INDEX pages_time_to_interactive_idx ON events.pages (time_to_interactive) WHERE time_to_interactive > 0; CREATE TABLE events.clicks