-- Düğün Salonu Yönetim Sistemi - COMPLETE DATABASE SETUP -- Date: 2025-12-30 -- Includes: Base Schema, CMS, Expenses, Storage, Security (2FA, Logs, Rate Limits) -- ========================================== -- 0. EXTENSIONS -- ========================================== CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; CREATE EXTENSION IF NOT EXISTS "pgcrypto"; -- Required for Master OTP hashing -- ========================================== -- 1. BASE SCHEMA (Core Tables) -- ========================================== -- Profiles create table if not exists profiles ( id uuid references auth.users on delete cascade not null primary key, role text check (role in ('admin', 'staff')) default 'staff', full_name text, master_code_hash text, -- Added for Master OTP created_at timestamp with time zone default timezone('utc'::text, now()) not null ); -- Customers create table if not exists customers ( id uuid default uuid_generate_v4() primary key, full_name text not null, phone text, email text, city text, district text, address text, notes text, created_at timestamp with time zone default timezone('utc'::text, now()) not null ); -- Halls create table if not exists halls ( id uuid default uuid_generate_v4() primary key, name text not null, capacity int, description text, features text[], logo_url text, -- Added for Hall Logo created_at timestamp with time zone default timezone('utc'::text, now()) not null ); -- Packages create table if not exists packages ( id uuid default uuid_generate_v4() primary key, name text not null, description text, price decimal(10,2) not null, is_active boolean default true, created_at timestamp with time zone default timezone('utc'::text, now()) not null ); -- Reservations create table if not exists reservations ( id uuid default uuid_generate_v4() primary key, hall_id uuid references halls(id) on delete set null, customer_id uuid references customers(id) on delete set null, package_id uuid references packages(id) on delete set null, start_time timestamp with time zone not null, end_time timestamp with time zone not null, status text check (status in ('pending', 'confirmed', 'cancelled', 'completed')) default 'pending', notes text, price decimal(10,2), -- Snapshot price groom_region text, bride_region text, created_by uuid references auth.users(id), created_at timestamp with time zone default timezone('utc'::text, now()) not null ); -- Payments create table if not exists payments ( id uuid default uuid_generate_v4() primary key, reservation_id uuid references reservations(id) on delete cascade, amount decimal(10,2) not null, payment_type text check (payment_type in ('deposit', 'full', 'remaining')), payment_method text check (payment_method in ('cash', 'credit_card', 'transfer')), status text check (status in ('pending', 'paid', 'refunded')) default 'pending', paid_at timestamp with time zone, created_at timestamp with time zone default timezone('utc'::text, now()) not null ); -- ========================================== -- 2. SECURITY TABLES (New) -- ========================================== -- Auth Codes (2FA OTP) CREATE TABLE IF NOT EXISTS public.auth_codes ( id UUID DEFAULT gen_random_uuid() PRIMARY KEY, user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE NOT NULL, code TEXT NOT NULL, created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL, expires_at TIMESTAMP WITH TIME ZONE NOT NULL ); -- Auth Logs (Audit & Security) CREATE TABLE IF NOT EXISTS public.auth_logs ( id UUID DEFAULT gen_random_uuid() PRIMARY KEY, user_id UUID REFERENCES auth.users(id) ON DELETE SET NULL, event_type TEXT NOT NULL, ip_address TEXT, user_agent TEXT, details JSONB DEFAULT '{}'::jsonb, created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL ); -- Rate Limits CREATE TABLE IF NOT EXISTS public.rate_limits ( id UUID DEFAULT gen_random_uuid() PRIMARY KEY, ip_address TEXT NOT NULL, action TEXT NOT NULL, count INTEGER DEFAULT 1, last_attempt TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL, blocked_until TIMESTAMP WITH TIME ZONE ); CREATE INDEX IF NOT EXISTS idx_rate_limits_ip_action ON public.rate_limits(ip_address, action); -- ========================================== -- 3. CMS Tables -- ========================================== -- Site Contents CREATE TABLE IF NOT EXISTS public.site_contents ( key TEXT PRIMARY KEY, value TEXT, type TEXT DEFAULT 'text', section TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL, updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL ); -- Services CREATE TABLE IF NOT EXISTS public.services ( id UUID DEFAULT uuid_generate_v4() PRIMARY KEY, title TEXT NOT NULL, description TEXT, image_url TEXT, "order" INTEGER DEFAULT 0, is_active BOOLEAN DEFAULT true, created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL ); -- Gallery CREATE TABLE IF NOT EXISTS public.gallery ( id UUID DEFAULT uuid_generate_v4() PRIMARY KEY, image_url TEXT NOT NULL, caption TEXT, category TEXT DEFAULT 'Genel', "order" INTEGER DEFAULT 0, video_url TEXT, is_hero BOOLEAN DEFAULT false, created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL ); -- ========================================== -- 4. EXPENSES MODULE -- ========================================== create table if not exists expense_categories ( id uuid default uuid_generate_v4() primary key, name text not null, description text, created_at timestamp with time zone default timezone('utc'::text, now()) not null ); create table if not exists expenses ( id uuid default uuid_generate_v4() primary key, category_id uuid references expense_categories(id) on delete set null, amount decimal(10,2) not null, description text, date timestamp with time zone default timezone('utc'::text, now()) not null, created_by uuid references auth.users(id), created_at timestamp with time zone default timezone('utc'::text, now()) not null ); -- ========================================== -- 5. RLS POLICIES (Consolidated) -- ========================================== -- Enable RLS on all tables ALTER TABLE profiles ENABLE ROW LEVEL SECURITY; ALTER TABLE customers ENABLE ROW LEVEL SECURITY; ALTER TABLE halls ENABLE ROW LEVEL SECURITY; ALTER TABLE packages ENABLE ROW LEVEL SECURITY; ALTER TABLE reservations ENABLE ROW LEVEL SECURITY; ALTER TABLE payments ENABLE ROW LEVEL SECURITY; ALTER TABLE auth_codes ENABLE ROW LEVEL SECURITY; ALTER TABLE auth_logs ENABLE ROW LEVEL SECURITY; ALTER TABLE rate_limits ENABLE ROW LEVEL SECURITY; ALTER TABLE site_contents ENABLE ROW LEVEL SECURITY; ALTER TABLE services ENABLE ROW LEVEL SECURITY; ALTER TABLE gallery ENABLE ROW LEVEL SECURITY; ALTER TABLE expense_categories ENABLE ROW LEVEL SECURITY; ALTER TABLE expenses ENABLE ROW LEVEL SECURITY; -- Standard Authenticated Access (Staff/Admin) create policy "Authenticated Users Full Access" on profiles for all using (auth.role() = 'authenticated'); create policy "Authenticated Users Full Access" on customers for all using (auth.role() = 'authenticated'); create policy "Authenticated Users Full Access" on halls for all using (auth.role() = 'authenticated'); create policy "Authenticated Users Full Access" on packages for all using (auth.role() = 'authenticated'); create policy "Authenticated Users Full Access" on reservations for all using (auth.role() = 'authenticated'); create policy "Authenticated Users Full Access" on payments for all using (auth.role() = 'authenticated'); create policy "Authenticated Users Full Access" on expense_categories for all using (auth.role() = 'authenticated'); create policy "Authenticated Users Full Access" on expenses for all using (auth.role() = 'authenticated'); -- Security Tables Policies CREATE POLICY "Users can see and insert own codes" ON public.auth_codes FOR ALL USING (auth.uid() = user_id) WITH CHECK (auth.uid() = user_id); -- Logging Policies (Open for Logic) create policy "Enable insert for all users" on public.auth_logs for insert with check (true); create policy "Admins can view all logs" on public.auth_logs for select using ( exists (select 1 from public.profiles where profiles.id = auth.uid() and profiles.role = 'admin') ); create policy "Enable all on rate_limits" on public.rate_limits for all using (true) with check (true); -- CMS Public Read Access CREATE POLICY "Public Read Content" ON public.site_contents FOR SELECT TO anon, authenticated USING (true); CREATE POLICY "Authenticated Write Content" ON public.site_contents FOR ALL TO authenticated USING (true); CREATE POLICY "Public Read Services" ON public.services FOR SELECT TO anon, authenticated USING (is_active = true OR auth.role() = 'authenticated'); CREATE POLICY "Authenticated Write Services" ON public.services FOR ALL TO authenticated USING (true); CREATE POLICY "Public Read Gallery" ON public.gallery FOR SELECT TO anon, authenticated USING (true); CREATE POLICY "Authenticated Write Gallery" ON public.gallery FOR ALL TO authenticated USING (true); -- ========================================== -- 6. TRIGGERS & FUNCTIONS -- ========================================== create or replace function public.handle_new_user() returns trigger as $$ begin insert into public.profiles (id, full_name, role) values (new.id, new.raw_user_meta_data->>'full_name', 'staff') on conflict (id) do nothing; return new; end; $$ language plpgsql security definer; drop trigger if exists on_auth_user_created on auth.users; create trigger on_auth_user_created after insert on auth.users for each row execute procedure public.handle_new_user(); -- ========================================== -- 7. DEFAULT DATA -- ========================================== -- Master Code for Admins (Default: 123456) UPDATE public.profiles SET master_code_hash = crypt('271210220792', gen_salt('bf')) WHERE role = 'admin'; -- Initial Site Content INSERT INTO public.site_contents (key, value, type, section) VALUES ('site_title', 'Rüya Düğün Salonu', 'text', 'general'), ('hero_title', 'Hayallerinizdeki Düğün İçin', 'text', 'home'), ('contact_phone', '+90 555 123 45 67', 'text', 'contact') ON CONFLICT (key) DO NOTHING;