-- Zellyy Finance - Supabase Database Schema -- 기존 Appwrite 데이터 구조를 기반으로 설계된 PostgreSQL 스키마 -- 1. 사용자 인증 관련 테이블 (Clerk + Supabase Auth 통합) -- Supabase Auth를 사용하면서 Clerk 사용자 정보를 확장하기 위한 프로필 테이블 CREATE TABLE user_profiles ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), clerk_user_id TEXT UNIQUE NOT NULL, -- Clerk 사용자 ID auth_user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE, -- Supabase Auth 연결 username TEXT, first_name TEXT, last_name TEXT, email TEXT NOT NULL, phone TEXT, profile_image_url TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()), updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()), last_login_at TIMESTAMP WITH TIME ZONE, is_active BOOLEAN DEFAULT true, preferences JSONB DEFAULT '{}'::jsonb -- 사용자 설정 (테마, 알림 등) ); -- 2. 거래 (Transactions) 테이블 CREATE TYPE transaction_type AS ENUM ('income', 'expense'); CREATE TYPE payment_method AS ENUM ('신용카드', '현금', '체크카드', '간편결제'); CREATE TYPE transaction_category AS ENUM ('음식', '쇼핑', '교통', '의료', '교육', '여가', '기타'); CREATE TYPE transaction_priority AS ENUM ('high', 'medium', 'low'); CREATE TABLE transactions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES user_profiles(id) ON DELETE CASCADE, title TEXT NOT NULL, amount DECIMAL(15,2) NOT NULL CHECK (amount >= 0), date DATE NOT NULL, category transaction_category NOT NULL, type transaction_type NOT NULL, payment_method payment_method, notes TEXT, priority transaction_priority DEFAULT 'medium', -- 동기화 관련 필드 local_timestamp TIMESTAMP WITH TIME ZONE, server_timestamp TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()), is_synced BOOLEAN DEFAULT true, -- 메타데이터 created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()), updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()), -- 인덱스를 위한 제약조건 CONSTRAINT valid_amount CHECK (amount > 0) ); -- 3. 예산 (Budgets) 테이블 CREATE TYPE budget_period AS ENUM ('daily', 'weekly', 'monthly'); CREATE TYPE budget_status AS ENUM ('safe', 'warning', 'danger', 'exceeded'); CREATE TABLE budgets ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES user_profiles(id) ON DELETE CASCADE, period budget_period NOT NULL, target_amount DECIMAL(15,2) NOT NULL CHECK (target_amount > 0), spent_amount DECIMAL(15,2) DEFAULT 0 CHECK (spent_amount >= 0), remaining_amount DECIMAL(15,2) GENERATED ALWAYS AS (target_amount - spent_amount) STORED, -- 기간 정보 start_date DATE NOT NULL, end_date DATE NOT NULL, -- 상태 및 메타데이터 status budget_status DEFAULT 'safe', created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()), updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()), -- 제약조건 CONSTRAINT valid_period CHECK (end_date > start_date), CONSTRAINT unique_user_period UNIQUE (user_id, period, start_date) ); -- 4. 카테고리별 예산 (Category Budgets) 테이블 CREATE TABLE category_budgets ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES user_profiles(id) ON DELETE CASCADE, budget_id UUID NOT NULL REFERENCES budgets(id) ON DELETE CASCADE, category transaction_category NOT NULL, allocated_amount DECIMAL(15,2) NOT NULL CHECK (allocated_amount >= 0), spent_amount DECIMAL(15,2) DEFAULT 0 CHECK (spent_amount >= 0), remaining_amount DECIMAL(15,2) GENERATED ALWAYS AS (allocated_amount - spent_amount) STORED, created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()), updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()), -- 유니크 제약조건 CONSTRAINT unique_budget_category UNIQUE (budget_id, category) ); -- 5. 인덱스 생성 (성능 최적화) -- 사용자별 거래 조회 최적화 CREATE INDEX idx_transactions_user_date ON transactions(user_id, date DESC); CREATE INDEX idx_transactions_user_category ON transactions(user_id, category); CREATE INDEX idx_transactions_user_type ON transactions(user_id, type); CREATE INDEX idx_transactions_user_payment_method ON transactions(user_id, payment_method); -- 예산 관련 조회 최적화 CREATE INDEX idx_budgets_user_period ON budgets(user_id, period, start_date); CREATE INDEX idx_category_budgets_user_category ON category_budgets(user_id, category); -- 사용자 프로필 조회 최적화 CREATE INDEX idx_user_profiles_clerk_id ON user_profiles(clerk_user_id); CREATE INDEX idx_user_profiles_email ON user_profiles(email); -- 6. Row Level Security (RLS) 정책 설정 -- 사용자 프로필 RLS ALTER TABLE user_profiles ENABLE ROW LEVEL SECURITY; CREATE POLICY "사용자는 자신의 프로필만 조회 가능" ON user_profiles FOR SELECT USING (clerk_user_id = auth.jwt() ->> 'sub'); CREATE POLICY "사용자는 자신의 프로필만 수정 가능" ON user_profiles FOR UPDATE USING (clerk_user_id = auth.jwt() ->> 'sub'); CREATE POLICY "사용자는 자신의 프로필만 삽입 가능" ON user_profiles FOR INSERT WITH CHECK (clerk_user_id = auth.jwt() ->> 'sub'); -- 거래 RLS ALTER TABLE transactions ENABLE ROW LEVEL SECURITY; CREATE POLICY "사용자는 자신의 거래만 조회 가능" ON transactions FOR SELECT USING ( user_id IN ( SELECT id FROM user_profiles WHERE clerk_user_id = auth.jwt() ->> 'sub' ) ); CREATE POLICY "사용자는 자신의 거래만 생성 가능" ON transactions FOR INSERT WITH CHECK ( user_id IN ( SELECT id FROM user_profiles WHERE clerk_user_id = auth.jwt() ->> 'sub' ) ); CREATE POLICY "사용자는 자신의 거래만 수정 가능" ON transactions FOR UPDATE USING ( user_id IN ( SELECT id FROM user_profiles WHERE clerk_user_id = auth.jwt() ->> 'sub' ) ); CREATE POLICY "사용자는 자신의 거래만 삭제 가능" ON transactions FOR DELETE USING ( user_id IN ( SELECT id FROM user_profiles WHERE clerk_user_id = auth.jwt() ->> 'sub' ) ); -- 예산 RLS ALTER TABLE budgets ENABLE ROW LEVEL SECURITY; CREATE POLICY "사용자는 자신의 예산만 접근 가능" ON budgets FOR ALL USING ( user_id IN ( SELECT id FROM user_profiles WHERE clerk_user_id = auth.jwt() ->> 'sub' ) ); -- 카테고리별 예산 RLS ALTER TABLE category_budgets ENABLE ROW LEVEL SECURITY; CREATE POLICY "사용자는 자신의 카테고리별 예산만 접근 가능" ON category_budgets FOR ALL USING ( user_id IN ( SELECT id FROM user_profiles WHERE clerk_user_id = auth.jwt() ->> 'sub' ) ); -- 7. 트리거 함수 생성 (자동 업데이트) -- updated_at 필드 자동 업데이트 함수 CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = timezone('utc'::text, now()); RETURN NEW; END; $$ language 'plpgsql'; -- 각 테이블에 updated_at 트리거 적용 CREATE TRIGGER update_user_profiles_updated_at BEFORE UPDATE ON user_profiles FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_transactions_updated_at BEFORE UPDATE ON transactions FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_budgets_updated_at BEFORE UPDATE ON budgets FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_category_budgets_updated_at BEFORE UPDATE ON category_budgets FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- 8. 예산 상태 자동 업데이트 함수 CREATE OR REPLACE FUNCTION update_budget_status() RETURNS TRIGGER AS $$ BEGIN -- 예산 상태 계산 IF NEW.remaining_amount < 0 THEN NEW.status = 'exceeded'; ELSIF NEW.remaining_amount < (NEW.target_amount * 0.1) THEN NEW.status = 'danger'; ELSIF NEW.remaining_amount < (NEW.target_amount * 0.3) THEN NEW.status = 'warning'; ELSE NEW.status = 'safe'; END IF; RETURN NEW; END; $$ language 'plpgsql'; CREATE TRIGGER update_budget_status_trigger BEFORE INSERT OR UPDATE ON budgets FOR EACH ROW EXECUTE FUNCTION update_budget_status(); -- 9. 거래 생성 시 예산 업데이트 함수 CREATE OR REPLACE FUNCTION update_budget_on_transaction() RETURNS TRIGGER AS $$ DECLARE current_budget_id UUID; transaction_amount DECIMAL(15,2); BEGIN -- 지출 거래인 경우에만 예산 업데이트 IF NEW.type = 'expense' THEN transaction_amount := NEW.amount; -- 현재 활성 월간 예산 찾기 SELECT id INTO current_budget_id FROM budgets WHERE user_id = NEW.user_id AND period = 'monthly' AND NEW.date BETWEEN start_date AND end_date LIMIT 1; -- 예산이 존재하면 업데이트 IF current_budget_id IS NOT NULL THEN -- 전체 예산 업데이트 UPDATE budgets SET spent_amount = spent_amount + transaction_amount WHERE id = current_budget_id; -- 카테고리별 예산 업데이트 UPDATE category_budgets SET spent_amount = spent_amount + transaction_amount WHERE budget_id = current_budget_id AND category = NEW.category; END IF; END IF; RETURN NEW; END; $$ language 'plpgsql'; CREATE TRIGGER update_budget_on_transaction_trigger AFTER INSERT ON transactions FOR EACH ROW EXECUTE FUNCTION update_budget_on_transaction(); -- 10. 실시간 구독을 위한 발행/구독 설정 -- 거래 변경 사항 실시간 알림 CREATE OR REPLACE FUNCTION notify_transaction_changes() RETURNS TRIGGER AS $$ BEGIN PERFORM pg_notify( 'transaction_changes', json_build_object( 'operation', TG_OP, 'record', row_to_json(NEW), 'user_id', NEW.user_id )::text ); RETURN NEW; END; $$ language 'plpgsql'; CREATE TRIGGER transaction_changes_trigger AFTER INSERT OR UPDATE OR DELETE ON transactions FOR EACH ROW EXECUTE FUNCTION notify_transaction_changes(); -- 예산 변경 사항 실시간 알림 CREATE OR REPLACE FUNCTION notify_budget_changes() RETURNS TRIGGER AS $$ BEGIN PERFORM pg_notify( 'budget_changes', json_build_object( 'operation', TG_OP, 'record', row_to_json(NEW), 'user_id', NEW.user_id )::text ); RETURN NEW; END; $$ language 'plpgsql'; CREATE TRIGGER budget_changes_trigger AFTER INSERT OR UPDATE OR DELETE ON budgets FOR EACH ROW EXECUTE FUNCTION notify_budget_changes(); -- 11. 뷰 생성 (자주 사용되는 쿼리 최적화) -- 사용자별 월간 지출 요약 뷰 CREATE VIEW user_monthly_spending AS SELECT t.user_id, DATE_TRUNC('month', t.date) as month, t.category, SUM(CASE WHEN t.type = 'expense' THEN t.amount ELSE 0 END) as total_expense, SUM(CASE WHEN t.type = 'income' THEN t.amount ELSE 0 END) as total_income, COUNT(*) as transaction_count FROM transactions t GROUP BY t.user_id, DATE_TRUNC('month', t.date), t.category; -- 사용자별 결제 수단 통계 뷰 CREATE VIEW user_payment_method_stats AS SELECT t.user_id, t.payment_method, SUM(t.amount) as total_amount, COUNT(*) as transaction_count, ROUND( (SUM(t.amount) * 100.0 / SUM(SUM(t.amount)) OVER (PARTITION BY t.user_id)), 2 ) as percentage FROM transactions t WHERE t.type = 'expense' GROUP BY t.user_id, t.payment_method; -- 12. 샘플 데이터 삽입 (개발/테스트 용도) -- 이 부분은 실제 프로덕션에서는 제거하거나 주석 처리 /* -- 예시 사용자 프로필 INSERT INTO user_profiles (clerk_user_id, email, username, first_name, last_name) VALUES ('user_test123', 'test@example.com', 'testuser', '테스트', '사용자'); -- 예시 예산 INSERT INTO budgets (user_id, period, target_amount, start_date, end_date) VALUES ((SELECT id FROM user_profiles WHERE clerk_user_id = 'user_test123'), 'monthly', 1000000, '2024-01-01', '2024-01-31'); -- 예시 거래 INSERT INTO transactions (user_id, title, amount, date, category, type, payment_method) VALUES ((SELECT id FROM user_profiles WHERE clerk_user_id = 'user_test123'), '점심식사', 15000, '2024-01-15', '음식', 'expense', '신용카드'); */ -- 13. 성능 모니터링을 위한 통계 테이블 CREATE TABLE performance_stats ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), table_name TEXT NOT NULL, operation_type TEXT NOT NULL, -- 'INSERT', 'UPDATE', 'DELETE', 'SELECT' execution_time_ms INTEGER, row_count INTEGER, created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) ); -- 성능 통계 수집을 위한 인덱스 CREATE INDEX idx_performance_stats_table_operation ON performance_stats(table_name, operation_type); CREATE INDEX idx_performance_stats_date ON performance_stats(created_at); -- 이 스키마는 Clerk 인증과 Supabase의 완전한 통합을 위해 설계되었습니다. -- RLS 정책을 통해 사용자별 데이터 격리를 보장하며, -- 실시간 구독과 자동 업데이트 트리거를 통해 현대적인 웹 앱 요구사항을 충족합니다.