Files
backend/migrations/00005_create_requests_table.sql
2025-12-13 22:34:01 +05:00

104 lines
4.7 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

-- +goose Up
-- +goose StatementBegin
-- =========================================
-- ENUM: request_status - Статусы заявки
-- =========================================
CREATE TYPE request_status AS ENUM (
'pending_moderation', -- На модерации
'approved', -- Одобрена, ожидает отклика волонтёра
'in_progress', -- Взята волонтёром в работу
'completed', -- Успешно выполнена
'cancelled', -- Отменена заявителем
'rejected' -- Отклонена модератором
);
COMMENT ON TYPE request_status IS 'Статусы жизненного цикла заявки на помощь';
-- =========================================
-- ТАБЛИЦА: requests - Заявки на помощь
-- =========================================
CREATE TABLE requests (
id BIGSERIAL PRIMARY KEY,
-- Связи
requester_id BIGINT NOT NULL REFERENCES users(id),
request_type_id BIGINT NOT NULL REFERENCES request_types(id),
assigned_volunteer_id BIGINT REFERENCES users(id),
-- Основная информация
title VARCHAR(255) NOT NULL,
description TEXT NOT NULL,
-- Геолокация (обязательное поле для геопоиска)
location GEOGRAPHY(POINT, 4326) NOT NULL,
address TEXT NOT NULL,
city VARCHAR(100),
-- Детали
desired_completion_date TIMESTAMP WITH TIME ZONE,
urgency VARCHAR(20) DEFAULT 'medium' CHECK (urgency IN ('low', 'medium', 'high', 'urgent')),
-- Статус и модерация
status request_status DEFAULT 'pending_moderation',
moderation_comment TEXT,
moderated_by BIGINT REFERENCES users(id),
moderated_at TIMESTAMP WITH TIME ZONE,
-- Контактная информация
contact_phone VARCHAR(20),
contact_notes TEXT,
-- Аудит
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
completed_at TIMESTAMP WITH TIME ZONE,
deleted_at TIMESTAMP WITH TIME ZONE
);
-- Комментарии
COMMENT ON TABLE requests IS 'Заявки на помощь от маломобильных граждан';
COMMENT ON COLUMN requests.location IS 'Координаты места, где нужна помощь (WGS84, SRID 4326)';
COMMENT ON COLUMN requests.urgency IS 'Срочность: low, medium, high, urgent';
COMMENT ON COLUMN requests.assigned_volunteer_id IS 'Волонтёр, который взял заявку в работу';
COMMENT ON COLUMN requests.contact_notes IS 'Дополнительная информация: код домофона, этаж и т.д.';
COMMENT ON COLUMN requests.deleted_at IS 'Soft delete - дата удаления заявки';
-- Индексы
CREATE INDEX idx_requests_requester_id ON requests(requester_id) WHERE deleted_at IS NULL;
CREATE INDEX idx_requests_assigned_volunteer_id ON requests(assigned_volunteer_id) WHERE assigned_volunteer_id IS NOT NULL;
CREATE INDEX idx_requests_status ON requests(status) WHERE deleted_at IS NULL;
CREATE INDEX idx_requests_type_id ON requests(request_type_id);
CREATE INDEX idx_requests_created_at ON requests(created_at DESC);
CREATE INDEX idx_requests_urgency ON requests(urgency) WHERE deleted_at IS NULL;
CREATE INDEX idx_requests_deleted_at ON requests(deleted_at) WHERE deleted_at IS NULL;
-- =========================================
-- ТАБЛИЦА: request_status_history - История изменения статусов
-- =========================================
CREATE TABLE request_status_history (
id BIGSERIAL PRIMARY KEY,
request_id BIGINT NOT NULL REFERENCES requests(id) ON DELETE CASCADE,
from_status request_status,
to_status request_status NOT NULL,
changed_by BIGINT NOT NULL REFERENCES users(id),
comment TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
COMMENT ON TABLE request_status_history IS 'Полная история изменения статусов заявок для аудита';
COMMENT ON COLUMN request_status_history.from_status IS 'Предыдущий статус (NULL при создании)';
-- Индекс для быстрого получения истории по заявке
CREATE INDEX idx_request_status_history_request_id ON request_status_history(request_id);
CREATE INDEX idx_request_status_history_created_at ON request_status_history(created_at DESC);
-- +goose StatementEnd
-- +goose Down
-- +goose StatementBegin
DROP TABLE IF EXISTS request_status_history CASCADE;
DROP TABLE IF EXISTS requests CASCADE;
DROP TYPE IF EXISTS request_status CASCADE;
-- +goose StatementEnd