forked from rapidpro/rapidpro
-
Notifications
You must be signed in to change notification settings - Fork 25
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Start tracking incoming message counts by flow
- Loading branch information
1 parent
87deb12
commit a8c434f
Showing
5 changed files
with
162 additions
and
24 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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,68 @@ | ||
# Generated by Django 5.1.2 on 2024-11-21 20:45 | ||
|
||
from django.db import migrations | ||
|
||
SQL = """ | ||
---------------------------------------------------------------------- | ||
-- Handles UPDATE statements on msg table | ||
---------------------------------------------------------------------- | ||
CREATE OR REPLACE FUNCTION temba_msg_on_update() RETURNS TRIGGER AS $$ | ||
BEGIN | ||
-- add negative counts for all old non-null system labels that don't match the new ones | ||
INSERT INTO msgs_systemlabelcount("org_id", "label_type", "count", "is_squashed") | ||
SELECT o.org_id, temba_msg_determine_system_label(o), -count(*), FALSE FROM oldtab o | ||
INNER JOIN newtab n ON n.id = o.id | ||
WHERE temba_msg_determine_system_label(o) IS DISTINCT FROM temba_msg_determine_system_label(n) AND temba_msg_determine_system_label(o) IS NOT NULL | ||
GROUP BY 1, 2; | ||
-- add counts for all new system labels that don't match the old ones | ||
INSERT INTO msgs_systemlabelcount("org_id", "label_type", "count", "is_squashed") | ||
SELECT n.org_id, temba_msg_determine_system_label(n), count(*), FALSE FROM newtab n | ||
INNER JOIN oldtab o ON o.id = n.id | ||
WHERE temba_msg_determine_system_label(o) IS DISTINCT FROM temba_msg_determine_system_label(n) AND temba_msg_determine_system_label(n) IS NOT NULL | ||
GROUP BY 1, 2; | ||
-- add negative old-state label counts for all messages being archived/restored | ||
INSERT INTO msgs_labelcount("label_id", "is_archived", "count", "is_squashed") | ||
SELECT ml.label_id, o.visibility != 'V', -count(*), FALSE FROM oldtab o | ||
INNER JOIN newtab n ON n.id = o.id | ||
INNER JOIN msgs_msg_labels ml ON ml.msg_id = o.id | ||
WHERE (o.visibility = 'V' AND n.visibility != 'V') or (o.visibility != 'V' AND n.visibility = 'V') | ||
GROUP BY 1, 2; | ||
-- add new-state label counts for all messages being archived/restored | ||
INSERT INTO msgs_labelcount("label_id", "is_archived", "count", "is_squashed") | ||
SELECT ml.label_id, n.visibility != 'V', count(*), FALSE FROM newtab n | ||
INNER JOIN oldtab o ON o.id = n.id | ||
INNER JOIN msgs_msg_labels ml ON ml.msg_id = n.id | ||
WHERE (o.visibility = 'V' AND n.visibility != 'V') or (o.visibility != 'V' AND n.visibility = 'V') | ||
GROUP BY 1, 2; | ||
-- add new flow activity counts for incoming messages now marked as handled by a flow | ||
INSERT INTO flows_flowactivitycount("flow_id", "scope", "count", "is_squashed") | ||
SELECT n.flow_id, format('msgsin:hour:%s', extract(hour FROM n.created_on)), count(*), FALSE FROM newtab n | ||
INNER JOIN oldtab o ON o.id = n.id | ||
WHERE o.flow_id IS NULL AND n.flow_id IS NOT NULL | ||
GROUP BY 1, 2; | ||
INSERT INTO flows_flowactivitycount("flow_id", "scope", "count", "is_squashed") | ||
SELECT n.flow_id, format('msgsin:dow:%s', extract(isodow FROM n.created_on)), count(*), FALSE FROM newtab n | ||
INNER JOIN oldtab o ON o.id = n.id | ||
WHERE o.flow_id IS NULL AND n.flow_id IS NOT NULL | ||
GROUP BY 1, 2; | ||
INSERT INTO flows_flowactivitycount("flow_id", "scope", "count", "is_squashed") | ||
SELECT n.flow_id, format('msgsin:date:%s', n.created_on::date), count(*), FALSE FROM newtab n | ||
INNER JOIN oldtab o ON o.id = n.id | ||
WHERE o.flow_id IS NULL AND n.flow_id IS NOT NULL | ||
GROUP BY 1, 2; | ||
RETURN NULL; | ||
END; | ||
$$ LANGUAGE plpgsql; | ||
""" | ||
|
||
|
||
class Migration(migrations.Migration): | ||
|
||
dependencies = [("flows", "0339_update_triggers")] | ||
|
||
operations = [migrations.RunSQL(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
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
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