Skip to content

Commit

Permalink
Random WIP???
Browse files Browse the repository at this point in the history
  • Loading branch information
jon-betts committed Jun 12, 2023
1 parent 6136125 commit 3e32f6a
Show file tree
Hide file tree
Showing 3 changed files with 56 additions and 1 deletion.
Original file line number Diff line number Diff line change
Expand Up @@ -6,5 +6,6 @@ REFRESH MATERIALIZED VIEW report.annotation_group_counts;
ANALYSE report.annotation_group_counts;

-- A unique index is mandatory for concurrent updates used in the refresh
CREATE UNIQUE INDEX annotation_group_counts_created_week_authority_id_group_id_idx ON report.annotation_group_counts (authority_id, created_week, group_id);
CREATE UNIQUE INDEX annotation_group_counts_created_week_authority_id_group_id_idx
ON report.annotation_group_counts (authority_id, created_week, group_id);
CREATE INDEX annotation_group_counts_created_week_idx ON report.annotation_group_counts USING BRIN (created_week);
Original file line number Diff line number Diff line change
@@ -0,0 +1,45 @@
DROP MATERIALIZED VIEW IF EXISTS report.annotation_type_group_counts CASCADE;

CREATE TYPE report.annotation_sub_type AS ENUM (
-- This is not a good name for a sub-type of an annotation, we should
-- change this
'annotation',
-- Other primary types of annotation
'reply', 'highlight', 'page_note',
-- A catch-all that should not happen
'other'
);

CREATE MATERIALIZED VIEW report.annotation_type_group_counts AS (
SELECT
group_id,
created_day,
CASE
WHEN has_text = true AND anchored = true AND is_root = true
THEN 'annotation'
WHEN has_text = false AND anchored = true AND is_root = true
THEN 'highlight'
WHEN has_text = true AND anchored = false AND is_root = true
THEN 'page_note'
WHEN has_text = true AND anchored = false AND is_root = false
THEN 'reply'
ELSE
-- This shouldn't happen, but it's good to check
'other'::report.annotation_sub_type
END AS sub_type,
shared,
COUNT(1) AS count
FROM (
SELECT
group_id,
DATE_TRUNC('day', created) AS created_day,
shared,
anchored,
-- Prep some booleans for easier comparisons later
size > 0 AS has_text,
ARRAY_LENGTH(parent_uuids, 1) = 0 AS is_root
FROM report.annotations
) AS data
GROUP BY group_id, created_day, sub_type, shared
ORDER BY group_id, created_day, count DESC
) WITH NO DATA;
Original file line number Diff line number Diff line change
@@ -0,0 +1,9 @@
DROP INDEX IF EXISTS report.annotation_type_group_counts_group_id_created_day_sub_type_idx;

REFRESH MATERIALIZED VIEW report.annotation_type_group_counts;

ANALYSE report.annotation_type_group_counts;

-- A unique index is mandatory for concurrent updates used in the refresh
CREATE UNIQUE INDEX annotation_type_group_counts_group_id_created_day_sub_type_idx
ON report.annotation_type_group_counts (group_id, created_day, sub_type, shared);

0 comments on commit 3e32f6a

Please sign in to comment.