-
Notifications
You must be signed in to change notification settings - Fork 14
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Add multiple versions of group annotation types
These are: * By the group * By the group - bubbled up to courses * By the organization
- Loading branch information
Jon Betts
committed
Jun 15, 2023
1 parent
5e8784d
commit f898379
Showing
12 changed files
with
144 additions
and
5 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
16 changes: 16 additions & 0 deletions
16
..._from_scratch/04_activity_counts/01_groups/04_group_type_counts/01_create_view.jinja2.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,16 @@ | ||
DROP MATERIALIZED VIEW IF EXISTS report.group_type_counts CASCADE; | ||
|
||
-- A weekly count of group annotation types limited to the correct authority | ||
|
||
CREATE MATERIALIZED VIEW report.group_type_counts AS ( | ||
SELECT | ||
created_week, | ||
group_id, | ||
sub_type, | ||
shared, | ||
count | ||
FROM h.annotation_type_group_counts | ||
JOIN h.authorities ON | ||
annotation_type_group_counts.authority_id = authorities.id | ||
AND authorities.authority = '{{ region.authority }}' | ||
) WITH NO DATA; |
9 changes: 9 additions & 0 deletions
9
...create_from_scratch/04_activity_counts/01_groups/04_group_type_counts/02_initial_fill.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,9 @@ | ||
DROP INDEX IF EXISTS report.group_type_counts_created_week_group_id_sub_type_shared_idx; | ||
|
||
REFRESH MATERIALIZED VIEW report.group_type_counts; | ||
|
||
ANALYSE report.group_type_counts; | ||
|
||
-- A unique index is mandatory for concurrent updates used in the refresh | ||
CREATE UNIQUE INDEX group_type_counts_created_week_group_id_sub_type_shared_idx | ||
ON report.group_type_counts (created_week, group_id, sub_type, shared); |
20 changes: 20 additions & 0 deletions
20
...from_scratch/04_activity_counts/01_groups/05_group_bubbled_type_counts/01_create_view.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,20 @@ | ||
DROP VIEW IF EXISTS report.group_bubble_type_counts CASCADE; | ||
|
||
-- A weekly count of annotation type, but with counts summed | ||
-- up and down between parents and children as appropriate. | ||
|
||
CREATE MATERIALIZED VIEW report.group_bubble_type_counts AS ( | ||
SELECT | ||
created_week, | ||
group_to_group.parent_id AS group_id, | ||
sub_type, | ||
shared, | ||
SUM(count) AS count | ||
FROM report.group_to_group | ||
-- The join on group to group without a relation includes self, | ||
-- so the child_id here is all children and ourselves | ||
JOIN report.group_type_counts ON | ||
group_type_counts.group_id = group_to_group.child_id | ||
GROUP BY created_week, group_to_group.parent_id, sub_type, shared | ||
ORDER BY created_week, group_to_group.parent_id, sub_type, shared | ||
) WITH NO DATA; |
8 changes: 8 additions & 0 deletions
8
...rom_scratch/04_activity_counts/01_groups/05_group_bubbled_type_counts/02_initial_fill.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,8 @@ | ||
DROP INDEX IF EXISTS report.group_bubbled_activity_created_week_group_id_idx; | ||
|
||
REFRESH MATERIALIZED VIEW report.group_bubbled_activity; | ||
|
||
ANALYSE report.group_bubbled_activity; | ||
|
||
-- A unique index is mandatory for concurrent updates used in the refresh | ||
CREATE UNIQUE INDEX group_bubbled_activity_created_week_group_id_idx ON report.group_bubbled_activity (created_week, group_id); |
File renamed without changes.
File renamed without changes.
57 changes: 57 additions & 0 deletions
57
...h/04_activity_counts/03_organizations/02_organization_annotation_types/01_create_view.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,57 @@ | ||
DROP MATERIALIZED VIEW IF EXISTS report.organization_annotation_types CASCADE; | ||
|
||
-- A multifaceted look at organization annotation types over different | ||
-- timescales | ||
|
||
CREATE MATERIALIZED VIEW report.organization_annotation_types AS ( | ||
WITH | ||
-- In order to get all the combinations of different types of data we | ||
-- want in this table without writing an explosion of queries we first | ||
-- create a "facets" CTE which represents all the different | ||
-- combinations of values we want to be able to filter by. | ||
|
||
-- We could probably do without this, but it makes it more like the | ||
-- `organization_activity` query | ||
weeks AS ( | ||
SELECT DISTINCT(created_week) AS timestamp_week | ||
FROM report.group_type_counts | ||
), | ||
|
||
timescales AS ( | ||
SELECT column1 AS timescale FROM ( | ||
VALUES | ||
('week'), | ||
('month'), | ||
('semester'), | ||
('academic_year'), | ||
('trailing_year'), | ||
('all_time') | ||
) AS data | ||
), | ||
|
||
facets AS ( | ||
SELECT | ||
timestamp_week, | ||
timescale::report.academic_timescale, | ||
report.multi_truncate(timescale, timestamp_week) AS period | ||
FROM weeks | ||
CROSS JOIN timescales | ||
) | ||
|
||
SELECT | ||
timescale, | ||
period::DATE AS start_date, | ||
(period + report.single_interval(timescale::text))::DATE AS end_date, | ||
report.present_date(timescale::text, period) AS period, | ||
group_map.organization_id, | ||
group_type_counts.sub_type, | ||
group_type_counts.shared, | ||
SUM(group_type_counts.count) AS count | ||
FROM facets | ||
JOIN report.group_type_counts ON | ||
group_type_counts.created_week = facets.timestamp_week | ||
JOIN report.group_map ON | ||
group_map.group_id = group_type_counts.group_id | ||
GROUP BY period, timescale, sub_type, shared, organization_id | ||
ORDER BY period, timescale, sub_type, shared, organization_id | ||
) WITH NO DATA; |
12 changes: 12 additions & 0 deletions
12
.../04_activity_counts/03_organizations/02_organization_annotation_types/02_initial_fill.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,12 @@ | ||
DROP INDEX IF EXISTS report.organization_annotation_types_period_timescale_sub_type_idx; | ||
DROP INDEX IF EXISTS report.organization_annotation_types_start_date_end_date_idx; | ||
|
||
REFRESH MATERIALIZED VIEW report.organization_annotation_types; | ||
|
||
ANALYSE report.organization_annotation_types; | ||
|
||
-- A unique index is mandatory for concurrent updates used in the refresh | ||
CREATE UNIQUE INDEX organization_annotation_types_period_timescale_sub_type_idx | ||
ON report.organization_annotation_types (period, timescale, sub_type, shared, organization_id); | ||
CREATE INDEX organization_annotation_types_start_date_end_date_idx | ||
ON report.organization_annotation_types (start_date, end_date); |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters