Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Rework msgs database triggers so we don't track counts for messages in archives #3691

Merged
merged 2 commits into from
Feb 21, 2022
Merged
Show file tree
Hide file tree
Changes from 1 commit
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
281 changes: 281 additions & 0 deletions temba/msgs/migrations/0166_delete_from_counts.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,281 @@
# Generated by Django 4.0.2 on 2022-02-16 15:51

from django.db import migrations

SQL = """
---------------------------------------------------------------------------------
-- Increment or decrement a system label count
---------------------------------------------------------------------------------
CREATE OR REPLACE FUNCTION temba_insert_system_label(_org_id INT, _label_type CHAR(1), _count INT)
RETURNS VOID AS $$
BEGIN
INSERT INTO msgs_systemlabelcount("org_id", "label_type", "is_archived", "count", "is_squashed")
VALUES(_org_id, _label_type, FALSE, _count, FALSE);
END;
$$ LANGUAGE plpgsql;

---------------------------------------------------------------------------------
-- Increment or decrement a user label count
---------------------------------------------------------------------------------
CREATE OR REPLACE FUNCTION temba_insert_label_count(_label_id INT, _count INT)
RETURNS VOID AS $$
BEGIN
INSERT INTO msgs_labelcount("label_id", "is_archived", "count", "is_squashed")
VALUES(_label_id, FALSE, _count, FALSE);
END;
$$ LANGUAGE plpgsql;

----------------------------------------------------------------------
-- Trigger procedure to update user and system labels on column changes
----------------------------------------------------------------------
CREATE OR REPLACE FUNCTION temba_msg_on_change() RETURNS TRIGGER AS $$
DECLARE
_new_label_type CHAR(1);
_old_label_type CHAR(1);
BEGIN
IF TG_OP IN ('INSERT', 'UPDATE') THEN
-- prevent illegal message states
IF NEW.direction = 'I' AND NEW.status NOT IN ('P', 'H') THEN
RAISE EXCEPTION 'Incoming messages can only be PENDING or HANDLED';
END IF;
IF NEW.direction = 'O' AND NEW.visibility = 'A' THEN
RAISE EXCEPTION 'Outgoing messages cannot be archived';
END IF;
END IF;

-- new message inserted
IF TG_OP = 'INSERT' THEN
_new_label_type := temba_msg_determine_system_label(NEW);
IF _new_label_type IS NOT NULL THEN
PERFORM temba_insert_system_label(NEW.org_id, _new_label_type, 1);
END IF;

IF NEW.broadcast_id IS NOT NULL THEN
PERFORM temba_insert_broadcastmsgcount(NEW.broadcast_id, 1);
END IF;

-- existing message updated
ELSIF TG_OP = 'UPDATE' THEN
_old_label_type := temba_msg_determine_system_label(OLD);
_new_label_type := temba_msg_determine_system_label(NEW);

IF _old_label_type IS DISTINCT FROM _new_label_type THEN
IF _old_label_type IS NOT NULL THEN
PERFORM temba_insert_system_label(OLD.org_id, _old_label_type, -1);
END IF;
IF _new_label_type IS NOT NULL THEN
PERFORM temba_insert_system_label(NEW.org_id, _new_label_type, 1);
END IF;
END IF;

-- is being archived or deleted (i.e. no longer included for user labels)
IF OLD.visibility = 'V' AND NEW.visibility != 'V' THEN
PERFORM temba_insert_message_label_counts(NEW.id, FALSE, -1);
END IF;

-- is being restored (i.e. now included for user labels)
IF OLD.visibility != 'V' AND NEW.visibility = 'V' THEN
PERFORM temba_insert_message_label_counts(NEW.id, FALSE, 1);
END IF;

-- update our broadcast msg count if it changed
IF NEW.broadcast_id IS DISTINCT FROM OLD.broadcast_id THEN
PERFORM temba_insert_broadcastmsgcount(OLD.broadcast_id, -1);
PERFORM temba_insert_broadcastmsgcount(NEW.broadcast_id, 1);
END IF;

-- existing message deleted
ELSIF TG_OP = 'DELETE' THEN
_old_label_type := temba_msg_determine_system_label(OLD);

IF _old_label_type IS NOT NULL THEN
PERFORM temba_insert_system_label(OLD.org_id, _old_label_type, -1);
END IF;
END IF;

RETURN NULL;
END;
$$ LANGUAGE plpgsql;

----------------------------------------------------------------------
-- Trigger procedure to update system labels on broadcast changes
----------------------------------------------------------------------
CREATE OR REPLACE FUNCTION temba_broadcast_on_change() RETURNS TRIGGER AS $$
DECLARE
_new_label_type CHAR(1);
_old_label_type CHAR(1);
BEGIN
-- new broadcast inserted
IF TG_OP = 'INSERT' THEN
_new_label_type := temba_broadcast_determine_system_label(NEW);
IF _new_label_type IS NOT NULL THEN
PERFORM temba_insert_system_label(NEW.org_id, _new_label_type, 1);
END IF;

-- existing broadcast updated
ELSIF TG_OP = 'UPDATE' THEN
_old_label_type := temba_broadcast_determine_system_label(OLD);
_new_label_type := temba_broadcast_determine_system_label(NEW);

IF _old_label_type IS DISTINCT FROM _new_label_type THEN
IF _old_label_type IS NOT NULL THEN
PERFORM temba_insert_system_label(OLD.org_id, _old_label_type, -1);
END IF;
IF _new_label_type IS NOT NULL THEN
PERFORM temba_insert_system_label(NEW.org_id, _new_label_type, 1);
END IF;
END IF;

-- existing broadcast deleted
ELSIF TG_OP = 'DELETE' THEN
_old_label_type := temba_broadcast_determine_system_label(OLD);

IF _old_label_type IS NOT NULL THEN
PERFORM temba_insert_system_label(OLD.org_id, _old_label_type, -1);
END IF;

END IF;

RETURN NULL;
END;
$$ LANGUAGE plpgsql;

----------------------------------------------------------------------
-- Trigger procedure to update system labels on channel event changes
----------------------------------------------------------------------
CREATE OR REPLACE FUNCTION temba_channelevent_on_change() RETURNS TRIGGER AS $$
BEGIN
-- new event inserted
IF TG_OP = 'INSERT' THEN
-- don't update anything for a non-call event
IF NOT temba_channelevent_is_call(NEW) THEN
RETURN NULL;
END IF;

PERFORM temba_insert_system_label(NEW.org_id, 'C', 1);

-- existing call updated
ELSIF TG_OP = 'UPDATE' THEN
-- don't update anything for a non-call event
IF NOT temba_channelevent_is_call(NEW) THEN
RETURN NULL;
END IF;

-- existing call deleted
ELSIF TG_OP = 'DELETE' THEN
-- don't update anything for a non-call event
IF NOT temba_channelevent_is_call(OLD) THEN
RETURN NULL;
END IF;

PERFORM temba_insert_system_label(OLD.org_id, 'C', -1);

END IF;

RETURN NULL;
END;
$$ LANGUAGE plpgsql;

----------------------------------------------------------------------
-- Manages keeping track of the # of messages sent and received by a channel
----------------------------------------------------------------------
CREATE OR REPLACE FUNCTION temba_update_channelcount() RETURNS TRIGGER AS $$
BEGIN
-- Message being updated
IF TG_OP = 'INSERT' THEN
-- Return if there is no channel on this message
IF NEW.channel_id IS NULL THEN
RETURN NULL;
END IF;

-- If this is an incoming message, without message type, then increment that count
IF NEW.direction = 'I' THEN
-- This is a voice message, increment that count
IF NEW.msg_type = 'V' THEN
PERFORM temba_insert_channelcount(NEW.channel_id, 'IV', NEW.created_on::date, 1);
-- Otherwise, this is a normal message
ELSE
PERFORM temba_insert_channelcount(NEW.channel_id, 'IM', NEW.created_on::date, 1);
END IF;

-- This is an outgoing message
ELSIF NEW.direction = 'O' THEN
-- This is a voice message, increment that count
IF NEW.msg_type = 'V' THEN
PERFORM temba_insert_channelcount(NEW.channel_id, 'OV', NEW.created_on::date, 1);
-- Otherwise, this is a normal message
ELSE
PERFORM temba_insert_channelcount(NEW.channel_id, 'OM', NEW.created_on::date, 1);
END IF;

END IF;

-- Assert that updates aren't happening that we don't approve of
ELSIF TG_OP = 'UPDATE' THEN
-- If the direction is changing, blow up
IF NEW.direction <> OLD.direction THEN
RAISE EXCEPTION 'Cannot change direction on messages';
END IF;

-- Cannot move from IVR to Text, or IVR to Text
IF (OLD.msg_type <> 'V' AND NEW.msg_type = 'V') OR (OLD.msg_type = 'V' AND NEW.msg_type <> 'V') THEN
RAISE EXCEPTION 'Cannot change a message from voice to something else or vice versa';
END IF;

-- Cannot change created_on
IF NEW.created_on <> OLD.created_on THEN
RAISE EXCEPTION 'Cannot change created_on on messages';
END IF;

END IF;

RETURN NULL;
END;
$$ LANGUAGE plpgsql;

-----------------------------------------------------------------------
--- Trigger procedure to maintain user label counts
-----------------------------------------------------------------------
CREATE OR REPLACE FUNCTION temba_msg_labels_on_change() RETURNS TRIGGER AS $$
DECLARE
is_visible BOOLEAN;
BEGIN
-- label applied to message
IF TG_OP = 'INSERT' THEN
-- is this message visible
SELECT msgs_msg.visibility = 'V'
INTO STRICT is_visible FROM msgs_msg
WHERE msgs_msg.id = NEW.msg_id;

IF is_visible THEN
PERFORM temba_insert_label_count(NEW.label_id, 1);
END IF;

-- label removed from message
ELSIF TG_OP = 'DELETE' THEN
-- is this message visible and why is it being deleted?
SELECT msgs_msg.visibility = 'V' INTO STRICT is_visible
FROM msgs_msg WHERE msgs_msg.id = OLD.msg_id;

IF is_visible THEN
PERFORM temba_insert_label_count(OLD.label_id, -1);
END IF;

END IF;

RETURN NULL;
END;
$$ LANGUAGE plpgsql;

DROP FUNCTION IF EXISTS temba_insert_system_label(INT, CHAR(1), BOOLEAN, INT);
DROP FUNCTION IF EXISTS temba_insert_label_count(INT, CHAR(1), BOOLEAN, INT);
"""


