kt-event-marketing/develop/database/schema/create_event_tables.sql

234 lines
11 KiB
PL/PgSQL

-- ====================================================================================================
-- Event Service 테이블 생성 스크립트 - PostgreSQL
-- ====================================================================================================
-- 작성일: 2025-10-29
-- 작성자: Backend Development Team
-- 설명: Event 서비스의 모든 테이블을 생성합니다.
-- 참고: FK(Foreign Key) 제약조건은 제외되어 있습니다.
-- ====================================================================================================
-- ====================================================================================================
-- 1. events 테이블 - 이벤트 메인 테이블
-- ====================================================================================================
CREATE TABLE IF NOT EXISTS events (
event_id VARCHAR(50) PRIMARY KEY,
user_id VARCHAR(50) NOT NULL,
store_id VARCHAR(50) 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 VARCHAR(50),
selected_image_url VARCHAR(500),
participants INTEGER DEFAULT 0,
target_participants INTEGER,
roi DOUBLE PRECISION DEFAULT 0.0,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
);
-- events 테이블 인덱스
CREATE INDEX IF NOT EXISTS idx_events_user_id ON events(user_id);
CREATE INDEX IF NOT EXISTS idx_events_store_id ON events(store_id);
CREATE INDEX IF NOT EXISTS idx_events_status ON events(status);
CREATE INDEX IF NOT EXISTS idx_events_created_at ON events(created_at);
COMMENT ON TABLE events IS '이벤트 메인 테이블';
COMMENT ON COLUMN events.event_id IS '이벤트 ID (Primary Key)';
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';
COMMENT ON COLUMN events.participants IS '참여자 수';
COMMENT ON COLUMN events.target_participants IS '목표 참여자 수';
COMMENT ON COLUMN events.roi IS 'ROI (투자 대비 수익률)';
COMMENT ON COLUMN events.created_at IS '생성일시';
COMMENT ON COLUMN events.updated_at IS '수정일시';
-- ====================================================================================================
-- 2. event_channels 테이블 - 이벤트 배포 채널 (ElementCollection)
-- ====================================================================================================
CREATE TABLE IF NOT EXISTS event_channels (
event_id VARCHAR(50) NOT NULL,
channel VARCHAR(50)
);
-- event_channels 테이블 인덱스
CREATE INDEX IF NOT EXISTS idx_event_channels_event_id ON event_channels(event_id);
COMMENT ON TABLE event_channels IS '이벤트 배포 채널 테이블';
COMMENT ON COLUMN event_channels.event_id IS '이벤트 ID';
COMMENT ON COLUMN event_channels.channel IS '배포 채널명';
-- ====================================================================================================
-- 3. generated_images 테이블 - 생성된 이미지
-- ====================================================================================================
CREATE TABLE IF NOT EXISTS generated_images (
image_id VARCHAR(50) PRIMARY KEY,
event_id VARCHAR(50) NOT NULL,
image_url VARCHAR(500) NOT NULL,
style VARCHAR(50),
platform VARCHAR(50),
is_selected BOOLEAN NOT NULL DEFAULT false,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
);
-- generated_images 테이블 인덱스
CREATE INDEX IF NOT EXISTS idx_generated_images_event_id ON generated_images(event_id);
CREATE INDEX IF NOT EXISTS idx_generated_images_is_selected ON generated_images(is_selected);
COMMENT ON TABLE generated_images IS 'AI가 생성한 이미지 테이블';
COMMENT ON COLUMN generated_images.image_id IS '이미지 ID (Primary Key)';
COMMENT ON COLUMN generated_images.event_id IS '이벤트 ID';
COMMENT ON COLUMN generated_images.image_url IS '이미지 URL';
COMMENT ON COLUMN generated_images.style IS '이미지 스타일';
COMMENT ON COLUMN generated_images.platform IS '타겟 플랫폼';
COMMENT ON COLUMN generated_images.is_selected IS '선택 여부';
COMMENT ON COLUMN generated_images.created_at IS '생성일시';
COMMENT ON COLUMN generated_images.updated_at IS '수정일시';
-- ====================================================================================================
-- 4. ai_recommendations 테이블 - AI 추천 기획안
-- ====================================================================================================
CREATE TABLE IF NOT EXISTS ai_recommendations (
recommendation_id VARCHAR(50) PRIMARY KEY,
event_id VARCHAR(50) NOT NULL,
event_name VARCHAR(200) NOT NULL,
description TEXT,
promotion_type VARCHAR(50),
target_audience VARCHAR(100),
is_selected BOOLEAN NOT NULL DEFAULT false,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
);
-- ai_recommendations 테이블 인덱스
CREATE INDEX IF NOT EXISTS idx_ai_recommendations_event_id ON ai_recommendations(event_id);
CREATE INDEX IF NOT EXISTS idx_ai_recommendations_is_selected ON ai_recommendations(is_selected);
COMMENT ON TABLE ai_recommendations IS 'AI 추천 이벤트 기획안 테이블';
COMMENT ON COLUMN ai_recommendations.recommendation_id IS '추천 ID (Primary Key)';
COMMENT ON COLUMN ai_recommendations.event_id IS '이벤트 ID';
COMMENT ON COLUMN ai_recommendations.event_name IS '추천 이벤트명';
COMMENT ON COLUMN ai_recommendations.description IS '추천 설명';
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 '수정일시';
-- ====================================================================================================
-- 5. jobs 테이블 - 비동기 작업 관리
-- ====================================================================================================
CREATE TABLE IF NOT EXISTS jobs (
job_id VARCHAR(50) PRIMARY KEY,
event_id VARCHAR(50) NOT NULL,
job_type VARCHAR(30) NOT NULL,
status VARCHAR(20) NOT NULL DEFAULT 'PENDING',
progress INTEGER NOT NULL DEFAULT 0,
result_key VARCHAR(200),
error_message VARCHAR(500),
completed_at TIMESTAMP,
retry_count INTEGER NOT NULL DEFAULT 0,
max_retry_count INTEGER NOT NULL DEFAULT 3,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
);
-- jobs 테이블 인덱스
CREATE INDEX IF NOT EXISTS idx_jobs_event_id ON jobs(event_id);
CREATE INDEX IF NOT EXISTS idx_jobs_status ON jobs(status);
CREATE INDEX IF NOT EXISTS idx_jobs_job_type ON jobs(job_type);
CREATE INDEX IF NOT EXISTS idx_jobs_created_at ON jobs(created_at);
COMMENT ON TABLE jobs IS '비동기 작업 관리 테이블';
COMMENT ON COLUMN jobs.job_id IS '작업 ID (Primary Key)';
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 '결과 키';
COMMENT ON COLUMN jobs.error_message IS '에러 메시지';
COMMENT ON COLUMN jobs.completed_at IS '완료일시';
COMMENT ON COLUMN jobs.retry_count IS '재시도 횟수';
COMMENT ON COLUMN jobs.max_retry_count IS '최대 재시도 횟수';
COMMENT ON COLUMN jobs.created_at IS '생성일시';
COMMENT ON COLUMN jobs.updated_at IS '수정일시';
-- ====================================================================================================
-- 6. updated_at 자동 업데이트를 위한 트리거 함수 생성
-- ====================================================================================================
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = CURRENT_TIMESTAMP;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- ====================================================================================================
-- 7. 각 테이블에 updated_at 자동 업데이트 트리거 적용
-- ====================================================================================================
-- events 테이블 트리거
DROP TRIGGER IF EXISTS update_events_updated_at ON events;
CREATE TRIGGER update_events_updated_at
BEFORE UPDATE ON events
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();
-- generated_images 테이블 트리거
DROP TRIGGER IF EXISTS update_generated_images_updated_at ON generated_images;
CREATE TRIGGER update_generated_images_updated_at
BEFORE UPDATE ON generated_images
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();
-- ai_recommendations 테이블 트리거
DROP TRIGGER IF EXISTS update_ai_recommendations_updated_at ON ai_recommendations;
CREATE TRIGGER update_ai_recommendations_updated_at
BEFORE UPDATE ON ai_recommendations
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();
-- jobs 테이블 트리거
DROP TRIGGER IF EXISTS update_jobs_updated_at ON jobs;
CREATE TRIGGER update_jobs_updated_at
BEFORE UPDATE ON jobs
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();
-- ====================================================================================================
-- 완료 메시지
-- ====================================================================================================
DO $$
BEGIN
RAISE NOTICE '=================================================';
RAISE NOTICE 'Event Service 테이블 생성이 완료되었습니다.';
RAISE NOTICE '=================================================';
RAISE NOTICE '생성된 테이블:';
RAISE NOTICE ' 1. events - 이벤트 메인 테이블';
RAISE NOTICE ' 2. event_channels - 이벤트 배포 채널';
RAISE NOTICE ' 3. generated_images - 생성된 이미지';
RAISE NOTICE ' 4. ai_recommendations - AI 추천 기획안';
RAISE NOTICE ' 5. jobs - 비동기 작업 관리';
RAISE NOTICE '=================================================';
RAISE NOTICE '참고: FK 제약조건은 생성되지 않았습니다.';
RAISE NOTICE '=================================================';
END $$;