주요 변경사항: - 게시판 계층형 댓글/답글 시스템 구현 - DB: root_idx, depth, thread_path, is_comment, reply_count 컬럼 추가 - 트리거: 댓글 개수 자동 업데이트 - 답글(is_comment=false)은 목록에 표시, 댓글(is_comment=true)은 뷰어에만 표시 - ESC 키로 모달 닫기 기능 - 업무일지 개선 - 프로젝트 선택 시 최종 설정 자동 불러오기 - 복사 시 jobgrp, tag 포함 - 완료(보고) 상태 프로젝트도 검색 가능하도록 수정 - 대시보드 개선 - 할일 목록 페이징 추가 (6개씩) - 할일에 요청자 정보 표시 (제목 좌측에 괄호로)
328 lines
9.1 KiB
Transact-SQL
328 lines
9.1 KiB
Transact-SQL
-- =============================================
|
|
-- EETGW_Board 테이블 구조 변경: 댓글/답글 시스템 추가
|
|
-- 작성일: 2025-12-03
|
|
-- 설명: 계층형 댓글/답글을 효율적으로 관리하기 위한 컬럼 추가
|
|
-- =============================================
|
|
|
|
USE [EETGW]
|
|
GO
|
|
|
|
PRINT '=== Starting EETGW_Board structure update ===';
|
|
PRINT 'Timestamp: ' + CONVERT(VARCHAR(20), GETDATE(), 120);
|
|
GO
|
|
|
|
-- 1. 기존 테이블 백업
|
|
IF NOT EXISTS (SELECT * FROM sys.tables WHERE name = 'EETGW_Board_Backup_20251203')
|
|
BEGIN
|
|
SELECT * INTO EETGW_Board_Backup_20251203 FROM EETGW_Board;
|
|
PRINT '✓ Backup created: EETGW_Board_Backup_20251203';
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
PRINT '⚠ Backup already exists: EETGW_Board_Backup_20251203';
|
|
END
|
|
GO
|
|
|
|
-- 2. 새로운 컬럼 추가
|
|
PRINT '';
|
|
PRINT '--- Adding new columns ---';
|
|
|
|
-- root_idx: 최상위 원글의 idx (답글/댓글이 어느 글에 속하는지)
|
|
IF NOT EXISTS (SELECT * FROM sys.columns WHERE object_id = OBJECT_ID('EETGW_Board') AND name = 'root_idx')
|
|
BEGIN
|
|
ALTER TABLE EETGW_Board ADD root_idx INT NULL;
|
|
PRINT '✓ Added column: root_idx (최상위 원글 idx)';
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
PRINT '⊙ Column already exists: root_idx';
|
|
END
|
|
GO
|
|
|
|
-- depth: 댓글 깊이 (0=원글, 1=1차댓글, 2=2차댓글...)
|
|
IF NOT EXISTS (SELECT * FROM sys.columns WHERE object_id = OBJECT_ID('EETGW_Board') AND name = 'depth')
|
|
BEGIN
|
|
ALTER TABLE EETGW_Board ADD depth INT NOT NULL DEFAULT 0;
|
|
PRINT '✓ Added column: depth (댓글 깊이)';
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
PRINT '⊙ Column already exists: depth';
|
|
END
|
|
GO
|
|
|
|
-- sort_order: 같은 레벨에서의 정렬 순서
|
|
IF NOT EXISTS (SELECT * FROM sys.columns WHERE object_id = OBJECT_ID('EETGW_Board') AND name = 'sort_order')
|
|
BEGIN
|
|
ALTER TABLE EETGW_Board ADD sort_order INT NOT NULL DEFAULT 0;
|
|
PRINT '✓ Added column: sort_order (정렬 순서)';
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
PRINT '⊙ Column already exists: sort_order';
|
|
END
|
|
GO
|
|
|
|
-- thread_path: 계층 경로 (예: "1/5/12" - 빠른 정렬과 조회용)
|
|
IF NOT EXISTS (SELECT * FROM sys.columns WHERE object_id = OBJECT_ID('EETGW_Board') AND name = 'thread_path')
|
|
BEGIN
|
|
ALTER TABLE EETGW_Board ADD thread_path VARCHAR(1000) NULL;
|
|
PRINT '✓ Added column: thread_path (계층 경로)';
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
PRINT '⊙ Column already exists: thread_path';
|
|
END
|
|
GO
|
|
|
|
-- is_comment: 댓글 여부 (true=댓글형식, false=답글형식)
|
|
IF NOT EXISTS (SELECT * FROM sys.columns WHERE object_id = OBJECT_ID('EETGW_Board') AND name = 'is_comment')
|
|
BEGIN
|
|
ALTER TABLE EETGW_Board ADD is_comment BIT NOT NULL DEFAULT 0;
|
|
PRINT '✓ Added column: is_comment (댓글/답글 구분)';
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
PRINT '⊙ Column already exists: is_comment';
|
|
END
|
|
GO
|
|
|
|
-- reply_count: 하위 댓글/답글 개수 (캐시용)
|
|
IF NOT EXISTS (SELECT * FROM sys.columns WHERE object_id = OBJECT_ID('EETGW_Board') AND name = 'reply_count')
|
|
BEGIN
|
|
ALTER TABLE EETGW_Board ADD reply_count INT NOT NULL DEFAULT 0;
|
|
PRINT '✓ Added column: reply_count (댓글 개수 캐시)';
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
PRINT '⊙ Column already exists: reply_count';
|
|
END
|
|
GO
|
|
|
|
-- 3. 기존 데이터 마이그레이션
|
|
PRINT '';
|
|
PRINT '--- Migrating existing data ---';
|
|
|
|
-- 원글(pidx가 0이거나 NULL인 경우)
|
|
UPDATE EETGW_Board
|
|
SET
|
|
root_idx = idx,
|
|
depth = 0,
|
|
thread_path = CAST(idx AS VARCHAR(20)),
|
|
sort_order = 0,
|
|
is_comment = 0
|
|
WHERE ISNULL(pidx, 0) = 0 AND (root_idx IS NULL OR thread_path IS NULL);
|
|
|
|
DECLARE @originalCount INT = @@ROWCOUNT;
|
|
PRINT '✓ Updated ' + CAST(@originalCount AS VARCHAR(10)) + ' original posts (depth=0)';
|
|
|
|
-- 답글(pidx가 있는 경우) - 1depth만 처리
|
|
UPDATE b
|
|
SET
|
|
root_idx = ISNULL(p.root_idx, b.pidx),
|
|
depth = CASE WHEN p.depth IS NULL THEN 1 ELSE p.depth + 1 END,
|
|
thread_path = ISNULL(p.thread_path, CAST(b.pidx AS VARCHAR(20))) + '/' + CAST(b.idx AS VARCHAR(20)),
|
|
sort_order = 0,
|
|
is_comment = 0
|
|
FROM EETGW_Board b
|
|
LEFT JOIN EETGW_Board p ON b.pidx = p.idx
|
|
WHERE ISNULL(b.pidx, 0) > 0 AND (b.root_idx IS NULL OR b.thread_path IS NULL);
|
|
|
|
DECLARE @replyCount INT = @@ROWCOUNT;
|
|
PRINT '✓ Updated ' + CAST(@replyCount AS VARCHAR(10)) + ' reply posts';
|
|
GO
|
|
|
|
-- 4. 인덱스 추가 (성능 최적화)
|
|
PRINT '';
|
|
PRINT '--- Creating indexes ---';
|
|
|
|
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_EETGW_Board_root_idx_thread_path')
|
|
BEGIN
|
|
CREATE INDEX IX_EETGW_Board_root_idx_thread_path
|
|
ON EETGW_Board(root_idx, thread_path);
|
|
PRINT '✓ Created index: IX_EETGW_Board_root_idx_thread_path';
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
PRINT '⊙ Index already exists: IX_EETGW_Board_root_idx_thread_path';
|
|
END
|
|
GO
|
|
|
|
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_EETGW_Board_pidx')
|
|
BEGIN
|
|
CREATE INDEX IX_EETGW_Board_pidx
|
|
ON EETGW_Board(pidx);
|
|
PRINT '✓ Created index: IX_EETGW_Board_pidx';
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
PRINT '⊙ Index already exists: IX_EETGW_Board_pidx';
|
|
END
|
|
GO
|
|
|
|
IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_EETGW_Board_bidx_wdate')
|
|
BEGIN
|
|
CREATE INDEX IX_EETGW_Board_bidx_wdate
|
|
ON EETGW_Board(bidx, wdate DESC);
|
|
PRINT '✓ Created index: IX_EETGW_Board_bidx_wdate';
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
PRINT '⊙ Index already exists: IX_EETGW_Board_bidx_wdate';
|
|
END
|
|
GO
|
|
|
|
-- 5. reply_count 업데이트 (기존 데이터 기준)
|
|
PRINT '';
|
|
PRINT '--- Updating reply counts ---';
|
|
|
|
UPDATE p
|
|
SET reply_count = (
|
|
SELECT COUNT(*)
|
|
FROM EETGW_Board c
|
|
WHERE c.root_idx = p.idx AND c.depth > 0
|
|
)
|
|
FROM EETGW_Board p
|
|
WHERE p.depth = 0;
|
|
|
|
DECLARE @updatedRootPosts INT = @@ROWCOUNT;
|
|
PRINT '✓ Updated reply_count for ' + CAST(@updatedRootPosts AS VARCHAR(10)) + ' root posts';
|
|
GO
|
|
|
|
-- 6. 트리거 생성 (reply_count 자동 업데이트)
|
|
PRINT '';
|
|
PRINT '--- Creating triggers ---';
|
|
|
|
IF EXISTS (SELECT * FROM sys.triggers WHERE name = 'TR_EETGW_Board_AfterInsert')
|
|
BEGIN
|
|
DROP TRIGGER TR_EETGW_Board_AfterInsert;
|
|
PRINT '⊙ Dropped existing trigger: TR_EETGW_Board_AfterInsert';
|
|
END
|
|
GO
|
|
|
|
CREATE TRIGGER TR_EETGW_Board_AfterInsert
|
|
ON EETGW_Board
|
|
AFTER INSERT
|
|
AS
|
|
BEGIN
|
|
SET NOCOUNT ON;
|
|
|
|
-- 댓글/답글이 추가된 경우 root_idx의 reply_count 증가
|
|
UPDATE b
|
|
SET b.reply_count = b.reply_count + 1
|
|
FROM EETGW_Board b
|
|
INNER JOIN inserted i ON b.idx = i.root_idx
|
|
WHERE i.root_idx IS NOT NULL AND i.depth > 0;
|
|
END
|
|
GO
|
|
|
|
PRINT '✓ Created trigger: TR_EETGW_Board_AfterInsert';
|
|
GO
|
|
|
|
IF EXISTS (SELECT * FROM sys.triggers WHERE name = 'TR_EETGW_Board_AfterDelete')
|
|
BEGIN
|
|
DROP TRIGGER TR_EETGW_Board_AfterDelete;
|
|
PRINT '⊙ Dropped existing trigger: TR_EETGW_Board_AfterDelete';
|
|
END
|
|
GO
|
|
|
|
CREATE TRIGGER TR_EETGW_Board_AfterDelete
|
|
ON EETGW_Board
|
|
AFTER DELETE
|
|
AS
|
|
BEGIN
|
|
SET NOCOUNT ON;
|
|
|
|
-- 댓글/답글이 삭제된 경우 root_idx의 reply_count 감소
|
|
UPDATE b
|
|
SET b.reply_count = b.reply_count - 1
|
|
FROM EETGW_Board b
|
|
INNER JOIN deleted d ON b.idx = d.root_idx
|
|
WHERE d.root_idx IS NOT NULL AND d.depth > 0 AND b.reply_count > 0;
|
|
END
|
|
GO
|
|
|
|
PRINT '✓ Created trigger: TR_EETGW_Board_AfterDelete';
|
|
GO
|
|
|
|
-- 7. 조회용 뷰 생성 (옵션)
|
|
PRINT '';
|
|
PRINT '--- Creating views ---';
|
|
|
|
IF EXISTS (SELECT * FROM sys.views WHERE name = 'vEETGW_Board_WithReplies')
|
|
BEGIN
|
|
DROP VIEW vEETGW_Board_WithReplies;
|
|
PRINT '⊙ Dropped existing view: vEETGW_Board_WithReplies';
|
|
END
|
|
GO
|
|
|
|
CREATE VIEW vEETGW_Board_WithReplies
|
|
AS
|
|
SELECT
|
|
b.idx,
|
|
b.bidx,
|
|
b.header,
|
|
b.cate,
|
|
b.title,
|
|
b.contents,
|
|
b.[file],
|
|
b.guid,
|
|
b.url,
|
|
b.wuid,
|
|
b.wdate,
|
|
b.project,
|
|
b.pidx,
|
|
b.gcode,
|
|
b.[close],
|
|
b.remark,
|
|
b.root_idx,
|
|
b.depth,
|
|
b.sort_order,
|
|
b.thread_path,
|
|
b.is_comment,
|
|
b.reply_count,
|
|
dbo.getUserName(b.wuid) AS wuid_name,
|
|
CASE WHEN b.depth = 0 THEN b.idx ELSE b.root_idx END AS display_root_idx
|
|
FROM EETGW_Board b;
|
|
GO
|
|
|
|
PRINT '✓ Created view: vEETGW_Board_WithReplies';
|
|
GO
|
|
|
|
-- 8. 검증 쿼리
|
|
PRINT '';
|
|
PRINT '--- Verification ---';
|
|
|
|
DECLARE @totalPosts INT = (SELECT COUNT(*) FROM EETGW_Board);
|
|
DECLARE @rootPosts INT = (SELECT COUNT(*) FROM EETGW_Board WHERE depth = 0);
|
|
DECLARE @replyPosts INT = (SELECT COUNT(*) FROM EETGW_Board WHERE depth > 0);
|
|
|
|
PRINT 'Total posts: ' + CAST(@totalPosts AS VARCHAR(10));
|
|
PRINT 'Root posts (depth=0): ' + CAST(@rootPosts AS VARCHAR(10));
|
|
PRINT 'Reply posts (depth>0): ' + CAST(@replyPosts AS VARCHAR(10));
|
|
GO
|
|
|
|
PRINT '';
|
|
PRINT '=== EETGW_Board structure update completed successfully ===';
|
|
PRINT '';
|
|
PRINT '📋 New columns added:';
|
|
PRINT ' • root_idx: 최상위 원글 idx';
|
|
PRINT ' • depth: 댓글 깊이 (0=원글, 1=1차댓글, 2=2차댓글...)';
|
|
PRINT ' • sort_order: 같은 레벨에서 정렬 순서';
|
|
PRINT ' • thread_path: 계층 경로 (빠른 정렬용)';
|
|
PRINT ' • is_comment: 댓글 타입 (0=답글, 1=댓글)';
|
|
PRINT ' • reply_count: 하위 댓글 개수';
|
|
PRINT '';
|
|
PRINT '📝 Usage examples:';
|
|
PRINT ' -- 원글 목록 (댓글 개수 포함)';
|
|
PRINT ' SELECT * FROM EETGW_Board WHERE bidx = 5 AND depth = 0 ORDER BY wdate DESC;';
|
|
PRINT '';
|
|
PRINT ' -- 특정 글의 전체 댓글 (계층 구조 유지)';
|
|
PRINT ' SELECT * FROM EETGW_Board WHERE root_idx = 123 ORDER BY thread_path, wdate;';
|
|
PRINT '';
|
|
PRINT ' -- 1depth 댓글만 조회';
|
|
PRINT ' SELECT * FROM EETGW_Board WHERE root_idx = 123 AND depth = 1 ORDER BY wdate;';
|
|
PRINT '';
|
|
PRINT '✅ Migration completed at: ' + CONVERT(VARCHAR(20), GETDATE(), 120);
|
|
GO
|