Skip to content

Commit

Permalink
Improving indexes used by MAM retrieval #84
Browse files Browse the repository at this point in the history
  • Loading branch information
hantu85 committed Dec 17, 2024
1 parent e161951 commit 11b62f0
Show file tree
Hide file tree
Showing 2 changed files with 78 additions and 10 deletions.
61 changes: 51 additions & 10 deletions src/main/database/mysql-message-archiving-3.3.0.sql
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,47 @@
-- If not, see http://www.gnu.org/licenses/.
--

-- QUERY START:
drop procedure if exists TigMAMUpgrade;
-- QUERY END:

delimiter //

-- QUERY START:
create procedure TigMAMUpgrade()
begin
if not exists (select 1 from information_schema.STATISTICS where TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'tig_ma_msgs' and INDEX_NAME = 'tig_ma_msgs_owner_id_ts_index') then
create index tig_ma_msgs_owner_id_ts_index on tig_ma_msgs (owner_id, ts);
end if;
if not exists (select 1 from information_schema.STATISTICS where TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'tig_ma_msgs' and INDEX_NAME = 'tig_ma_msgs_owner_id_buddy_id_ts_index') then
create index tig_ma_msgs_owner_id_buddy_id_ts_index on tig_ma_msgs (owner_id, buddy_id, ts);
end if;

if exists (select 1 from information_schema.STATISTICS where TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'tig_ma_msgs' and INDEX_NAME = 'tig_ma_msgs_ts_index') then
drop index tig_ma_msgs_ts_index on tig_ma_msgs;
end if;
if exists (select 1 from information_schema.STATISTICS where TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'tig_ma_msgs' and INDEX_NAME = 'tig_ma_msgs_owner_id') then
drop index tig_ma_msgs_owner_id on tig_ma_msgs;
end if;
if exists (select 1 from information_schema.STATISTICS where TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'tig_ma_msgs' and INDEX_NAME = 'tig_ma_msgs_owner_id_ts_buddy_id') then
drop index tig_ma_msgs_owner_id_ts_buddy_id on tig_ma_msgs;
end if;
if exists (select 1 from information_schema.STATISTICS where TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'tig_ma_msgs' and INDEX_NAME = 'tig_ma_msgs_owner_id_buddy_id') then
drop index tig_ma_msgs_owner_id_buddy_id on tig_ma_msgs;
end if;
end //
-- QUERY END:

delimiter ;

-- QUERY START:
call TigMAMUpgrade();
-- QUERY END:

-- QUERY START:
drop procedure if exists TigMAMUpgrade;
-- QUERY END:

