create extension if not exists btree_gin; create table accounts ( id serial not null primary key, name varchar(255) not null, email varchar(255) not null, settings jsonb not null -- настройки: replyto, cc, bcc, in_server, in_port, out_server, out_port, login, password -- sent_folder, trash_folder, spam_folder, drafts_folder -- in_server varchar(255) not null, -- out_server varchar(255) not null, -- reply_to ); create unique index accounts_email on accounts (email); create table folders ( id serial not null primary key, uidvalidity int not null, account_id int not null, name varchar(255) not null, unread_count int not null, highestmodseq int not null default 0, kind varchar(255) not null, foreign key (account_id) references accounts (id) on delete cascade on update cascade ); create unique index folders_name on folders (account_id, name); create table messages ( id serial not null primary key, thread_id int, folder_id int not null, uid int, messageid varchar(1000) not null, inreplyto varchar(1000) not null, refs varchar(1000)[] not null, subject text not null, from_email varchar(255) not null, from_name varchar(255) not null, replyto_email varchar(255) not null, replyto_name varchar(255) not null, to_list text not null, cc_list text not null, bcc_list text not null, headers text not null, body_html text not null, body_text text not null, body_html_text text not null, text_index tsvector not null, time timestamptz not null, size unsigned not null, flags varchar(255)[] not null, foreign key (folder_id) references folders (id) on delete cascade on update cascade ); create unique index messages_unique on messages (folder_id, uid); create index messages_flags on messages using gin (folder_id, flags); create index messages_messageid on messages (messageid); create index messages_refs on messages using gin (refs); create index messages_time on messages (folder_id, time); create index messages_text on messages using gin (text_index); create or replace function fn_messages_text_index() returns trigger security definer language plpgsql as $$ begin NEW.text_index = ( setweight(to_tsvector('russian', regexp_replace(NEW.from_name || ' ' || NEW.from_email || ' ' || NEW.replyto_name || ' ' || NEW.replyto_email || ' ' || NEW.to_list || ' ' || NEW.cc_list || ' ' || NEW.bcc_list || ' ' || NEW.subject, '\W+', ' ', 'g')), 'A') || setweight(to_tsvector('russian', NEW.body_html_text || ' ' || NEW.body_text), 'B') ); return NEW; end $$; create trigger messages_text_index before insert or update on messages for each row execute procedure fn_messages_text_index(); create table attachments ( id serial not null primary key, msg_id int not null, ctype varchar(255) not null, size unsigned not null, foreign key (msg_id) references messages (id) on delete cascade on update cascade ); create table threads ( id serial not null primary key, first_msg int, msg_count int not null default 1, foreign key (first_msg) references messages (id) on delete restrict on update cascade ); create index threads_first_msg on threads (first_msg); alter table messages add foreign key (thread_id) references threads (id) on delete restrict on update cascade; --create table tt as with recursive t (id, messageid, upperid, uppermsg) as (select (array_agg(m1.id))[0], m1.messageid, (array_agg(m1.id))[1], m1.messageid from messages m1 left join messages m2 on m1.messageid!='' and m1.inreplyto!='' and m2.messageid=m1.inreplyto where m2.id is null group by m1.messageid union select m1.id, m1.messageid, t.upperid, t.uppermsg from messages m1 inner join t on m1.inreplyto!='' and m1.inreplyto=t.messageid where m1.messageid!='') select * from t; --alter table messages alter flags type varchar(255)[] using (case when flags&1=1 then array['recent'] else array[]::varchar(255)[] end) || (case when flags&2=2 then array['flagged'] else array[]::varchar(255)[] end) || (case when flags&4=4 then array['answered'] else array[]::varchar(255)[] end) || (case when flags&8=8 then array['unread'] else array[]::varchar(255)[] end);