likeopera-backend/database/db.sql

108 lines
3.6 KiB
PL/PgSQL

create extension if not exists btree_gin;
create table accounts (
id serial not null primary key,
name text not null,
email text not null,
settings jsonb not null
-- настройки: replyto, cc, bcc, imap, smtp, folders
);
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 text not null,
highestmodseq int not null default 0,
kind text 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);
-- Очередь команд. Виды команд:
-- 1) пометить сообщение
-- 2) переместить сообщение
-- 3) удалить сообщение
-- 4) отправить черновик
create table command_queue (
id serial not null primary key,
account_id int not null,
folder_id int,
uid int,
props jsonb not null
);
-- Ещё нигде не сохранённые черновики сообщений
create table drafts (
id serial not null primary key,
time bigint not null,
props jsonb not null
);
create table messages (
id serial not null primary key,
thread_id int,
folder_id int not null,
uid int,
messageid text not null,
inreplyto text not null,
refs text[] not null,
subject text not null,
props jsonb not null,
body_html text not null default '',
body_text text not null default '',
body_html_text text not null default '',
-- FIXME bigint
time timestamptz not null,
size int not null,
-- FIXME jsonb
flags text[] 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_folder_id_time on messages (folder_id, time);
create index messages_time on messages (time);
-- create or replace function immutable_year(d timestamptz) returns text
-- language plpgsql immutable as $$
-- begin
-- return date_part('year', d);
-- end
-- $$;
-- create index messages_year on messages (immutable_year(time));
create or replace function messages_fulltext(msg messages) returns tsvector
language plpgsql immutable as $$
begin
return setweight(to_tsvector('russian', regexp_replace(
coalesce(msg.props->>'from', '') || ' ' ||
coalesce(msg.props->>'replyto', '') || ' ' ||
coalesce(msg.props->>'to', '') || ' ' ||
coalesce(msg.props->>'cc', '') || ' ' ||
coalesce(msg.props->>'bcc', '') || ' ' ||
coalesce(msg.props->>'attachments', '') || ' ' ||
msg.subject,
'\W+', ' ', 'g'
)), 'A')
|| setweight(to_tsvector('russian', msg.body_html_text || ' ' || msg.body_text), 'B');
end
$$;
create index messages_text on messages using gin (messages_fulltext(messages));
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;
alter table accounts owner to operetta;
alter table folders owner to operetta;
alter table messages owner to operetta;
alter table threads owner to operetta;