|
19 | 19 | # |1|00:00:00.208768|00:00:01.398161|00:00:28.951521|
|
20 | 20 | # |2|00:00:01.330297|00:00:06.076814|00:00:03.481192|
|
21 | 21 | # |3|00:00:02.092967|00:00:11.271081|00:00:06.045881|
|
| 22 | + |
| 23 | +UPDATE_PROJECT_GROUP_DATA_USING_PROJECT_ID = f""" |
| 24 | + WITH to_calculate_groups AS ( |
| 25 | + SELECT |
| 26 | + project_id, |
| 27 | + group_id |
| 28 | + FROM groups |
| 29 | + WHERE |
| 30 | + (project_id, group_id) in ( |
| 31 | + SELECT |
| 32 | + MS.project_id, |
| 33 | + MS.group_id |
| 34 | + FROM mapping_sessions MS |
| 35 | + WHERE |
| 36 | + project_id = %(project_id)s |
| 37 | + GROUP BY MS.project_id, MS.group_id |
| 38 | + ) AND |
| 39 | + ( |
| 40 | + total_area is NULL OR time_spent_max_allowed is NULL |
| 41 | + ) |
| 42 | + ), |
| 43 | + groups_data AS ( |
| 44 | + SELECT |
| 45 | + T.project_id, |
| 46 | + T.group_id, |
| 47 | + SUM( -- sqkm |
| 48 | + ST_Area(T.geom::geography(GEOMETRY,4326)) / 1000000 |
| 49 | + ) as total_task_group_area, |
| 50 | + ( |
| 51 | + CASE |
| 52 | + -- Using 95_percent value of existing data for each project_type |
| 53 | + WHEN P.project_type = {Project.Type.BUILD_AREA.value} THEN 1.4 |
| 54 | + WHEN P.project_type = {Project.Type.COMPLETENESS.value} THEN 1.4 |
| 55 | + WHEN P.project_type = {Project.Type.CHANGE_DETECTION.value} THEN 11.2 |
| 56 | + -- FOOTPRINT: Not calculated right now |
| 57 | + WHEN P.project_type = {Project.Type.FOOTPRINT.value} THEN 6.1 |
| 58 | + ELSE 1 |
| 59 | + END |
| 60 | + ) * COUNT(*) as time_spent_max_allowed |
| 61 | + FROM tasks T |
| 62 | + INNER JOIN to_calculate_groups G USING (project_id, group_id) |
| 63 | + INNER JOIN projects P USING (project_id) |
| 64 | + GROUP BY project_id, P.project_type, group_id |
| 65 | + ) |
| 66 | + UPDATE groups G |
| 67 | + SET |
| 68 | + total_area = GD.total_task_group_area, |
| 69 | + time_spent_max_allowed = GD.time_spent_max_allowed |
| 70 | + FROM groups_data GD |
| 71 | + WHERE |
| 72 | + G.project_id = GD.project_id AND |
| 73 | + G.group_id = GD.group_id; |
| 74 | +""" |
| 75 | + |
| 76 | + |
| 77 | +UPDATE_PROJECT_GROUP_DATA_USING_TIME_RANGE = f""" |
| 78 | + WITH to_calculate_groups AS ( |
| 79 | + SELECT |
| 80 | + project_id, |
| 81 | + group_id |
| 82 | + FROM groups |
| 83 | + WHERE |
| 84 | + (project_id, group_id) in ( |
| 85 | + SELECT |
| 86 | + MS.project_id, |
| 87 | + MS.group_id |
| 88 | + FROM mapping_sessions MS |
| 89 | + WHERE |
| 90 | + MS.start_time >= %(from_date)s |
| 91 | + AND MS.start_time < %(until_date)s |
| 92 | + GROUP BY MS.project_id, MS.group_id |
| 93 | + ) AND |
| 94 | + ( |
| 95 | + total_area is NULL OR time_spent_max_allowed is NULL |
| 96 | + ) |
| 97 | + ), |
| 98 | + groups_data AS ( |
| 99 | + SELECT |
| 100 | + T.project_id, |
| 101 | + T.group_id, |
| 102 | + SUM( -- sqkm |
| 103 | + ST_Area(T.geom::geography(GEOMETRY,4326)) / 1000000 |
| 104 | + ) as total_task_group_area, |
| 105 | + ( |
| 106 | + CASE |
| 107 | + -- Using 95_percent value of existing data for each project_type |
| 108 | + WHEN P.project_type = {Project.Type.BUILD_AREA.value} THEN 1.4 |
| 109 | + WHEN P.project_type = {Project.Type.COMPLETENESS.value} THEN 1.4 |
| 110 | + WHEN P.project_type = {Project.Type.CHANGE_DETECTION.value} THEN 11.2 |
| 111 | + -- FOOTPRINT: Not calculated right now |
| 112 | + WHEN P.project_type = {Project.Type.FOOTPRINT.value} THEN 6.1 |
| 113 | + ELSE 1 |
| 114 | + END |
| 115 | + ) * COUNT(*) as time_spent_max_allowed |
| 116 | + FROM tasks T |
| 117 | + INNER JOIN to_calculate_groups G USING (project_id, group_id) |
| 118 | + INNER JOIN projects P USING (project_id) |
| 119 | + GROUP BY project_id, P.project_type, group_id |
| 120 | + ) |
| 121 | + UPDATE groups G |
| 122 | + SET |
| 123 | + total_area = GD.total_task_group_area, |
| 124 | + time_spent_max_allowed = GD.time_spent_max_allowed |
| 125 | + FROM groups_data GD |
| 126 | + WHERE |
| 127 | + G.project_id = GD.project_id AND |
| 128 | + G.group_id = GD.group_id; |
| 129 | +""" |
| 130 | + |
22 | 131 | TASK_GROUP_METADATA_QUERY = f"""
|
23 |
| - SELECT |
24 |
| - project_id, |
25 |
| - group_id, |
26 |
| - SUM( |
27 |
| - ST_Area(geom::geography(GEOMETRY,4326)) / 1000000 |
28 |
| - ) as total_task_group_area, -- sqkm |
29 |
| - ( |
| 132 | + SELECT |
| 133 | + G.project_id, |
| 134 | + G.group_id, |
| 135 | + ( |
30 | 136 | CASE
|
31 |
| - -- Using 95_percent value of existing data for each project_type |
32 |
| - WHEN UG.project_type = {Project.Type.BUILD_AREA.value} THEN 1.4 |
33 |
| - WHEN UG.project_type = {Project.Type.COMPLETENESS.value} THEN 1.4 |
34 |
| - WHEN UG.project_type = {Project.Type.CHANGE_DETECTION.value} THEN 11.2 |
35 |
| - -- FOOTPRINT: Not calculated right now |
36 |
| - WHEN UG.project_type = {Project.Type.FOOTPRINT.value} THEN 6.1 |
37 |
| - ELSE 1 |
| 137 | + -- Hide area for Footprint |
| 138 | + WHEN P.project_type = {Project.Type.FOOTPRINT.value} THEN 0 |
| 139 | + ELSE G.total_area |
38 | 140 | END
|
39 |
| - ) * COUNT(*) as time_spent_max_allowed |
40 |
| - FROM tasks T |
41 |
| - INNER JOIN used_task_groups UG USING (project_id, group_id) |
42 |
| - GROUP BY project_id, project_type, group_id |
| 141 | + ) as total_task_group_area, |
| 142 | + G.time_spent_max_allowed |
| 143 | + FROM groups G |
| 144 | + INNER JOIN used_task_groups UG USING (project_id, group_id) |
| 145 | + INNER JOIN projects P USING (project_id) |
| 146 | + GROUP BY G.project_id, P.project_type, G.group_id |
43 | 147 | """
|
44 | 148 |
|
45 | 149 |
|
|
63 | 167 | FROM mapping_sessions MS
|
64 | 168 | INNER JOIN projects P USING (project_id)
|
65 | 169 | WHERE
|
66 |
| - -- Skip for footprint type missions |
67 |
| - P.project_type != {Project.Type.FOOTPRINT.value} |
68 |
| - AND MS.start_time >= %(from_date)s |
| 170 | + MS.start_time >= %(from_date)s |
69 | 171 | AND MS.start_time < %(until_date)s
|
70 | 172 | GROUP BY project_id, project_type, group_id -- To get unique
|
71 | 173 | ),
|
|
142 | 244 | INNER JOIN mapping_sessions MS USING (mapping_session_id)
|
143 | 245 | INNER JOIN projects P USING (project_id)
|
144 | 246 | WHERE
|
145 |
| - -- Skip for footprint type missions |
146 |
| - P.project_type != {Project.Type.FOOTPRINT.value} |
147 |
| - AND MS.start_time >= %(from_date)s |
| 247 | + MS.start_time >= %(from_date)s |
148 | 248 | AND MS.start_time < %(until_date)s
|
149 | 249 | GROUP BY project_id, project_type, group_id -- To get unique
|
150 | 250 | ),
|
@@ -239,6 +339,20 @@ def _track(self, tracker_type, label, sql):
|
239 | 339 | until_date=until_date.strftime("%Y-%m-%d"),
|
240 | 340 | )
|
241 | 341 | start_time = time.time()
|
| 342 | + |
| 343 | + self.stdout.write( |
| 344 | + f"Updating Project Group Data for {label.title()} for date: {params}" |
| 345 | + ) |
| 346 | + with transaction.atomic(): |
| 347 | + with connection.cursor() as cursor: |
| 348 | + cursor.execute(UPDATE_PROJECT_GROUP_DATA_USING_TIME_RANGE, params) |
| 349 | + self.stdout.write( |
| 350 | + self.style.SUCCESS( |
| 351 | + f"Successfull. Runtime: {time.time() - start_time} seconds" |
| 352 | + ) |
| 353 | + ) |
| 354 | + |
| 355 | + start_time = time.time() |
242 | 356 | self.stdout.write(f"Updating {label.title()} Data for date: {params}")
|
243 | 357 | with transaction.atomic():
|
244 | 358 | with connection.cursor() as cursor:
|
|
0 commit comments