-- ============================================================================ -- Distribution Service Database Schema -- ============================================================================ -- 목적: 이벤트 배포 상태 및 채널별 성과 추적 -- 작성일: 2025-10-29 -- 작성자: Backend Developer (최수연 "아키텍처") -- 데이터베이스: PostgreSQL 14+ -- ============================================================================ -- ============================================================================ -- 1. 데이터베이스 및 스키마 생성 -- ============================================================================ -- 데이터베이스 생성 (필요시) -- CREATE DATABASE distribution_db; -- 스키마 생성 CREATE SCHEMA IF NOT EXISTS distribution; -- 스키마를 기본 검색 경로로 설정 SET search_path TO distribution, public; -- ============================================================================ -- 2. 기존 테이블 삭제 (개발 환경용 - 주의!) -- ============================================================================ -- 주의: 운영 환경에서는 이 섹션을 주석 처리하거나 제거해야 합니다. DROP TABLE IF EXISTS distribution.channel_status CASCADE; DROP TABLE IF EXISTS distribution.distribution_status CASCADE; -- ============================================================================ -- 3. distribution_status 테이블 생성 -- ============================================================================ CREATE TABLE distribution.distribution_status ( -- 기본 키 id BIGSERIAL PRIMARY KEY, -- 배포 정보 event_id VARCHAR(36) NOT NULL, overall_status VARCHAR(20) NOT NULL, -- 시간 정보 started_at TIMESTAMP NOT NULL, completed_at TIMESTAMP, -- 감사 정보 created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 제약 조건 CONSTRAINT uk_distribution_event_id UNIQUE (event_id), CONSTRAINT ck_distribution_overall_status CHECK ( overall_status IN ('IN_PROGRESS', 'COMPLETED', 'FAILED', 'PARTIAL_SUCCESS') ) ); -- 코멘트 추가 COMMENT ON TABLE distribution.distribution_status IS '이벤트별 배포 전체 상태 관리'; COMMENT ON COLUMN distribution.distribution_status.id IS '배포 상태 ID (PK)'; COMMENT ON COLUMN distribution.distribution_status.event_id IS '이벤트 ID (UUID)'; COMMENT ON COLUMN distribution.distribution_status.overall_status IS '전체 배포 상태 (IN_PROGRESS, COMPLETED, FAILED, PARTIAL_SUCCESS)'; COMMENT ON COLUMN distribution.distribution_status.started_at IS '배포 시작 시간'; COMMENT ON COLUMN distribution.distribution_status.completed_at IS '배포 완료 시간'; COMMENT ON COLUMN distribution.distribution_status.created_at IS '생성 시간'; COMMENT ON COLUMN distribution.distribution_status.updated_at IS '수정 시간'; -- 인덱스 생성 CREATE INDEX idx_distribution_status_event_id ON distribution.distribution_status(event_id); CREATE INDEX idx_distribution_status_overall_status ON distribution.distribution_status(overall_status); CREATE INDEX idx_distribution_status_started_at ON distribution.distribution_status(started_at DESC); -- ============================================================================ -- 4. channel_status 테이블 생성 -- ============================================================================ CREATE TABLE distribution.channel_status ( -- 기본 키 id BIGSERIAL PRIMARY KEY, -- 외래 키 distribution_status_id BIGINT NOT NULL, -- 채널 정보 channel VARCHAR(20) NOT NULL, status VARCHAR(20) NOT NULL, progress INTEGER DEFAULT 0, -- 배포 결과 정보 distribution_id VARCHAR(100), estimated_views INTEGER DEFAULT 0, -- 시간 정보 update_timestamp TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, completed_at TIMESTAMP, -- 조회 최적화용 event_id VARCHAR(36) NOT NULL, -- 채널별 상세 정보 impression_schedule TEXT, post_url VARCHAR(500), post_id VARCHAR(100), message_id VARCHAR(100), -- 에러 정보 error_message TEXT, retries INTEGER DEFAULT 0, last_retry_at TIMESTAMP, -- 감사 정보 created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 외래 키 제약 조건 CONSTRAINT fk_channel_distribution_status FOREIGN KEY (distribution_status_id) REFERENCES distribution.distribution_status(id) ON DELETE CASCADE, -- 유니크 제약 조건 CONSTRAINT uk_channel_status_distribution_channel UNIQUE (distribution_status_id, channel), -- CHECK 제약 조건 CONSTRAINT ck_channel_status_channel CHECK ( channel IN ('URIDONGNETV', 'RINGOBIZ', 'GINITV', 'INSTAGRAM', 'NAVER', 'KAKAO') ), CONSTRAINT ck_channel_status_status CHECK ( status IN ('PENDING', 'IN_PROGRESS', 'SUCCESS', 'FAILED') ), CONSTRAINT ck_channel_status_progress CHECK ( progress BETWEEN 0 AND 100 ) ); -- 코멘트 추가 COMMENT ON TABLE distribution.channel_status IS '채널별 세부 배포 상태 및 성과 추적'; COMMENT ON COLUMN distribution.channel_status.id IS '채널 상태 ID (PK)'; COMMENT ON COLUMN distribution.channel_status.distribution_status_id IS '배포 상태 ID (FK)'; COMMENT ON COLUMN distribution.channel_status.channel IS '채널 타입 (URIDONGNETV, RINGOBIZ, GINITV, INSTAGRAM, NAVER, KAKAO)'; COMMENT ON COLUMN distribution.channel_status.status IS '채널 배포 상태 (PENDING, IN_PROGRESS, SUCCESS, FAILED)'; COMMENT ON COLUMN distribution.channel_status.progress IS '진행률 (0-100)'; COMMENT ON COLUMN distribution.channel_status.distribution_id IS '채널별 배포 ID (외부 시스템 ID)'; COMMENT ON COLUMN distribution.channel_status.estimated_views IS '예상 도달률 (조회수)'; COMMENT ON COLUMN distribution.channel_status.update_timestamp IS '상태 업데이트 시간'; COMMENT ON COLUMN distribution.channel_status.event_id IS '이벤트 ID (조회 최적화용)'; COMMENT ON COLUMN distribution.channel_status.impression_schedule IS '노출 일정 (JSON 배열)'; COMMENT ON COLUMN distribution.channel_status.post_url IS '게시물 URL'; COMMENT ON COLUMN distribution.channel_status.post_id IS '게시물 ID'; COMMENT ON COLUMN distribution.channel_status.message_id IS '메시지 ID (카카오톡)'; COMMENT ON COLUMN distribution.channel_status.completed_at IS '채널 배포 완료 시간'; COMMENT ON COLUMN distribution.channel_status.error_message IS '에러 메시지'; COMMENT ON COLUMN distribution.channel_status.retries IS '재시도 횟수'; COMMENT ON COLUMN distribution.channel_status.last_retry_at IS '마지막 재시도 시간'; COMMENT ON COLUMN distribution.channel_status.created_at IS '생성 시간'; COMMENT ON COLUMN distribution.channel_status.updated_at IS '수정 시간'; -- 인덱스 생성 CREATE INDEX idx_channel_status_event_id ON distribution.channel_status(event_id); CREATE INDEX idx_channel_status_event_channel ON distribution.channel_status(event_id, channel); CREATE INDEX idx_channel_status_status ON distribution.channel_status(status); CREATE INDEX idx_channel_status_distribution_status_id ON distribution.channel_status(distribution_status_id); -- ============================================================================ -- 5. 트리거 생성 (updated_at 자동 업데이트) -- ============================================================================ -- updated_at 자동 업데이트 함수 CREATE OR REPLACE FUNCTION distribution.update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = CURRENT_TIMESTAMP; RETURN NEW; END; $$ LANGUAGE plpgsql; -- distribution_status 테이블 트리거 CREATE TRIGGER trg_distribution_status_updated_at BEFORE UPDATE ON distribution.distribution_status FOR EACH ROW EXECUTE FUNCTION distribution.update_updated_at_column(); -- channel_status 테이블 트리거 CREATE TRIGGER trg_channel_status_updated_at BEFORE UPDATE ON distribution.channel_status FOR EACH ROW EXECUTE FUNCTION distribution.update_updated_at_column(); -- ============================================================================ -- 6. 샘플 데이터 삽입 (개발 환경용) -- ============================================================================ -- 주의: 운영 환경에서는 이 섹션을 제거해야 합니다. -- 샘플 배포 상태 1: 진행 중 INSERT INTO distribution.distribution_status ( event_id, overall_status, started_at, completed_at ) VALUES ( '123e4567-e89b-12d3-a456-426614174000', 'IN_PROGRESS', CURRENT_TIMESTAMP, NULL ); -- 샘플 채널 상태 1: Instagram (성공) INSERT INTO distribution.channel_status ( distribution_status_id, channel, status, progress, distribution_id, estimated_views, event_id, post_url, post_id ) VALUES ( 1, 'INSTAGRAM', 'SUCCESS', 100, 'ig_post_12345', 5000, '123e4567-e89b-12d3-a456-426614174000', 'https://instagram.com/p/abc123', 'abc123' ); -- 샘플 채널 상태 2: 카카오톡 (진행 중) INSERT INTO distribution.channel_status ( distribution_status_id, channel, status, progress, distribution_id, estimated_views, event_id, message_id ) VALUES ( 1, 'KAKAO', 'IN_PROGRESS', 75, 'kakao_msg_67890', 3000, '123e4567-e89b-12d3-a456-426614174000', 'msg_67890' ); -- 샘플 배포 상태 2: 완료 INSERT INTO distribution.distribution_status ( event_id, overall_status, started_at, completed_at ) VALUES ( '223e4567-e89b-12d3-a456-426614174001', 'COMPLETED', CURRENT_TIMESTAMP - INTERVAL '2 hours', CURRENT_TIMESTAMP - INTERVAL '1 hour' ); -- 샘플 채널 상태 3: 네이버 (성공) INSERT INTO distribution.channel_status ( distribution_status_id, channel, status, progress, distribution_id, estimated_views, event_id, post_url, post_id, completed_at ) VALUES ( 2, 'NAVER', 'SUCCESS', 100, 'naver_post_11111', 8000, '223e4567-e89b-12d3-a456-426614174001', 'https://blog.naver.com/post/11111', '11111', CURRENT_TIMESTAMP - INTERVAL '1 hour' ); -- ============================================================================ -- 7. 권한 설정 (필요시) -- ============================================================================ -- 애플리케이션 사용자 권한 부여 (예시) -- CREATE USER distribution_app WITH PASSWORD 'secure_password'; -- GRANT USAGE ON SCHEMA distribution TO distribution_app; -- GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA distribution TO distribution_app; -- GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA distribution TO distribution_app; -- ============================================================================ -- 8. 데이터 검증 쿼리 -- ============================================================================ -- 테이블 생성 확인 SELECT table_name, table_type FROM information_schema.tables WHERE table_schema = 'distribution' ORDER BY table_name; -- 제약 조건 확인 SELECT tc.constraint_name, tc.table_name, tc.constraint_type, kcu.column_name FROM information_schema.table_constraints tc JOIN information_schema.key_column_usage kcu ON tc.constraint_name = kcu.constraint_name AND tc.table_schema = kcu.table_schema WHERE tc.table_schema = 'distribution' ORDER BY tc.table_name, tc.constraint_type; -- 인덱스 확인 SELECT schemaname, tablename, indexname, indexdef FROM pg_indexes WHERE schemaname = 'distribution' ORDER BY tablename, indexname; -- 샘플 데이터 확인 SELECT ds.event_id, ds.overall_status, COUNT(cs.id) AS channel_count, SUM(CASE WHEN cs.status = 'SUCCESS' THEN 1 ELSE 0 END) AS success_count, SUM(cs.estimated_views) AS total_estimated_views FROM distribution.distribution_status ds LEFT JOIN distribution.channel_status cs ON ds.id = cs.distribution_status_id GROUP BY ds.event_id, ds.overall_status; -- ============================================================================ -- 9. 성능 모니터링 쿼리 (운영용) -- ============================================================================ -- 배포 상태별 통계 SELECT overall_status, COUNT(*) AS count, AVG(EXTRACT(EPOCH FROM (completed_at - started_at))) AS avg_duration_seconds FROM distribution.distribution_status WHERE completed_at IS NOT NULL GROUP BY overall_status; -- 채널별 성공률 SELECT channel, COUNT(*) AS total_distributions, SUM(CASE WHEN status = 'SUCCESS' THEN 1 ELSE 0 END) AS success_count, ROUND(100.0 * SUM(CASE WHEN status = 'SUCCESS' THEN 1 ELSE 0 END) / COUNT(*), 2) AS success_rate FROM distribution.channel_status GROUP BY channel ORDER BY success_rate DESC; -- 평균 재시도 횟수 SELECT channel, AVG(retries) AS avg_retries, MAX(retries) AS max_retries FROM distribution.channel_status WHERE retries > 0 GROUP BY channel ORDER BY avg_retries DESC; -- ============================================================================ -- 스키마 생성 완료 -- ============================================================================