140 lines
4.6 KiB
PL/PgSQL
140 lines
4.6 KiB
PL/PgSQL
BEGIN;
|
|
|
|
CREATE OR REPLACE FUNCTION set_updated_at()
|
|
RETURNS TRIGGER
|
|
LANGUAGE plpgsql AS
|
|
$$
|
|
BEGIN
|
|
NEW.updated_at := NOW();
|
|
RETURN NEW;
|
|
END;
|
|
$$;
|
|
|
|
COMMIT;
|
|
|
|
-- Таблица привилегий (например: "Администратор", "Оператор склада", "Менеджер заказов")
|
|
CREATE TABLE user_privileges (
|
|
id SERIAL PRIMARY KEY,
|
|
code TEXT NOT NULL UNIQUE, -- internal code (e.g., 'admin', 'warehouse_operator')
|
|
name TEXT NOT NULL, -- display name
|
|
description TEXT,
|
|
is_active BOOLEAN DEFAULT TRUE,
|
|
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Таблица прав (перечень отдельных действий — CRUD по сущностям)
|
|
CREATE TABLE user_permissions (
|
|
id SERIAL PRIMARY KEY,
|
|
code TEXT NOT NULL UNIQUE, -- internal code (e.g., 'product.view', 'order.update')
|
|
name TEXT NOT NULL,
|
|
description TEXT,
|
|
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Связь привилегий и разрешений (многие ко многим)
|
|
CREATE TABLE user_privilege_permissions (
|
|
privilege_id INTEGER REFERENCES user_privileges(id) ON DELETE CASCADE,
|
|
permission_id INTEGER REFERENCES user_permissions(id) ON DELETE CASCADE,
|
|
PRIMARY KEY (privilege_id, permission_id)
|
|
);
|
|
|
|
-- Таблица юзеров
|
|
-- CREATE TABLE user_employees (
|
|
-- id SERIAL PRIMARY KEY,
|
|
-- full_name TEXT,
|
|
-- login TEXT UNIQUE,
|
|
-- password_hash TEXT NOT NULL,
|
|
-- is_active BOOLEAN DEFAULT FALSE,
|
|
-- privilege_id INTEGER REFERENCES user_privileges(id),
|
|
-- created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP
|
|
-- );
|
|
CREATE TABLE users (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
|
|
full_name TEXT,
|
|
login TEXT UNIQUE,
|
|
password_hash TEXT NOT NULL,
|
|
|
|
is_blocked BOOLEAN DEFAULT FALSE,
|
|
is_deleted BOOLEAN DEFAULT FALSE,
|
|
privilege_id INTEGER REFERENCES user_privileges(id),
|
|
|
|
-- Баланс
|
|
--btc BIGINT DEFAULT 0,
|
|
--btc_balance NUMERIC(20, 8) DEFAULT 0.0,
|
|
|
|
-- Конфиденциальность
|
|
is_searchable BOOLEAN DEFAULT TRUE,
|
|
allow_message_forwarding BOOLEAN DEFAULT TRUE,
|
|
allow_messages_from_non_contacts BOOLEAN DEFAULT TRUE,
|
|
show_profile_photo_to_non_contacts BOOLEAN DEFAULT TRUE,
|
|
last_seen_visibility SMALLINT DEFAULT 0 CHECK (last_seen_visibility IN (0, 1, 2)),
|
|
last_seen_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
|
|
|
-- Биография
|
|
bio TEXT,
|
|
show_bio_to_non_contacts BOOLEAN DEFAULT TRUE,
|
|
|
|
-- Сторисы
|
|
show_stories_to_non_contacts BOOLEAN DEFAULT TRUE,
|
|
|
|
-- Разрешения на чаты
|
|
allow_server_chats BOOLEAN DEFAULT TRUE,
|
|
public_invite_permission SMALLINT DEFAULT 0 CHECK (public_invite_permission IN (0, 1, 2)),
|
|
group_invite_permission SMALLINT DEFAULT 0 CHECK (group_invite_permission IN (0, 1, 2)),
|
|
--chat_invite_permission SMALLINT DEFAULT 0 CHECK (chat_invite_permission IN (0, 1, 2)),
|
|
|
|
-- Звонки
|
|
call_permission SMALLINT DEFAULT 0 CHECK (call_permission IN (0, 1, 2)),
|
|
|
|
-- Автоудаление аккаунта
|
|
auto_delete_after_days INTEGER CHECK (auto_delete_after_days IS NULL OR auto_delete_after_days > 0),
|
|
|
|
-- Автоудаление сообщений
|
|
force_auto_delete_messages_in_private BOOLEAN DEFAULT FALSE,
|
|
max_message_auto_delete_seconds INTEGER CHECK (max_message_auto_delete_seconds IS NULL OR max_message_auto_delete_seconds >= 0),
|
|
|
|
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- =======================
|
|
-- Таблица сессий
|
|
-- =======================
|
|
CREATE TABLE user_sessions (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
|
|
user_id UUID REFERENCES users(id) ON DELETE CASCADE,
|
|
|
|
access_token TEXT NOT NULL, -- JWT
|
|
refresh_token TEXT NOT NULL, -- JWT
|
|
|
|
ip_address TEXT,
|
|
user_agent TEXT,
|
|
|
|
is_active BOOLEAN DEFAULT TRUE,
|
|
|
|
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
|
last_refresh_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- =======================
|
|
-- Функция автообновления last_refresh_at при смене токенов
|
|
-- =======================
|
|
CREATE OR REPLACE FUNCTION update_last_refresh_at()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF NEW.access_token IS DISTINCT FROM OLD.access_token THEN
|
|
NEW.last_refresh_at := CURRENT_TIMESTAMP;
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- =======================
|
|
-- Триггер на обновление
|
|
-- =======================
|
|
CREATE TRIGGER trg_update_last_refresh_at
|
|
BEFORE UPDATE ON user_sessions
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_last_refresh_at();
|