Skip to content

Commit

Permalink
Add multiple versions of group annotation types
Browse files Browse the repository at this point in the history
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
Show file tree
Hide file tree
Showing 12 changed files with 144 additions and 5 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -19,6 +19,10 @@ CREATE TYPE public.group_writeable_by AS ENUM (
'authority', 'members'
);

CREATE TYPE report.annotation_sub_type AS ENUM (
'annotation', 'reply', 'highlight', 'page_note'
);

IMPORT FOREIGN SCHEMA "public" LIMIT TO (
user_group,
"user",
Expand All @@ -28,5 +32,6 @@ IMPORT FOREIGN SCHEMA "public" LIMIT TO (
IMPORT FOREIGN SCHEMA "report" LIMIT TO (
authorities,
annotation_group_counts,
annotation_type_group_counts,
annotation_user_counts
) FROM SERVER "h_server" INTO h;
Original file line number Diff line number Diff line change
Expand Up @@ -7,10 +7,10 @@ CREATE MATERIALIZED VIEW report.group_bubbled_activity AS (
SELECT
created_week,
group_to_group.parent_id AS group_id,
SUM(annotation_count) as annotation_count,
SUM(annotation_shared_count) as annotation_shared_count,
SUM(annotation_replies_count) as annotation_replies_count,
SUM(launch_count) as launch_count
SUM(annotation_count) AS annotation_count,
SUM(annotation_shared_count) AS annotation_shared_count,
SUM(annotation_replies_count) AS annotation_replies_count,
SUM(launch_count) AS launch_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
Expand Down
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;
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);
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;
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);
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;
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);
Original file line number Diff line number Diff line change
Expand Up @@ -24,8 +24,11 @@
GRANT SELECT ON report.group_map TO "{{fdw_user}}";
GRANT SELECT ON report.group_bubbled_activity TO "{{fdw_user}}";
GRANT SELECT ON report.group_bubbled_counts TO "{{fdw_user}}";
GRANT SELECT ON report.group_type_counts TO "{{fdw_user}}";
GRANT SELECT ON report.group_bubbled_type_counts TO "{{fdw_user}}";
GRANT SELECT ON report.group_roles TO "{{fdw_user}}";
GRANT SELECT ON report.organization_activity TO "{{fdw_user}}";
GRANT SELECT ON report.organization_annotation_types TO "{{fdw_user}}";
GRANT SELECT ON report.organization_assignments TO "{{fdw_user}}";
GRANT SELECT ON report.organization_roles TO "{{fdw_user}}";
GRANT SELECT ON report.users TO "{{fdw_user}}";
Expand Down
11 changes: 10 additions & 1 deletion lms/data_tasks/report/refresh/03_activity_counts_refresh.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,8 +7,17 @@ ANALYSE report.group_bubbled_activity;
REFRESH MATERIALIZED VIEW CONCURRENTLY report.group_bubbled_counts;
ANALYSE report.group_bubbled_counts;

REFRESH MATERIALIZED VIEW CONCURRENTLY report.group_type_counts;
ANALYSE report.group_type_counts;

REFRESH MATERIALIZED VIEW CONCURRENTLY report.group_bubbled_type_counts;
ANALYSE report.group_bubbled_type_counts;

REFRESH MATERIALIZED VIEW CONCURRENTLY report.user_activity;
ANALYSE report.organization_activity;
ANALYSE report.user_activity;

REFRESH MATERIALIZED VIEW CONCURRENTLY report.organization_activity;
ANALYSE report.organization_activity;

REFRESH MATERIALIZED VIEW CONCURRENTLY report.organization_annotation_types;
ANALYSE report.organization_annotation_types;

0 comments on commit f898379

Please sign in to comment.