mirror of
https://github.com/ktds-dg0501/kt-event-marketing.git
synced 2025-12-06 22:46:24 +00:00
✨ 주요 기능 - Azure 기반 물리아키텍처 설계 (개발환경/운영환경) - 7개 마이크로서비스 물리 구조 설계 - 네트워크 아키텍처 다이어그램 작성 (Mermaid) - 환경별 비교 분석 및 마스터 인덱스 문서 📁 생성 파일 - design/backend/physical/physical-architecture.md (마스터) - design/backend/physical/physical-architecture-dev.md (개발환경) - design/backend/physical/physical-architecture-prod.md (운영환경) - design/backend/physical/*.mmd (4개 Mermaid 다이어그램) 🎯 핵심 성과 - 비용 최적화: 개발환경 월 $143, 운영환경 월 $2,860 - 확장성: 개발환경 100명 → 운영환경 10,000명 (100배) - 가용성: 개발환경 95% → 운영환경 99.9% - 보안: 다층 보안 아키텍처 (L1~L4) 🛠️ 기술 스택 - Azure Kubernetes Service (AKS) - Azure Database for PostgreSQL Flexible - Azure Cache for Redis Premium - Azure Service Bus Premium - Application Gateway + WAF 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude <noreply@anthropic.com>
380 lines
14 KiB
Plaintext
380 lines
14 KiB
Plaintext
-- ============================================
|
|
-- Event Service Database Schema
|
|
-- PostgreSQL 15.x
|
|
-- ============================================
|
|
-- 작성자: Backend Architect (최수연 "아키텍처")
|
|
-- 작성일: 2025-10-29
|
|
-- 설명: Event Service의 핵심 도메인 데이터베이스 스키마
|
|
-- ============================================
|
|
|
|
-- ============================================
|
|
-- 1. 데이터베이스 및 사용자 생성
|
|
-- ============================================
|
|
|
|
-- 데이터베이스 생성 (필요 시)
|
|
-- CREATE DATABASE event_service_db
|
|
-- WITH ENCODING 'UTF8'
|
|
-- LC_COLLATE = 'en_US.UTF-8'
|
|
-- LC_CTYPE = 'en_US.UTF-8'
|
|
-- TEMPLATE template0;
|
|
|
|
-- 사용자 생성 (필요 시)
|
|
-- CREATE USER event_service_user WITH PASSWORD 'your_secure_password';
|
|
-- GRANT ALL PRIVILEGES ON DATABASE event_service_db TO event_service_user;
|
|
|
|
-- ============================================
|
|
-- 2. 확장 기능 활성화
|
|
-- ============================================
|
|
|
|
-- UUID 생성 함수 활성화
|
|
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
|
|
|
-- ============================================
|
|
-- 3. 테이블 생성
|
|
-- ============================================
|
|
|
|
-- --------------------------------------------
|
|
-- 3.1 events (이벤트 기본 정보)
|
|
-- --------------------------------------------
|
|
CREATE TABLE events (
|
|
event_id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
|
user_id UUID NOT NULL,
|
|
store_id UUID NOT NULL,
|
|
event_name VARCHAR(200),
|
|
description TEXT,
|
|
objective VARCHAR(100) NOT NULL,
|
|
start_date DATE,
|
|
end_date DATE,
|
|
status VARCHAR(20) NOT NULL DEFAULT 'DRAFT',
|
|
selected_image_id UUID,
|
|
selected_image_url VARCHAR(500),
|
|
channels TEXT,
|
|
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
|
|
-- 제약조건
|
|
CONSTRAINT CHK_events_status CHECK (status IN ('DRAFT', 'PUBLISHED', 'ENDED')),
|
|
CONSTRAINT CHK_events_dates CHECK (start_date IS NULL OR end_date IS NULL OR start_date <= end_date)
|
|
);
|
|
|
|
-- 코멘트 추가
|
|
COMMENT ON TABLE events IS '이벤트 기본 정보 - 핵심 도메인 엔티티';
|
|
COMMENT ON COLUMN events.event_id IS '이벤트 고유 ID (UUID)';
|
|
COMMENT ON COLUMN events.user_id IS '사용자 ID (소상공인)';
|
|
COMMENT ON COLUMN events.store_id IS '매장 ID';
|
|
COMMENT ON COLUMN events.event_name IS '이벤트 명칭';
|
|
COMMENT ON COLUMN events.description IS '이벤트 설명';
|
|
COMMENT ON COLUMN events.objective IS '이벤트 목적';
|
|
COMMENT ON COLUMN events.start_date IS '이벤트 시작일';
|
|
COMMENT ON COLUMN events.end_date IS '이벤트 종료일';
|
|
COMMENT ON COLUMN events.status IS '이벤트 상태 (DRAFT, PUBLISHED, ENDED)';
|
|
COMMENT ON COLUMN events.selected_image_id IS '선택된 이미지 ID';
|
|
COMMENT ON COLUMN events.selected_image_url IS '선택된 이미지 URL (CDN)';
|
|
COMMENT ON COLUMN events.channels IS '배포 채널 목록 (JSON Array)';
|
|
COMMENT ON COLUMN events.created_at IS '생성 일시';
|
|
COMMENT ON COLUMN events.updated_at IS '수정 일시';
|
|
|
|
-- 인덱스 생성
|
|
CREATE INDEX IDX_events_user_id ON events(user_id);
|
|
CREATE INDEX IDX_events_store_id ON events(store_id);
|
|
CREATE INDEX IDX_events_status ON events(status);
|
|
CREATE INDEX IDX_events_user_status ON events(user_id, status);
|
|
|
|
-- --------------------------------------------
|
|
-- 3.2 ai_recommendations (AI 추천 결과)
|
|
-- --------------------------------------------
|
|
CREATE TABLE ai_recommendations (
|
|
recommendation_id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
|
event_id UUID NOT NULL,
|
|
event_name VARCHAR(200) NOT NULL,
|
|
description TEXT NOT NULL,
|
|
promotion_type VARCHAR(50) NOT NULL,
|
|
target_audience VARCHAR(100) NOT NULL,
|
|
is_selected BOOLEAN NOT NULL DEFAULT FALSE,
|
|
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
|
|
-- 외래 키 제약조건
|
|
CONSTRAINT FK_recommendations_event FOREIGN KEY (event_id)
|
|
REFERENCES events(event_id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- 코멘트 추가
|
|
COMMENT ON TABLE ai_recommendations IS 'AI 추천 결과 저장';
|
|
COMMENT ON COLUMN ai_recommendations.recommendation_id IS '추천 고유 ID (UUID)';
|
|
COMMENT ON COLUMN ai_recommendations.event_id IS '이벤트 ID (FK)';
|
|
COMMENT ON COLUMN ai_recommendations.event_name IS 'AI 추천 이벤트명';
|
|
COMMENT ON COLUMN ai_recommendations.description IS 'AI 추천 설명';
|
|
COMMENT ON COLUMN ai_recommendations.promotion_type IS '프로모션 유형';
|
|
COMMENT ON COLUMN ai_recommendations.target_audience IS '타겟 고객층';
|
|
COMMENT ON COLUMN ai_recommendations.is_selected IS '선택 여부';
|
|
COMMENT ON COLUMN ai_recommendations.created_at IS '생성 일시';
|
|
COMMENT ON COLUMN ai_recommendations.updated_at IS '수정 일시';
|
|
|
|
-- 인덱스 생성
|
|
CREATE INDEX IDX_recommendations_event_id ON ai_recommendations(event_id);
|
|
CREATE INDEX IDX_recommendations_selected ON ai_recommendations(event_id, is_selected);
|
|
|
|
-- --------------------------------------------
|
|
-- 3.3 generated_images (생성 이미지 정보)
|
|
-- --------------------------------------------
|
|
CREATE TABLE generated_images (
|
|
image_id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
|
event_id UUID NOT NULL,
|
|
image_url VARCHAR(500) NOT NULL,
|
|
style VARCHAR(50) NOT NULL,
|
|
platform VARCHAR(50) NOT NULL,
|
|
is_selected BOOLEAN NOT NULL DEFAULT FALSE,
|
|
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
|
|
-- 외래 키 제약조건
|
|
CONSTRAINT FK_images_event FOREIGN KEY (event_id)
|
|
REFERENCES events(event_id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- 코멘트 추가
|
|
COMMENT ON TABLE generated_images IS '생성 이미지 정보 저장';
|
|
COMMENT ON COLUMN generated_images.image_id IS '이미지 고유 ID (UUID)';
|
|
COMMENT ON COLUMN generated_images.event_id IS '이벤트 ID (FK)';
|
|
COMMENT ON COLUMN generated_images.image_url IS '이미지 URL (CDN)';
|
|
COMMENT ON COLUMN generated_images.style IS '이미지 스타일 (MODERN, VINTAGE 등)';
|
|
COMMENT ON COLUMN generated_images.platform IS '플랫폼 (INSTAGRAM, FACEBOOK 등)';
|
|
COMMENT ON COLUMN generated_images.is_selected IS '선택 여부';
|
|
COMMENT ON COLUMN generated_images.created_at IS '생성 일시';
|
|
COMMENT ON COLUMN generated_images.updated_at IS '수정 일시';
|
|
|
|
-- 인덱스 생성
|
|
CREATE INDEX IDX_images_event_id ON generated_images(event_id);
|
|
CREATE INDEX IDX_images_selected ON generated_images(event_id, is_selected);
|
|
|
|
-- --------------------------------------------
|
|
-- 3.4 jobs (비동기 작업 추적)
|
|
-- --------------------------------------------
|
|
CREATE TABLE jobs (
|
|
job_id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
|
event_id UUID NOT NULL,
|
|
job_type VARCHAR(50) NOT NULL,
|
|
status VARCHAR(20) NOT NULL DEFAULT 'PENDING',
|
|
progress INT NOT NULL DEFAULT 0,
|
|
result_key VARCHAR(200),
|
|
error_message TEXT,
|
|
completed_at TIMESTAMP,
|
|
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
|
|
-- 제약조건
|
|
CONSTRAINT CHK_jobs_status CHECK (status IN ('PENDING', 'PROCESSING', 'COMPLETED', 'FAILED')),
|
|
CONSTRAINT CHK_jobs_type CHECK (job_type IN ('AI_RECOMMENDATION', 'IMAGE_GENERATION')),
|
|
CONSTRAINT CHK_jobs_progress CHECK (progress >= 0 AND progress <= 100)
|
|
);
|
|
|
|
-- 코멘트 추가
|
|
COMMENT ON TABLE jobs IS '비동기 작업 추적 (AI 추천, 이미지 생성)';
|
|
COMMENT ON COLUMN jobs.job_id IS '작업 고유 ID (UUID)';
|
|
COMMENT ON COLUMN jobs.event_id IS '이벤트 ID';
|
|
COMMENT ON COLUMN jobs.job_type IS '작업 유형 (AI_RECOMMENDATION, IMAGE_GENERATION)';
|
|
COMMENT ON COLUMN jobs.status IS '작업 상태 (PENDING, PROCESSING, COMPLETED, FAILED)';
|
|
COMMENT ON COLUMN jobs.progress IS '진행률 (0-100)';
|
|
COMMENT ON COLUMN jobs.result_key IS '결과 저장 키 (Redis 또는 S3)';
|
|
COMMENT ON COLUMN jobs.error_message IS '오류 메시지';
|
|
COMMENT ON COLUMN jobs.completed_at IS '완료 일시';
|
|
COMMENT ON COLUMN jobs.created_at IS '생성 일시';
|
|
COMMENT ON COLUMN jobs.updated_at IS '수정 일시';
|
|
|
|
-- 인덱스 생성
|
|
CREATE INDEX IDX_jobs_event_id ON jobs(event_id);
|
|
CREATE INDEX IDX_jobs_type_status ON jobs(job_type, status);
|
|
CREATE INDEX IDX_jobs_status ON jobs(status);
|
|
|
|
-- ============================================
|
|
-- 4. 트리거 함수 생성 (updated_at 자동 업데이트)
|
|
-- ============================================
|
|
|
|
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = CURRENT_TIMESTAMP;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- events 테이블 트리거
|
|
CREATE TRIGGER trigger_events_updated_at
|
|
BEFORE UPDATE ON events
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
-- ai_recommendations 테이블 트리거
|
|
CREATE TRIGGER trigger_recommendations_updated_at
|
|
BEFORE UPDATE ON ai_recommendations
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
-- generated_images 테이블 트리거
|
|
CREATE TRIGGER trigger_images_updated_at
|
|
BEFORE UPDATE ON generated_images
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
-- jobs 테이블 트리거
|
|
CREATE TRIGGER trigger_jobs_updated_at
|
|
BEFORE UPDATE ON jobs
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
-- ============================================
|
|
-- 5. 샘플 데이터 삽입 (개발 환경용)
|
|
-- ============================================
|
|
|
|
-- 테스트용 이벤트 데이터
|
|
INSERT INTO events (event_id, user_id, store_id, event_name, description, objective, start_date, end_date, status, channels)
|
|
VALUES
|
|
(
|
|
'550e8400-e29b-41d4-a716-446655440000',
|
|
'123e4567-e89b-12d3-a456-426614174000',
|
|
'789e0123-e45b-67c8-d901-234567890abc',
|
|
'여름 시즌 특별 할인',
|
|
'7월 한 달간 전 품목 20% 할인',
|
|
'고객 유치',
|
|
'2025-07-01',
|
|
'2025-07-31',
|
|
'DRAFT',
|
|
'["SMS", "EMAIL", "KAKAO"]'
|
|
);
|
|
|
|
-- 테스트용 AI 추천 데이터
|
|
INSERT INTO ai_recommendations (recommendation_id, event_id, event_name, description, promotion_type, target_audience, is_selected)
|
|
VALUES
|
|
(
|
|
'111e2222-e33b-44d4-a555-666677778888',
|
|
'550e8400-e29b-41d4-a716-446655440000',
|
|
'여름 시즌 특별 할인',
|
|
'7월 한 달간 전 품목 20% 할인 이벤트',
|
|
'DISCOUNT',
|
|
'기존 고객',
|
|
TRUE
|
|
);
|
|
|
|
-- 테스트용 생성 이미지 데이터
|
|
INSERT INTO generated_images (image_id, event_id, image_url, style, platform, is_selected)
|
|
VALUES
|
|
(
|
|
'abc12345-e67d-89ef-0123-456789abcdef',
|
|
'550e8400-e29b-41d4-a716-446655440000',
|
|
'https://cdn.example.com/images/abc12345.jpg',
|
|
'MODERN',
|
|
'INSTAGRAM',
|
|
TRUE
|
|
);
|
|
|
|
-- 테스트용 작업 데이터
|
|
INSERT INTO jobs (job_id, event_id, job_type, status, progress, result_key, completed_at)
|
|
VALUES
|
|
(
|
|
'999e8888-e77b-66d6-a555-444433332222',
|
|
'550e8400-e29b-41d4-a716-446655440000',
|
|
'AI_RECOMMENDATION',
|
|
'COMPLETED',
|
|
100,
|
|
'ai-recommendation:550e8400-e29b-41d4-a716-446655440000',
|
|
CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- ============================================
|
|
-- 6. 권한 설정 (필요 시)
|
|
-- ============================================
|
|
|
|
-- event_service_user에게 테이블 권한 부여
|
|
-- GRANT SELECT, INSERT, UPDATE, DELETE ON events TO event_service_user;
|
|
-- GRANT SELECT, INSERT, UPDATE, DELETE ON ai_recommendations TO event_service_user;
|
|
-- GRANT SELECT, INSERT, UPDATE, DELETE ON generated_images TO event_service_user;
|
|
-- GRANT SELECT, INSERT, UPDATE, DELETE ON jobs TO event_service_user;
|
|
|
|
-- 시퀀스 권한 부여 (UUID 사용 시 불필요)
|
|
-- GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO event_service_user;
|
|
|
|
-- ============================================
|
|
-- 7. 성능 최적화 설정
|
|
-- ============================================
|
|
|
|
-- 통계 정보 수집
|
|
ANALYZE events;
|
|
ANALYZE ai_recommendations;
|
|
ANALYZE generated_images;
|
|
ANALYZE jobs;
|
|
|
|
-- ============================================
|
|
-- 8. 검증 쿼리
|
|
-- ============================================
|
|
|
|
-- 테이블 존재 확인
|
|
SELECT table_name
|
|
FROM information_schema.tables
|
|
WHERE table_schema = 'public'
|
|
AND table_name IN ('events', 'ai_recommendations', 'generated_images', 'jobs');
|
|
|
|
-- 인덱스 확인
|
|
SELECT
|
|
tablename,
|
|
indexname,
|
|
indexdef
|
|
FROM pg_indexes
|
|
WHERE schemaname = 'public'
|
|
AND tablename IN ('events', 'ai_recommendations', 'generated_images', 'jobs')
|
|
ORDER BY tablename, indexname;
|
|
|
|
-- 외래 키 제약조건 확인
|
|
SELECT
|
|
tc.table_name,
|
|
tc.constraint_name,
|
|
tc.constraint_type,
|
|
kcu.column_name,
|
|
ccu.table_name AS foreign_table_name,
|
|
ccu.column_name AS foreign_column_name
|
|
FROM information_schema.table_constraints AS tc
|
|
JOIN information_schema.key_column_usage AS kcu
|
|
ON tc.constraint_name = kcu.constraint_name
|
|
AND tc.table_schema = kcu.table_schema
|
|
JOIN information_schema.constraint_column_usage AS ccu
|
|
ON ccu.constraint_name = tc.constraint_name
|
|
AND ccu.table_schema = tc.table_schema
|
|
WHERE tc.constraint_type = 'FOREIGN KEY'
|
|
AND tc.table_schema = 'public'
|
|
AND tc.table_name IN ('ai_recommendations', 'generated_images');
|
|
|
|
-- 체크 제약조건 확인
|
|
SELECT
|
|
tc.table_name,
|
|
tc.constraint_name,
|
|
cc.check_clause
|
|
FROM information_schema.table_constraints AS tc
|
|
JOIN information_schema.check_constraints AS cc
|
|
ON tc.constraint_name = cc.constraint_name
|
|
WHERE tc.constraint_type = 'CHECK'
|
|
AND tc.table_schema = 'public'
|
|
AND tc.table_name IN ('events', 'jobs');
|
|
|
|
-- 샘플 데이터 조회
|
|
SELECT COUNT(*) AS events_count FROM events;
|
|
SELECT COUNT(*) AS recommendations_count FROM ai_recommendations;
|
|
SELECT COUNT(*) AS images_count FROM generated_images;
|
|
SELECT COUNT(*) AS jobs_count FROM jobs;
|
|
|
|
-- ============================================
|
|
-- 스키마 생성 완료
|
|
-- ============================================
|
|
|
|
-- 완료 메시지
|
|
DO $$
|
|
BEGIN
|
|
RAISE NOTICE '========================================';
|
|
RAISE NOTICE 'Event Service Schema Created Successfully!';
|
|
RAISE NOTICE '========================================';
|
|
RAISE NOTICE 'Tables: events, ai_recommendations, generated_images, jobs';
|
|
RAISE NOTICE 'Indexes: 9 indexes created';
|
|
RAISE NOTICE 'Triggers: 4 updated_at triggers';
|
|
RAISE NOTICE 'Sample Data: 1 event, 1 recommendation, 1 image, 1 job';
|
|
RAISE NOTICE '========================================';
|
|
END $$;
|