-- QUERY START:
drop procedure if exists Tig_MA_GetMessages;
-- QUERY END:
Expand Down Expand Up @@ -51,7 +92,7 @@ begin
select Tig_MA_GetHasTagsQuery(_tags) into @tags_query;
select Tig_MA_GetBodyContainsQuery(_contains) into @contains_query;
set @msgs_query = 'select m.msg, m.ts, b.jid, Tig_MA_OrderedToUuid(m.stable_id) as stable_id, Tig_MA_OrderedToUuid(m.ref_stable_id) as ref_stable_id
from tig_ma_msgs m
from tig_ma_msgs m ignore index (buddy_id, tig_ma_msgs_owner_id_buddy_id_is_ref_ts_index, tig_ma_msgs_owner_id_buddy_id_stanza_id_ts_index)
inner join tig_ma_jids o on m.owner_id = o.jid_id
inner join tig_ma_jids b on b.jid_id = m.buddy_id
where
Expand Down Expand Up @@ -82,7 +123,7 @@ begin
limit _limit offset _offset;
when 1 then
select m.msg, m.ts, b.jid, Tig_MA_OrderedToUuid(m.stable_id) as stable_id, Tig_MA_OrderedToUuid(m.ref_stable_id) as ref_stable_id
from tig_ma_msgs m
from tig_ma_msgs m ignore index (buddy_id, tig_ma_msgs_owner_id_buddy_id_is_ref_ts_index, tig_ma_msgs_owner_id_buddy_id_stanza_id_ts_index)
inner join tig_ma_jids o on m.owner_id = o.jid_id
inner join tig_ma_jids b on b.jid_id = m.buddy_id
where
Expand Down Expand Up @@ -156,7 +197,7 @@ begin
select Tig_MA_GetHasTagsQuery(_tags) into @tags_query;
select Tig_MA_GetBodyContainsQuery(_contains) into @contains_query;
set @msgs_query = 'select count(1)
from tig_ma_msgs m
from tig_ma_msgs m ignore index (buddy_id, tig_ma_msgs_owner_id_buddy_id_is_ref_ts_index, tig_ma_msgs_owner_id_buddy_id_stanza_id_ts_index)
inner join tig_ma_jids o on m.owner_id = o.jid_id
inner join tig_ma_jids b on b.jid_id = m.buddy_id
where
Expand All @@ -173,7 +214,7 @@ begin
case _refType
when 1 then
select count(1)
from tig_ma_msgs m
from tig_ma_msgs m ignore index (buddy_id, tig_ma_msgs_owner_id_buddy_id_is_ref_ts_index, tig_ma_msgs_owner_id_buddy_id_stanza_id_ts_index)
inner join tig_ma_jids o on m.owner_id = o.jid_id
inner join tig_ma_jids b on b.jid_id = m.buddy_id
where
Expand Down Expand Up @@ -210,7 +251,7 @@ begin
select Tig_MA_GetHasTagsQuery(_tags) into @tags_query;
select Tig_MA_GetBodyContainsQuery(_contains) into @contains_query;
set @msgs_query = 'select count(1) + 1
from tig_ma_msgs m
from tig_ma_msgs m ignore index (buddy_id, tig_ma_msgs_owner_id_buddy_id_is_ref_ts_index, tig_ma_msgs_owner_id_buddy_id_stanza_id_ts_index)
inner join tig_ma_jids o on m.owner_id = o.jid_id
inner join tig_ma_jids b on b.jid_id = m.buddy_id
where
Expand All @@ -235,7 +276,7 @@ begin
case _refType
when 1 then
select count(1) + 1
from tig_ma_msgs m
from tig_ma_msgs m ignore index (buddy_id, tig_ma_msgs_owner_id_buddy_id_is_ref_ts_index, tig_ma_msgs_owner_id_buddy_id_stanza_id_ts_index)
join tig_ma_jids o on m.owner_id = o.jid_id
join tig_ma_jids b on m.buddy_id = b.jid_id
where
Expand Down Expand Up @@ -289,7 +330,7 @@ begin
select Tig_MA_GetHasTagsQuery(_tags) into @tags_query;
select Tig_MA_GetBodyContainsQuery(_contains) into @contains_query;
set @msgs_query = 'select min(m.ts), b.jid';
set @msgs_query = CONCAT( @msgs_query,' from tig_ma_msgs m
set @msgs_query = CONCAT( @msgs_query,' from tig_ma_msgs m ignore index (buddy_id, tig_ma_msgs_owner_id_buddy_id_is_ref_ts_index, tig_ma_msgs_owner_id_buddy_id_stanza_id_ts_index)
inner join tig_ma_jids o on m.owner_id = o.jid_id
inner join tig_ma_jids b on b.jid_id = m.buddy_id
where
Expand All @@ -306,7 +347,7 @@ begin
deallocate prepare stmt;
else
select min(m.ts), b.jid
from tig_ma_msgs m
from tig_ma_msgs m ignore index (buddy_id, tig_ma_msgs_owner_id_buddy_id_is_ref_ts_index, tig_ma_msgs_owner_id_buddy_id_stanza_id_ts_index)
inner join tig_ma_jids o on m.owner_id = o.jid_id
inner join tig_ma_jids b on b.jid_id = m.buddy_id
where
Expand All @@ -333,7 +374,7 @@ begin
select Tig_MA_GetHasTagsQuery(_tags) into @tags_query;
select Tig_MA_GetBodyContainsQuery(_contains) into @contains_query;
set @msgs_query = 'select count(1) from (select min(m.ts), b.jid';
set @msgs_query = CONCAT( @msgs_query,' from tig_ma_msgs m
set @msgs_query = CONCAT( @msgs_query,' from tig_ma_msgs m ignore index (buddy_id, tig_ma_msgs_owner_id_buddy_id_is_ref_ts_index, tig_ma_msgs_owner_id_buddy_id_stanza_id_ts_index)
inner join tig_ma_jids o on m.owner_id = o.jid_id
inner join tig_ma_jids b on b.jid_id = m.buddy_id
where
Expand All @@ -350,7 +391,7 @@ begin
else
select count(1) from (
select min(m.ts), b.jid
from tig_ma_msgs m
from tig_ma_msgs m ignore index (buddy_id, tig_ma_msgs_owner_id_buddy_id_is_ref_ts_index, tig_ma_msgs_owner_id_buddy_id_stanza_id_ts_index)
inner join tig_ma_jids o on m.owner_id = o.jid_id
inner join tig_ma_jids b on b.jid_id = m.buddy_id
where
Expand Down
27 changes: 27 additions & 0 deletions src/main/database/postgresql-message-archiving-3.3.0.sql
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,33 @@
-- If not, see http://www.gnu.org/licenses/.
--

-- QUERY START:
do $$
begin
if exists (select 1 where (select to_regclass('public.tig_ma_msgs_ts_index')) is not null) then
drop index tig_ma_msgs_ts_index on tig_ma_msgs;
end if;
end$$;
-- QUERY END:

-- QUERY START:
do $$
begin
if exists (select 1 where (select to_regclass('public.tig_ma_msgs_owner_id_ts_index')) is null) then
create index tig_ma_msgs_owner_id_ts_index on tig_ma_msgs ( owner_id, ts );
end if;
end$$;
-- QUERY END:

-- QUERY START:
do $$
begin
if exists (select 1 where (select to_regclass('public.tig_ma_msgs_owner_id_buddy_id_ts_index')) is null) then
create index tig_ma_msgs_owner_id_buddy_id_ts_index on tig_ma_msgs ( owner_id, buddy_id, ts );
end if;
end$$;
-- QUERY END:

-- QUERY START:
create or replace function Tig_MA_GetMessages(_ownerJid varchar(2049), _buddyJid varchar(2049), _from timestamp with time zone, _to timestamp with time zone, _refType smallint, _tags text, _contains text, _limit int, _offset int) returns table(
"msg" text, "ts" timestamp with time zone, "buddyJid" varchar(2049), "stableId" varchar(36), "refStableId" varchar(36)
Expand Down

0 comments on commit 11b62f0

Please sign in to comment.