From 0798154fa26f965f80b17e7a945055c1030be415 Mon Sep 17 00:00:00 2001 From: Rebecca Law Date: Tue, 20 Mar 2018 15:48:32 +0000 Subject: [PATCH] Optimize the query used to return the services and todays notification totals. By changing the created_at filter to use a specific date range I found a significant improvement to the queries performance. The unit test needed to change because now were are returning todays date as BST the local timezone. Query plan before Merge Left Join (cost=1226133.76..1226143.77 rows=1753 width=70) (actual time=5800.160..5801.657 rows=1849 loops=1) Merge Cond: (services.id = anon_1.service_id) -> Sort (cost=152.99..157.37 rows=1753 width=46) (actual time=2.205..2.631 rows=1762 loops=1) Sort Key: services.id Sort Method: quicksort Memory: 224kB -> Seq Scan on services (cost=0.00..58.54 rows=1753 width=46) (actual time=0.011..1.156 rows=1762 loops=1) Filter: active Rows Removed by Filter: 101 -> Sort (cost=1225980.77..1225980.99 rows=86 width=40) (actual time=5797.949..5797.984 rows=198 loops=1) Sort Key: anon_1.service_id Sort Method: quicksort Memory: 40kB -> Subquery Scan on anon_1 (cost=1225976.29..1225978.01 rows=86 width=40) (actual time=5797.682..5797.823 rows=198 loops=1) -> HashAggregate (cost=1225976.29..1225977.15 rows=86 width=48) (actual time=5797.681..5797.747 rows=198 loops=1) Group Key: notifications.notification_type, notifications.notification_status, notifications.service_id -> Seq Scan on notifications (cost=0.00..1220610.86 rows=536543 width=48) (actual time=0.064..5482.975 rows=643799 loops=1) Filter: (((key_type)::text <> 'TEST'::text) AND (date(created_at) = '2018-03-20'::date)) Rows Removed by Filter: 6804774 Planning time: 1.106 ms Execution time: 5802.130 ms Query plan after Merge Left Join (cost=953378.30..953388.30 rows=1753 width=70) (actual time=2380.144..2382.499 rows=1852 loops=1) Merge Cond: (services.id = anon_1.service_id) -> Sort (cost=152.99..157.37 rows=1753 width=46) (actual time=2.944..3.570 rows=1762 loops=1) Sort Key: services.id Sort Method: quicksort Memory: 224kB -> Seq Scan on services (cost=0.00..58.54 rows=1753 width=46) (actual time=0.006..1.294 rows=1762 loops=1) Filter: active Rows Removed by Filter: 101 -> Sort (cost=953225.31..953225.53 rows=86 width=40) (actual time=2377.194..2377.262 rows=201 loops=1) Sort Key: anon_1.service_id Sort Method: quicksort Memory: 40kB -> Subquery Scan on anon_1 (cost=953220.83..953222.55 rows=86 width=40) (actual time=2376.797..2377.034 rows=201 loops=1) -> HashAggregate (cost=953220.83..953221.69 rows=86 width=48) (actual time=2376.795..2376.905 rows=201 loops=1) Group Key: notifications.notification_type, notifications.notification_status, notifications.service_id -> Bitmap Heap Scan on notifications (cost=29883.14..947856.24 rows=536459 width=48) (actual time=270.061..1887.754 rows=644735 loops=1) Recheck Cond: ((created_at >= '2018-03-20 00:00:00'::timestamp without time zone) AND (created_at < '2018-03-21 00:00:00'::timestamp without time zone)) Rows Removed by Index Recheck: 947427 Filter: ((key_type)::text <> 'TEST'::text) Heap Blocks: exact=40882 lossy=186483 -> Bitmap Index Scan on ix_notifications_created_at (cost=0.00..29749.02 rows=536459 width=0) (actual time=258.631..258.631 rows=644849 loops=1) Index Cond: ((created_at >= '2018-03-20 00:00:00'::timestamp without time zone) AND (created_at < '2018-03-21 00:00:00'::timestamp without time zone)) Planning time: 0.548 ms Execution time: 2383.485 ms --- app/dao/services_dao.py | 6 +++++- tests/app/service/test_rest.py | 3 ++- 2 files changed, 7 insertions(+), 2 deletions(-) diff --git a/app/dao/services_dao.py b/app/dao/services_dao.py index 027cd9f82..c362e19d9 100644 --- a/app/dao/services_dao.py +++ b/app/dao/services_dao.py @@ -333,6 +333,9 @@ def dao_fetch_monthly_historical_stats_for_service(service_id, year): @statsd(namespace='dao') def dao_fetch_todays_stats_for_all_services(include_from_test_key=True, only_active=True): + today = date.today() + start_date = get_london_midnight_in_utc(today) + end_date = get_london_midnight_in_utc(today + timedelta(days=1)) subquery = db.session.query( Notification.notification_type, @@ -340,7 +343,8 @@ def dao_fetch_todays_stats_for_all_services(include_from_test_key=True, only_act Notification.service_id, func.count(Notification.id).label('count') ).filter( - func.date(Notification.created_at) == date.today(), + Notification.created_at >= start_date, + Notification.created_at < end_date ).group_by( Notification.notification_type, Notification.status, diff --git a/tests/app/service/test_rest.py b/tests/app/service/test_rest.py index 912e8c120..92e8ddd41 100644 --- a/tests/app/service/test_rest.py +++ b/tests/app/service/test_rest.py @@ -1635,6 +1635,7 @@ def test_get_detailed_services_only_includes_todays_notifications(notify_db, not create_sample_notification(notify_db, notify_db_session, created_at=datetime(2015, 10, 9, 23, 59)) create_sample_notification(notify_db, notify_db_session, created_at=datetime(2015, 10, 10, 0, 0)) create_sample_notification(notify_db, notify_db_session, created_at=datetime(2015, 10, 10, 12, 0)) + create_sample_notification(notify_db, notify_db_session, created_at=datetime(2015, 10, 10, 23, 0)) with freeze_time('2015-10-10T12:00:00'): data = get_detailed_services(start_date=datetime.utcnow().date(), end_date=datetime.utcnow().date()) @@ -1643,7 +1644,7 @@ def test_get_detailed_services_only_includes_todays_notifications(notify_db, not assert len(data) == 1 assert data[0]['statistics'] == { EMAIL_TYPE: {'delivered': 0, 'failed': 0, 'requested': 0}, - SMS_TYPE: {'delivered': 0, 'failed': 0, 'requested': 2}, + SMS_TYPE: {'delivered': 0, 'failed': 0, 'requested': 3}, LETTER_TYPE: {'delivered': 0, 'failed': 0, 'requested': 0} }