mirror of
https://github.com/ktds-dg0501/kt-event-marketing.git
synced 2025-12-06 18:06:23 +00:00
모든 테이블의 외래키 제약조건을 주석처리: - event_channels.fk_event_channels_event - generated_images.fk_generated_images_event - ai_recommendations.fk_ai_recommendations_event - jobs.fk_jobs_event 사유: - JPA에서 연관관계 관리로 충분 - 개발 환경에서 유연성 확보 - 필요시 운영 환경에서 활성화 가능 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude <noreply@anthropic.com>
271 lines
11 KiB
PL/PgSQL
271 lines
11 KiB
PL/PgSQL
-- ============================================
|
|
-- Event Service Database DDL
|
|
-- ============================================
|
|
-- Description: Event Service 데이터베이스 테이블 생성 스크립트
|
|
-- Database: PostgreSQL 15+
|
|
-- Author: Event Service Team
|
|
-- Version: 1.0.0
|
|
-- Created: 2025-10-24
|
|
-- ============================================
|
|
|
|
-- UUID 확장 활성화 (PostgreSQL)
|
|
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
|
|
|
-- ============================================
|
|
-- 1. events 테이블
|
|
-- ============================================
|
|
-- 이벤트 마스터 테이블
|
|
-- 이벤트의 전체 생명주기(생성, 수정, 배포, 종료)를 관리
|
|
-- ============================================
|
|
|
|
CREATE TABLE IF NOT EXISTS events (
|
|
event_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
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),
|
|
created_at TIMESTAMP NOT NULL, -- Managed by JPA @CreatedDate
|
|
updated_at TIMESTAMP NOT NULL, -- Managed by JPA @LastModifiedDate
|
|
|
|
-- 제약조건
|
|
CONSTRAINT chk_event_period CHECK (start_date IS NULL OR end_date IS NULL OR start_date <= end_date),
|
|
CONSTRAINT chk_event_status CHECK (status IN ('DRAFT', 'PUBLISHED', 'ENDED'))
|
|
);
|
|
|
|
-- 인덱스
|
|
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_created_at ON events(created_at);
|
|
|
|
-- 복합 인덱스 (쿼리 성능 최적화)
|
|
CREATE INDEX idx_events_user_status_created ON events(user_id, status, created_at DESC);
|
|
|
|
-- 주석
|
|
COMMENT ON TABLE events IS '이벤트 마스터 테이블';
|
|
COMMENT ON COLUMN events.event_id IS '이벤트 ID (PK)';
|
|
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.created_at IS '생성일시';
|
|
COMMENT ON COLUMN events.updated_at IS '수정일시';
|
|
|
|
|
|
-- ============================================
|
|
-- 2. event_channels 테이블
|
|
-- ============================================
|
|
-- 이벤트 배포 채널 테이블
|
|
-- 이벤트별 배포 채널 정보 관리 (ElementCollection)
|
|
-- ============================================
|
|
|
|
CREATE TABLE IF NOT EXISTS event_channels (
|
|
event_id UUID NOT NULL,
|
|
channel VARCHAR(50) NOT NULL,
|
|
|
|
-- 제약조건
|
|
-- CONSTRAINT fk_event_channels_event FOREIGN KEY (event_id)
|
|
-- REFERENCES events(event_id) ON DELETE CASCADE,
|
|
CONSTRAINT pk_event_channels PRIMARY KEY (event_id, channel)
|
|
);
|
|
|
|
-- 인덱스
|
|
CREATE INDEX 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 (FK)';
|
|
COMMENT ON COLUMN event_channels.channel IS '배포 채널 (예: 카카오톡, 인스타그램 등)';
|
|
|
|
|
|
-- ============================================
|
|
-- 3. generated_images 테이블
|
|
-- ============================================
|
|
-- 생성된 이미지 테이블
|
|
-- 이벤트별로 생성된 이미지를 관리
|
|
-- ============================================
|
|
|
|
CREATE TABLE IF NOT EXISTS generated_images (
|
|
image_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
event_id UUID 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, -- Managed by JPA @CreatedDate
|
|
updated_at TIMESTAMP NOT NULL, -- Managed by JPA @LastModifiedDate
|
|
|
|
-- 제약조건
|
|
-- CONSTRAINT fk_generated_images_event FOREIGN KEY (event_id)
|
|
-- REFERENCES events(event_id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- 인덱스
|
|
CREATE INDEX idx_generated_images_event_id ON generated_images(event_id);
|
|
CREATE INDEX idx_generated_images_is_selected ON generated_images(is_selected);
|
|
|
|
-- 복합 인덱스 (이벤트별 선택 이미지 조회 최적화)
|
|
CREATE INDEX idx_generated_images_event_selected ON generated_images(event_id, is_selected);
|
|
|
|
-- 주석
|
|
COMMENT ON TABLE generated_images IS '생성된 이미지 테이블';
|
|
COMMENT ON COLUMN generated_images.image_id IS '이미지 ID (PK)';
|
|
COMMENT ON COLUMN generated_images.event_id IS '이벤트 ID (FK)';
|
|
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 추천 테이블
|
|
-- AI가 추천한 이벤트 기획안을 관리
|
|
-- ============================================
|
|
|
|
CREATE TABLE IF NOT EXISTS ai_recommendations (
|
|
recommendation_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
event_id UUID 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, -- Managed by JPA @CreatedDate
|
|
updated_at TIMESTAMP NOT NULL, -- Managed by JPA @LastModifiedDate
|
|
|
|
-- 제약조건
|
|
-- CONSTRAINT fk_ai_recommendations_event FOREIGN KEY (event_id)
|
|
-- REFERENCES events(event_id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- 인덱스
|
|
CREATE INDEX idx_ai_recommendations_event_id ON ai_recommendations(event_id);
|
|
CREATE INDEX idx_ai_recommendations_is_selected ON ai_recommendations(is_selected);
|
|
|
|
-- 복합 인덱스 (이벤트별 선택 추천 조회 최적화)
|
|
CREATE INDEX idx_ai_recommendations_event_selected ON ai_recommendations(event_id, is_selected);
|
|
|
|
-- 주석
|
|
COMMENT ON TABLE ai_recommendations IS 'AI 추천 이벤트 기획안 테이블';
|
|
COMMENT ON COLUMN ai_recommendations.recommendation_id IS '추천 ID (PK)';
|
|
COMMENT ON COLUMN ai_recommendations.event_id IS '이벤트 ID (FK)';
|
|
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 테이블
|
|
-- ============================================
|
|
-- 비동기 작업 테이블
|
|
-- AI 추천 생성, 이미지 생성 등의 비동기 작업 상태를 관리
|
|
-- ============================================
|
|
|
|
CREATE TABLE IF NOT EXISTS jobs (
|
|
job_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
event_id UUID NOT NULL,
|
|
job_type VARCHAR(30) NOT NULL,
|
|
status VARCHAR(20) NOT NULL DEFAULT 'PENDING',
|
|
progress INT NOT NULL DEFAULT 0,
|
|
result_key VARCHAR(200),
|
|
error_message VARCHAR(500),
|
|
completed_at TIMESTAMP,
|
|
created_at TIMESTAMP NOT NULL, -- Managed by JPA @CreatedDate
|
|
updated_at TIMESTAMP NOT NULL, -- Managed by JPA @LastModifiedDate
|
|
|
|
-- 제약조건
|
|
-- CONSTRAINT fk_jobs_event FOREIGN KEY (event_id)
|
|
-- REFERENCES events(event_id) ON DELETE CASCADE,
|
|
CONSTRAINT chk_job_type CHECK (job_type IN ('AI_RECOMMENDATION', 'IMAGE_GENERATION')),
|
|
CONSTRAINT chk_job_status CHECK (status IN ('PENDING', 'PROCESSING', 'COMPLETED', 'FAILED')),
|
|
CONSTRAINT chk_job_progress CHECK (progress >= 0 AND progress <= 100)
|
|
);
|
|
|
|
-- 인덱스
|
|
CREATE INDEX idx_jobs_event_id ON jobs(event_id);
|
|
CREATE INDEX idx_jobs_status ON jobs(status);
|
|
CREATE INDEX idx_jobs_created_at ON jobs(created_at);
|
|
|
|
-- 복합 인덱스 (상태별 최신 작업 조회 최적화)
|
|
CREATE INDEX idx_jobs_status_created ON jobs(status, created_at DESC);
|
|
|
|
-- 주석
|
|
COMMENT ON TABLE jobs IS '비동기 작업 테이블';
|
|
COMMENT ON COLUMN jobs.job_id IS '작업 ID (PK)';
|
|
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 캐시 키 또는 리소스 식별자)';
|
|
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 '수정일시';
|
|
|
|
|
|
-- ============================================
|
|
-- Trigger for updated_at (자동 업데이트)
|
|
-- ============================================
|
|
-- NOTE: updated_at 필드는 JPA @LastModifiedDate 어노테이션으로 관리됩니다.
|
|
-- 따라서 PostgreSQL Trigger는 사용하지 않습니다.
|
|
-- JPA 환경에서는 애플리케이션 레벨에서 자동으로 updated_at이 갱신됩니다.
|
|
--
|
|
-- 만약 JPA 외부에서 직접 SQL로 데이터를 수정하는 경우,
|
|
-- 아래 Trigger를 활성화할 수 있습니다.
|
|
|
|
-- 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 update_events_updated_at BEFORE UPDATE ON events
|
|
-- FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
-- 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 테이블 트리거 (비활성화)
|
|
-- CREATE TRIGGER update_ai_recommendations_updated_at BEFORE UPDATE ON ai_recommendations
|
|
-- FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
-- jobs 테이블 트리거 (비활성화)
|
|
-- CREATE TRIGGER update_jobs_updated_at BEFORE UPDATE ON jobs
|
|
-- FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
|
|
-- ============================================
|
|
-- 샘플 데이터 (선택 사항)
|
|
-- ============================================
|
|
-- 개발/테스트 환경에서만 사용
|
|
|
|
-- 샘플 이벤트
|
|
-- INSERT INTO events (event_id, user_id, store_id, event_name, description, objective, start_date, end_date, status)
|
|
-- VALUES
|
|
-- (uuid_generate_v4(), uuid_generate_v4(), uuid_generate_v4(), '신규 고객 환영 이벤트', '첫 방문 고객 10% 할인', '신규 고객 유치', '2025-11-01', '2025-11-30', 'DRAFT');
|