125 lines
5.4 KiB
PL/PgSQL
125 lines
5.4 KiB
PL/PgSQL
-- Инициализация базы данных ERP MVP
|
|
|
|
-- Создание расширений
|
|
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
|
|
|
-- Создание таблиц
|
|
|
|
-- Организации
|
|
CREATE TABLE IF NOT EXISTS organizations (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
name VARCHAR(255) NOT NULL,
|
|
type VARCHAR(100),
|
|
settings JSONB DEFAULT '{}',
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
|
);
|
|
|
|
-- Пользователи
|
|
CREATE TABLE IF NOT EXISTS users (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
organization_id UUID NOT NULL REFERENCES organizations(id) ON DELETE CASCADE,
|
|
email VARCHAR(255) UNIQUE NOT NULL,
|
|
password_hash VARCHAR(255) NOT NULL,
|
|
role VARCHAR(50) DEFAULT 'user',
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
|
);
|
|
|
|
-- Места хранения
|
|
CREATE TABLE IF NOT EXISTS storage_locations (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
organization_id UUID NOT NULL REFERENCES organizations(id) ON DELETE CASCADE,
|
|
parent_id UUID REFERENCES storage_locations(id) ON DELETE CASCADE,
|
|
name VARCHAR(255) NOT NULL,
|
|
address VARCHAR(100) NOT NULL,
|
|
type VARCHAR(50) NOT NULL,
|
|
coordinates JSONB DEFAULT '{}',
|
|
qr_code VARCHAR(255),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
|
);
|
|
|
|
-- Товары
|
|
CREATE TABLE IF NOT EXISTS items (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
organization_id UUID NOT NULL REFERENCES organizations(id) ON DELETE CASCADE,
|
|
name VARCHAR(255) NOT NULL,
|
|
description TEXT,
|
|
category VARCHAR(100),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
|
);
|
|
|
|
-- Размещение товаров
|
|
CREATE TABLE IF NOT EXISTS item_placements (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
organization_id UUID NOT NULL REFERENCES organizations(id) ON DELETE CASCADE,
|
|
item_id UUID NOT NULL REFERENCES items(id) ON DELETE CASCADE,
|
|
location_id UUID NOT NULL REFERENCES storage_locations(id) ON DELETE CASCADE,
|
|
quantity INTEGER DEFAULT 1,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
|
);
|
|
|
|
-- Операции
|
|
CREATE TABLE IF NOT EXISTS operations (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
organization_id UUID NOT NULL REFERENCES organizations(id) ON DELETE CASCADE,
|
|
operation_type VARCHAR(50) NOT NULL,
|
|
item_id UUID REFERENCES items(id) ON DELETE SET NULL,
|
|
from_location_id UUID REFERENCES storage_locations(id) ON DELETE SET NULL,
|
|
to_location_id UUID REFERENCES storage_locations(id) ON DELETE SET NULL,
|
|
quantity INTEGER,
|
|
user_id UUID REFERENCES users(id) ON DELETE SET NULL,
|
|
metadata JSONB DEFAULT '{}',
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
|
);
|
|
|
|
-- Создание индексов для производительности
|
|
CREATE INDEX IF NOT EXISTS idx_users_organization_id ON users(organization_id);
|
|
CREATE INDEX IF NOT EXISTS idx_users_email ON users(email);
|
|
CREATE INDEX IF NOT EXISTS idx_storage_locations_organization_id ON storage_locations(organization_id);
|
|
CREATE INDEX IF NOT EXISTS idx_storage_locations_parent_id ON storage_locations(parent_id);
|
|
CREATE INDEX IF NOT EXISTS idx_storage_locations_type ON storage_locations(type);
|
|
CREATE INDEX IF NOT EXISTS idx_items_organization_id ON items(organization_id);
|
|
CREATE INDEX IF NOT EXISTS idx_items_category ON items(category);
|
|
CREATE INDEX IF NOT EXISTS idx_item_placements_organization_id ON item_placements(organization_id);
|
|
CREATE INDEX IF NOT EXISTS idx_item_placements_item_id ON item_placements(item_id);
|
|
CREATE INDEX IF NOT EXISTS idx_item_placements_location_id ON item_placements(location_id);
|
|
CREATE INDEX IF NOT EXISTS idx_operations_organization_id ON operations(organization_id);
|
|
CREATE INDEX IF NOT EXISTS idx_operations_created_at ON operations(created_at);
|
|
|
|
-- Создание триггеров для автоматического обновления updated_at
|
|
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = NOW();
|
|
RETURN NEW;
|
|
END;
|
|
$$ language 'plpgsql';
|
|
|
|
CREATE TRIGGER update_organizations_updated_at BEFORE UPDATE ON organizations
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_storage_locations_updated_at BEFORE UPDATE ON storage_locations
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_items_updated_at BEFORE UPDATE ON items
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_item_placements_updated_at BEFORE UPDATE ON item_placements
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
-- Создание тестовых данных (опционально)
|
|
INSERT INTO organizations (id, name, type) VALUES
|
|
('550e8400-e29b-41d4-a716-446655440000', 'Тестовая мастерская', 'workshop')
|
|
ON CONFLICT (id) DO NOTHING;
|
|
|
|
INSERT INTO users (id, organization_id, email, password_hash, role) VALUES
|
|
('550e8400-e29b-41d4-a716-446655440001', '550e8400-e29b-41d4-a716-446655440000', 'admin@test.com', '$2a$10$example', 'admin')
|
|
ON CONFLICT (id) DO NOTHING;
|