class Migration(migrations.Migration):

dependencies = [
("msgs", "0165_alter_msg_visibility"),
]

operations = [migrations.RunSQL(SQL)]
8 changes: 4 additions & 4 deletions temba/msgs/models.py
Original file line number Diff line number Diff line change
Expand Up @@ -875,11 +875,11 @@ def get_squash_query(cls, distinct_set):
return sql, (distinct_set.org_id, distinct_set.label_type, distinct_set.is_archived) * 2

@classmethod
def get_totals(cls, org, is_archived=False):
def get_totals(cls, org):
"""
Gets all system label counts by type for the given org
"""
counts = cls.objects.filter(org=org, is_archived=is_archived)
counts = cls.objects.filter(org=org, is_archived=False)
counts = counts.values_list("label_type").annotate(count_sum=Sum("count"))
counts_by_type = {c[0]: c[1] for c in counts}

Expand Down Expand Up @@ -1095,12 +1095,12 @@ def get_squash_query(cls, distinct_set):
return sql, (distinct_set.label_id, distinct_set.is_archived) * 2

@classmethod
def get_totals(cls, labels, is_archived=False):
def get_totals(cls, labels):
"""
Gets total counts for all the given labels
"""
counts = (
cls.objects.filter(label__in=labels, is_archived=is_archived)
cls.objects.filter(label__in=labels, is_archived=False)
.values_list("label_id")
.annotate(count_sum=Sum("count"))
)
Expand Down
Loading