Skip to content

Commit

Permalink
Remove mam_server_user table (without the other stuff)
Browse files Browse the repository at this point in the history
  • Loading branch information
duogenesis committed Mar 2, 2025
1 parent 6b44da8 commit ca42ba9
Show file tree
Hide file tree
Showing 12 changed files with 33 additions and 201 deletions.
21 changes: 1 addition & 20 deletions init-api.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1488,20 +1488,10 @@ EXCEPTION
WHEN duplicate_object THEN null;
END $$;

CREATE TABLE IF NOT EXISTS mam_server_user(
id SERIAL UNIQUE PRIMARY KEY,
user_name varchar(250) NOT NULL
);

CREATE UNIQUE INDEX IF NOT EXISTS
idx__mam_server_user__user_name
ON mam_server_user(user_name);

CREATE TABLE IF NOT EXISTS mam_message(
-- Message UID (64 bits)
-- A server-assigned UID that MUST be unique within the archive.
id BIGINT NOT NULL,
user_id INT NOT NULL,
-- FromJID used to form a message without looking into stanza.
-- This value will be send to the client "as is".
from_jid varchar(250) NOT NULL,
Expand All @@ -1516,18 +1506,13 @@ CREATE TABLE IF NOT EXISTS mam_message(
message bytea NOT NULL,
search_body text,
person_id INT REFERENCES person(id) ON DELETE CASCADE ON UPDATE CASCADE,
PRIMARY KEY(user_id, id)
PRIMARY KEY(person_id, id)
);

CREATE INDEX IF NOT EXISTS idx__mam_message__person_id__remote_bare_jid__id
ON mam_message
(person_id, remote_bare_jid, id);

CREATE INDEX IF NOT EXISTS i_mam_message_username_jid_id
ON mam_message
USING BTREE
(user_id, remote_bare_jid, id);

CREATE TABLE IF NOT EXISTS inbox (
luser VARCHAR(250) NOT NULL,
remote_bare_jid VARCHAR(250) NOT NULL,
Expand Down Expand Up @@ -1577,10 +1562,6 @@ CREATE INDEX IF NOT EXISTS duo_idx__mam_message__remote_bare_jid__id
ON mam_message(remote_bare_jid, id)
WHERE direction = 'I';

CREATE UNIQUE INDEX IF NOT EXISTS
idx__mam_server_user__user_name
ON mam_server_user(user_name);

CREATE INDEX IF NOT EXISTS
idx__inbox__luser__timestamp
ON inbox(luser, timestamp);
Expand Down
112 changes: 13 additions & 99 deletions migrations.sql
Original file line number Diff line number Diff line change
@@ -1,105 +1,19 @@
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx__mam_message__person_id__remote_bare_jid__id
ON mam_message
(person_id, remote_bare_jid, id);

-- Populate `mam_message.person_id` with values linking it to the `person` table
CREATE PROCEDURE update_messages_proc()
LANGUAGE plpgsql
AS $$
DECLARE
v_total_updated INTEGER := 0;
v_rows_updated INTEGER;
BEGIN
LOOP
WITH mam_message_to_update AS (
SELECT
mam_message.user_id,
mam_message.id
FROM
mam_message
WHERE
mam_message.person_id IS NULL
LIMIT
1000
), updated_mam_message AS (
SELECT
mam_message_to_update.user_id,
mam_message_to_update.id,
COALESCE(person.id, -1) AS new_person_id
FROM
mam_message_to_update
LEFT JOIN
mam_server_user
ON
mam_message_to_update.user_id = mam_server_user.id
LEFT JOIN
person
ON
person.uuid = uuid_or_null(mam_server_user.user_name)
)
UPDATE
mam_message
SET
person_id = updated_mam_message.new_person_id
FROM
updated_mam_message
WHERE
mam_message.id = updated_mam_message.id
AND
mam_message.user_id = updated_mam_message.user_id
;

GET DIAGNOSTICS v_rows_updated = ROW_COUNT;
v_total_updated := v_total_updated + v_rows_updated;
RAISE NOTICE 'Total rows updated: %', v_total_updated;
DROP INDEX IF EXISTS idx__mam_server_user__user_name;

IF v_rows_updated = 0 THEN
COMMIT; -- Commit any remaining work before exiting
EXIT;
END IF;
DROP TABLE IF EXISTS mam_server_user;

COMMIT; -- Commit the current batch; a new transaction will start automatically for the next iteration
END LOOP;
END;
$$;
ALTER TABLE mam_message DROP CONSTRAINT mam_message_pkey;

CALL update_messages_proc();
ALTER TABLE mam_message ADD CONSTRAINT mam_message_pkey PRIMARY KEY (person_id, id);

DROP PROCEDURE IF EXISTS update_messages_proc();
DROP INDEX IF EXISTS i_mam_message_username_jid_id;

DO $$
BEGIN
IF NOT EXISTS (
SELECT 1 FROM pg_constraint
WHERE conname = 'mam_message_person_id_fkey'
) THEN
-- DELETE orphaned `mam_message`s
DELETE FROM
mam_message
WHERE
person_id = -1
;

-- Now that `mam_message.person_id` is populated, we can add a `NOT NULL`
-- constraint
ALTER TABLE
mam_message
ALTER COLUMN
person_id SET NOT NULL
;

-- Now that `mam_message.person_id` points to corresponding values in
-- `person_id`, we can add a `FOREIGN KEY` constraint
ALTER TABLE
mam_message
ADD CONSTRAINT
mam_message_person_id_fkey
FOREIGN KEY
(person_id)
REFERENCES
person(id)
ON UPDATE CASCADE
ON DELETE CASCADE;
END IF;
END$$;
CREATE INDEX IF NOT EXISTS idx__mam_message__person_id__remote_bare_jid__id
ON mam_message
(person_id, remote_bare_jid, id);

ALTER TABLE
mam_message
DROP COLUMN IF EXISTS
user_id
;
5 changes: 0 additions & 5 deletions service/chat/__init__.py
Original file line number Diff line number Diff line change
Expand Up @@ -26,7 +26,6 @@
upsert_conversation,
)
from service.chat.mam import (
insert_server_user,
maybe_get_conversation,
store_message,
)
Expand Down Expand Up @@ -399,15 +398,11 @@ async def process_duo_message(

if not from_id:
return
else:
await insert_server_user(from_username)

to_id = await fetch_id_from_username(to_username)

if not to_id:
return
else:
await insert_server_user(to_username)

if await fetch_is_skipped(from_id=from_id, to_id=to_id):
return await redis_publish_many(connection_uuid, [
Expand Down
36 changes: 9 additions & 27 deletions service/chat/mam/__init__.py
Original file line number Diff line number Diff line change
Expand Up @@ -21,48 +21,36 @@
from async_lru_cache import AsyncLruCache


Q_INSERT_SERVER_USER = f"""
INSERT INTO
mam_server_user (user_name)
VALUES
(%(user_name)s)
ON CONFLICT (user_name) DO NOTHING
"""


Q_INSERT_MESSAGE = """
INSERT INTO
mam_message (
id,
user_id,
person_id,
from_jid,
remote_bare_jid,
direction,
message,
search_body,
person_id
search_body
)
VALUES
(
%(id)s,
(SELECT id FROM mam_server_user WHERE user_name = %(from_username)s),
(SELECT id FROM person WHERE uuid = uuid_or_null(%(from_username)s)),
'', -- from_jid is ignored
%(to_username)s,
'O',
%(message)s,
%(search_body)s,
(SELECT id FROM person WHERE uuid = uuid_or_null(%(from_username)s))
%(search_body)s
),
(
%(id)s + 1,
(SELECT id FROM mam_server_user WHERE user_name = %(to_username)s),
(SELECT id FROM person WHERE uuid = uuid_or_null(%(to_username)s)),
'', -- from_jid is ignored
%(from_username)s,
'I',
%(message)s,
%(search_body)s,
(SELECT id FROM person WHERE uuid = uuid_or_null(%(to_username)s))
%(search_body)s
)
"""

Expand All @@ -75,11 +63,11 @@
FROM
mam_message
JOIN
mam_server_user
person
ON
mam_server_user.id = mam_message.user_id
person.id = mam_message.person_id
WHERE
mam_server_user.user_name = %(from_username)s
person.uuid = %(from_username)s
AND
mam_message.remote_bare_jid = %(to_username)s
AND (
Expand Down Expand Up @@ -332,12 +320,6 @@ async def _get_conversation(
return messages


@AsyncLruCache(maxsize=1024)
async def insert_server_user(username: str):
async with asyncdatabase.api_tx() as tx:
await tx.execute(Q_INSERT_SERVER_USER, dict(user_name=username))


def microseconds_to_mam_message_id(microseconds: int):
return microseconds << 8

Expand Down
1 change: 0 additions & 1 deletion service/person/__init__.py
Original file line number Diff line number Diff line change
Expand Up @@ -761,7 +761,6 @@ def post_skip_by_uuid(req: t.PostSkip, s: t.SessionInfo, prospect_uuid: str):
with api_tx() as tx:
last_messages = tx.execute(Q_LAST_MESSAGES, params=params).fetchall()

with api_tx() as tx:
report_obj = tx.execute(Q_MAKE_REPORT, params=params).fetchall()

threading.Thread(
Expand Down
32 changes: 10 additions & 22 deletions service/person/sql/__init__.py
Original file line number Diff line number Diff line change
Expand Up @@ -1446,27 +1446,15 @@

Q_DELETE_XMPP = """
WITH q1 AS (
DELETE FROM
mam_message
USING
mam_server_user
WHERE
mam_message.user_id = mam_server_user.id
AND
mam_server_user.user_name = %(person_uuid)s
), q2 AS (
DELETE FROM last
WHERE username = %(person_uuid)s
), q3 AS (
), q2 AS (
DELETE FROM inbox
WHERE luser = %(person_uuid)s
), q4 AS (
DELETE FROM mam_server_user
WHERE user_name = %(person_uuid)s
), q5 AS (
DELETE FROM duo_last_notification
WHERE username = %(person_uuid)s
), q6 AS (
), q5 AS (
DELETE FROM duo_push_token
WHERE username = %(person_uuid)s
)
Expand Down Expand Up @@ -2068,15 +2056,15 @@
FROM
mam_message
JOIN
mam_server_user
person
ON
mam_server_user.id = mam_message.user_id
person.id = mam_message.person_id
AND
mam_server_user.user_name = %(subject_person_uuid)s
person.uuid = %(subject_person_uuid)s
WHERE
mam_message.remote_bare_jid IN (
%(subject_person_uuid)s,
%(prospect_uuid)s
%(subject_person_uuid)s::TEXT,
%(prospect_uuid)s::TEXT
)
ORDER BY
mam_message.id DESC
Expand Down Expand Up @@ -2760,11 +2748,11 @@
FROM
mam_message
JOIN
mam_server_user
person
ON
mam_message.user_id = mam_server_user.id
mam_message.user_id = person.id
WHERE
mam_server_user.user_name = %(person_uuid)s::TEXT
person.uuid = %(person_uuid)s::TEXT
ORDER BY
mam_message.id
"""
Expand Down
2 changes: 0 additions & 2 deletions test/functionality4/xmpp-inbox.sh
Original file line number Diff line number Diff line change
Expand Up @@ -14,10 +14,8 @@ q "delete from banned_person"
q "delete from banned_person_admin_token"
q "delete from duo_session"
q "delete from mam_message"
q "delete from mam_server_user"
q "delete from last"
q "delete from inbox"
q "delete from mam_server_user"
q "delete from duo_last_notification"
q "delete from duo_push_token"
q "delete from intro_hash"
Expand Down
2 changes: 0 additions & 2 deletions test/functionality4/xmpp-mam.sh
Original file line number Diff line number Diff line change
Expand Up @@ -14,10 +14,8 @@ q "delete from banned_person"
q "delete from banned_person_admin_token"
q "delete from duo_session"
q "delete from mam_message"
q "delete from mam_server_user"
q "delete from last"
q "delete from inbox"
q "delete from mam_server_user"
q "delete from duo_last_notification"
q "delete from duo_push_token"
q "delete from intro_hash"
Expand Down
2 changes: 0 additions & 2 deletions test/functionality4/xmpp-offensive.sh
Original file line number Diff line number Diff line change
Expand Up @@ -14,10 +14,8 @@ q "delete from banned_person"
q "delete from banned_person_admin_token"
q "delete from duo_session"
q "delete from mam_message"
q "delete from mam_server_user"
q "delete from last"
q "delete from inbox"
q "delete from mam_server_user"
q "delete from duo_last_notification"
q "delete from duo_push_token"
q "delete from intro_hash"
Expand Down
2 changes: 0 additions & 2 deletions test/functionality4/xmpp-rate-limit.sh
Original file line number Diff line number Diff line change
Expand Up @@ -20,10 +20,8 @@ test_rate_limit () {
q "delete from banned_person_admin_token"
q "delete from duo_session"
q "delete from mam_message"
q "delete from mam_server_user"
q "delete from last"
q "delete from inbox"
q "delete from mam_server_user"
q "delete from duo_last_notification"
q "delete from duo_push_token"
q "delete from intro_hash"
Expand Down
Loading

0 comments on commit ca42ba9

Please sign in to comment.