diff --git a/server/routers/kfu-m-24-1/sber_mobile/DB_Scheme.txt b/server/routers/kfu-m-24-1/sber_mobile/DB_Scheme.txt new file mode 100644 index 0000000..81dade2 --- /dev/null +++ b/server/routers/kfu-m-24-1/sber_mobile/DB_Scheme.txt @@ -0,0 +1,222 @@ +-- Расширение для генерации UUID +CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; + +-- 1. Управляющие компании +CREATE TABLE management_companies ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + name TEXT NOT NULL, + logo_url TEXT, + contact_phone TEXT NOT NULL, + email TEXT, + created_at TIMESTAMPTZ DEFAULT NOW(), + updated_at TIMESTAMPTZ DEFAULT NOW() +); + +-- 2. Жилые дома +CREATE TABLE buildings ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + management_company_id UUID NOT NULL REFERENCES management_companies(id), + name TEXT, + address TEXT NOT NULL, + floors INTEGER, + entrances INTEGER, + created_at TIMESTAMPTZ DEFAULT NOW(), + updated_at TIMESTAMPTZ DEFAULT NOW() +); + +-- 3. Профили пользователей +CREATE TABLE user_profiles ( + id UUID PRIMARY KEY REFERENCES auth.users(id), + full_name TEXT, + avatar_url TEXT, + created_at TIMESTAMPTZ DEFAULT NOW(), + updated_at TIMESTAMPTZ DEFAULT NOW() +); + +-- 4. Квартиры +CREATE TABLE apartments ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + building_id UUID NOT NULL REFERENCES buildings(id), + number TEXT NOT NULL, + area DECIMAL(10, 2), + floor INTEGER, + created_at TIMESTAMPTZ DEFAULT NOW(), + updated_at TIMESTAMPTZ DEFAULT NOW() +); + +-- 5. Связь пользователей с квартирами +CREATE TABLE apartment_residents ( + apartment_id UUID NOT NULL REFERENCES apartments(id), + user_id UUID NOT NULL REFERENCES auth.users(id), + is_owner BOOLEAN DEFAULT FALSE, + created_at TIMESTAMPTZ DEFAULT NOW(), + PRIMARY KEY (apartment_id, user_id) +); + +-- 6. Сервисы УК +CREATE TABLE management_services ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + management_company_id UUID NOT NULL REFERENCES management_companies(id), + title TEXT NOT NULL, + description TEXT, + category TEXT NOT NULL, + base_price DECIMAL(10, 2), + image_url TEXT, + created_at TIMESTAMPTZ DEFAULT NOW(), + updated_at TIMESTAMPTZ DEFAULT NOW() +); + +-- 7. Связь сервисов УК с домами +CREATE TABLE building_management_services ( + building_id UUID NOT NULL REFERENCES buildings(id), + service_id UUID NOT NULL REFERENCES management_services(id), + custom_price DECIMAL(10, 2), + is_active BOOLEAN DEFAULT TRUE, + created_at TIMESTAMPTZ DEFAULT NOW(), + updated_at TIMESTAMPTZ DEFAULT NOW(), + PRIMARY KEY (building_id, service_id) +); + +-- 8. Платежные сервисы +CREATE TABLE payment_services ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + name TEXT NOT NULL, + logo_url TEXT, + provider_name TEXT, + created_at TIMESTAMPTZ DEFAULT NOW(), + updated_at TIMESTAMPTZ DEFAULT NOW() +); + +-- 9. Дополнительные сервисы +CREATE TABLE additional_services ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + title TEXT NOT NULL, + description TEXT, + category TEXT NOT NULL, + price DECIMAL(10, 2), + image_url TEXT, + created_at TIMESTAMPTZ DEFAULT NOW(), + updated_at TIMESTAMPTZ DEFAULT NOW() +); + +-- 10. Инициативы +CREATE TABLE initiatives ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + building_id UUID NOT NULL REFERENCES buildings(id), + creator_id UUID NOT NULL REFERENCES auth.users(id), + title TEXT NOT NULL, + description TEXT NOT NULL, + status TEXT NOT NULL CHECK ( + status IN ('moderation', 'review', 'fundraising', 'approved', 'rejected') + ), + target_amount DECIMAL(10, 2), + current_amount DECIMAL(10, 2) DEFAULT 0, + image_url TEXT, + created_at TIMESTAMPTZ DEFAULT NOW(), + updated_at TIMESTAMPTZ DEFAULT NOW() +); + +-- 11. Голосования +CREATE TABLE votes ( + initiative_id UUID NOT NULL REFERENCES initiatives(id), + user_id UUID NOT NULL REFERENCES auth.users(id), + vote_type TEXT NOT NULL CHECK (vote_type IN ('for', 'against')), + created_at TIMESTAMPTZ DEFAULT NOW(), + PRIMARY KEY (initiative_id, user_id) +); + +-- 12. Чат +CREATE TABLE chats ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + building_id UUID NOT NULL REFERENCES buildings(id), + name TEXT, + created_at TIMESTAMPTZ DEFAULT NOW() +); + +-- 13. Сообщения +CREATE TABLE messages ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + chat_id UUID NOT NULL REFERENCES chats(id), + user_id UUID NOT NULL REFERENCES auth.users(id), + text TEXT NOT NULL, + created_at TIMESTAMPTZ DEFAULT NOW() +); + +-- 14. Камеры +CREATE TABLE cameras ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + building_id UUID NOT NULL REFERENCES buildings(id), + location TEXT NOT NULL, + stream_url TEXT NOT NULL, + is_active BOOLEAN DEFAULT TRUE, + created_at TIMESTAMPTZ DEFAULT NOW(), + updated_at TIMESTAMPTZ DEFAULT NOW() +); + +-- 15. Платежи ЖКХ (исправленная версия) +CREATE TABLE utility_payments ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + apartment_id UUID NOT NULL REFERENCES apartments(id), + service_id UUID NOT NULL REFERENCES payment_services(id), + amount DECIMAL(10, 2) NOT NULL, + period DATE NOT NULL, + status TEXT NOT NULL CHECK (status IN ('paid', 'pending', 'overdue')), + created_at TIMESTAMPTZ DEFAULT NOW(), + updated_at TIMESTAMPTZ DEFAULT NOW() +); + +-- 16. Заявки +CREATE TABLE tickets ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + user_id UUID NOT NULL REFERENCES auth.users(id), + building_id UUID NOT NULL REFERENCES buildings(id), + title TEXT NOT NULL, + description TEXT NOT NULL, + status TEXT NOT NULL CHECK (status IN ('open', 'in_progress', 'resolved')), + category TEXT NOT NULL, + created_at TIMESTAMPTZ DEFAULT NOW(), + updated_at TIMESTAMPTZ DEFAULT NOW() +); + +-- Индексы +CREATE INDEX idx_buildings_management_company ON buildings(management_company_id); +CREATE INDEX idx_management_services_company ON management_services(management_company_id); +CREATE INDEX idx_building_services_building ON building_management_services(building_id); +CREATE INDEX idx_initiatives_building ON initiatives(building_id); +CREATE INDEX idx_votes_initiative ON votes(initiative_id); +CREATE INDEX idx_messages_chat ON messages(chat_id); +CREATE INDEX idx_cameras_building ON cameras(building_id); +CREATE INDEX idx_tickets_user ON tickets(user_id); +CREATE INDEX idx_apartments_building ON apartments(building_id); +CREATE INDEX idx_apartment_residents_apartment ON apartment_residents(apartment_id); +CREATE INDEX idx_apartment_residents_user ON apartment_residents(user_id); +CREATE INDEX idx_payments_apartment ON utility_payments(apartment_id); +CREATE INDEX idx_payments_service ON utility_payments(service_id); + +-- Триггеры для обновления updated_at +CREATE OR REPLACE FUNCTION update_updated_at() +RETURNS TRIGGER AS $$ +BEGIN + NEW.updated_at = NOW(); + RETURN NEW; +END; +$$ LANGUAGE plpgsql; + +-- Применяем триггеры ко всем таблицам с updated_at +DO $$ +DECLARE + t record; +BEGIN + FOR t IN + SELECT table_name + FROM information_schema.columns + WHERE column_name = 'updated_at' + AND table_schema = 'public' + LOOP + EXECUTE format('CREATE TRIGGER trigger_%s_updated_at + BEFORE UPDATE ON %I + FOR EACH ROW EXECUTE FUNCTION update_updated_at()', + t.table_name, t.table_name); + END LOOP; +END; +$$ LANGUAGE plpgsql; \ No newline at end of file