166 lines
5.5 KiB
SQL
166 lines
5.5 KiB
SQL
pragma foreign_keys = off;
|
|
|
|
create table if not exists customers (
|
|
id integer primary key autoincrement,
|
|
name text check(name is null or trim(name) <> '' and length(name) < 256),
|
|
email text check(email is null or trim(email) <> '' and length(email) < 128),
|
|
password text check(password is null or length(password) > 7 and length(password) < 64),
|
|
telegram_id integer,
|
|
plan integer,
|
|
json_balance text default '{}',
|
|
is_blocked integer default 0,
|
|
json_company text default '{}',
|
|
upload_group_id integer,
|
|
json_backup_server text default '{}',
|
|
json_backup_params text default '{}'
|
|
) strict;
|
|
|
|
create table if not exists projects (
|
|
id integer primary key autoincrement,
|
|
customer_id integer references customers(id) on delete cascade,
|
|
name text not null check(trim(name) <> '' and length(name) < 256),
|
|
description text check(description is null or length(description) < 4096),
|
|
logo text,
|
|
is_deleted integer default 0
|
|
) strict;
|
|
|
|
create table if not exists groups (
|
|
id integer primary key autoincrement,
|
|
project_id integer references projects(id) on delete cascade,
|
|
name text,
|
|
telegram_id integer,
|
|
access_hash integer,
|
|
is_channel integer check(is_channel in (0, 1)) default 0,
|
|
bot_can_ban integer default 0,
|
|
user_count integer,
|
|
last_update_time integer
|
|
);
|
|
create unique index if not exists idx_groups_telegram_id on groups (telegram_id);
|
|
|
|
create table if not exists users (
|
|
id integer primary key autoincrement,
|
|
telegram_id integer,
|
|
access_hash integer,
|
|
firstname text,
|
|
lastname text,
|
|
username text,
|
|
photo_id integer,
|
|
photo text,
|
|
language_code text,
|
|
phone text,
|
|
json_phone_projects text default '[]',
|
|
json_settings text default '{}'
|
|
) strict;
|
|
create unique index if not exists idx_users_telegram_id on users (telegram_id);
|
|
|
|
create table if not exists user_details (
|
|
user_id integer references users(id) on delete cascade,
|
|
project_id integer references projects(id) on delete cascade,
|
|
fullname text,
|
|
role text,
|
|
department text,
|
|
is_blocked integer check(is_blocked in (0, 1)) default 0,
|
|
primary key (user_id, project_id)
|
|
) strict;
|
|
|
|
create table if not exists tasks (
|
|
id integer primary key autoincrement,
|
|
project_id integer references projects(id) on delete cascade,
|
|
name text not null check(trim(name) <> '' and length(name) < 4096),
|
|
created_by integer references users(id) on delete set null,
|
|
assigned_to integer references users(id) on delete set null,
|
|
closed_by integer references users(id) on delete set null,
|
|
priority integer check(priority in (0, 1, 2, 3, 4, 5)) default 0,
|
|
status integer check(status >= 1 and status <= 10) default 1,
|
|
time_spent integer check(time_spent is null or time_spent > 0 and time_spent < 44640), -- one month
|
|
create_date integer,
|
|
plan_date integer,
|
|
close_date integer
|
|
) strict;
|
|
|
|
create table if not exists meetings (
|
|
id integer primary key autoincrement,
|
|
project_id integer references projects(id) on delete cascade,
|
|
name text not null check(trim(name) <> '' and length(name) < 4096),
|
|
description text check(description is null or length(description) < 4096),
|
|
created_by integer references users(id) on delete set null,
|
|
meet_date integer
|
|
) strict;
|
|
|
|
create table if not exists documents (
|
|
id integer primary key autoincrement,
|
|
project_id integer references projects(id) on delete cascade,
|
|
origin_group_id integer references groups(id) on delete set null,
|
|
origin_message_id integer,
|
|
group_id integer references groups(id) on delete set null,
|
|
message_id integer,
|
|
file_id integer,
|
|
access_hash integer,
|
|
filename text not null check(length(filename) < 256),
|
|
mime text check(mime is null or length(mime) < 128),
|
|
caption text check(caption is null or length(caption) < 4096),
|
|
size integer,
|
|
published_by integer references users(id) on delete set null,
|
|
parent_type integer check(parent_type in (0, 1, 2)) default 0,
|
|
parent_id integer,
|
|
backup_state integer default 0
|
|
) strict;
|
|
|
|
create table if not exists companies (
|
|
id integer primary key autoincrement,
|
|
project_id integer references projects(id) on delete cascade,
|
|
name text not null check(length(name) < 4096),
|
|
email text check(email is null or length(email) < 128),
|
|
phone text check(phone is null or length(phone) < 128),
|
|
site text check(site is null or length(site) < 128),
|
|
description text check(description is null or length(description) < 4096),
|
|
logo text
|
|
) strict;
|
|
|
|
create table if not exists company_mappings (
|
|
project_id integer references projects(id) on delete cascade,
|
|
company_id integer references companies(id) on delete cascade,
|
|
show_as_id integer references companies(id) on delete cascade,
|
|
show_to_id integer references companies(id) on delete cascade
|
|
) strict;
|
|
|
|
create table if not exists task_users (
|
|
task_id integer references tasks(id) on delete cascade,
|
|
user_id integer references users(id) on delete cascade,
|
|
primary key (task_id, user_id)
|
|
) without rowid;
|
|
|
|
create table if not exists meeting_users (
|
|
meeting_id integer references meetings(id) on delete cascade,
|
|
user_id integer references users(id) on delete cascade,
|
|
primary key (meeting_id, user_id)
|
|
) without rowid;
|
|
|
|
create table if not exists company_users (
|
|
company_id integer references companies(id) on delete cascade,
|
|
user_id integer references users(id) on delete cascade,
|
|
primary key (company_id, user_id)
|
|
) without rowid;
|
|
|
|
create table if not exists group_users (
|
|
group_id integer references groups(id) on delete cascade,
|
|
user_id integer references users(id) on delete cascade,
|
|
primary key (group_id, user_id)
|
|
) without rowid;
|
|
|
|
pragma foreign_keys = on;
|
|
|
|
|
|
create trigger if not exists trg_groups_update after update
|
|
on groups
|
|
when NEW.project_id is null
|
|
begin
|
|
delete from group_users where group_id = NEW.id;
|
|
end;
|
|
|
|
|
|
|
|
|
|
|
|
|