012_add_vendor_list_essential_columns.sql 4.8 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134
  1. -- DDL 012: VENDOR_LIST 필수 컬럼 추가
  2. -- 목적: 벤더사 검색 기능에 필요한 컬럼들 추가
  3. -- 현재 테이블 구조 확인 (참고용)
  4. -- DESCRIBE VENDOR_LIST;
  5. -- 1. CATEGORY 컬럼 추가 (이미 존재하면 오류 발생하므로 개별 실행)
  6. -- ALTER TABLE `VENDOR_LIST` ADD COLUMN `CATEGORY` varchar(50) DEFAULT NULL COMMENT '사업 카테고리: FASHION_BEAUTY, FOOD_HEALTH, LIFESTYLE, TECH_ELECTRONICS, SPORTS_LEISURE, CULTURE_ENTERTAINMENT';
  7. -- 2. REGION 컬럼 추가
  8. -- ALTER TABLE `VENDOR_LIST` ADD COLUMN `REGION` varchar(50) DEFAULT NULL COMMENT '지역: SEOUL, GYEONGGI, INCHEON, BUSAN, DAEGU, DAEJEON, GWANGJU, ULSAN, OTHER';
  9. -- 3. DESCRIPTION 컬럼 추가
  10. -- ALTER TABLE `VENDOR_LIST` ADD COLUMN `DESCRIPTION` text DEFAULT NULL COMMENT '벤더사 설명';
  11. -- 4. LOGO 컬럼 추가
  12. -- ALTER TABLE `VENDOR_LIST` ADD COLUMN `LOGO` varchar(500) DEFAULT NULL COMMENT '로고 이미지 URL';
  13. -- 5. TAGS 컬럼 추가
  14. -- ALTER TABLE `VENDOR_LIST` ADD COLUMN `TAGS` varchar(500) DEFAULT NULL COMMENT '검색 태그 (콤마 구분)';
  15. -- 6. APPROVAL_STATUS 컬럼 추가
  16. -- ALTER TABLE `VENDOR_LIST` ADD COLUMN `APPROVAL_STATUS` varchar(20) DEFAULT 'PENDING' COMMENT '승인 상태: PENDING, APPROVED, REJECTED';
  17. -- 7. APPROVED_DATE 컬럼 추가
  18. -- ALTER TABLE `VENDOR_LIST` ADD COLUMN `APPROVED_DATE` timestamp NULL DEFAULT NULL COMMENT '승인일시';
  19. -- ========================================
  20. -- 실행 방법 (DBeaver에서 개별 실행)
  21. -- ========================================
  22. -- 1단계: 현재 컬럼 확인
  23. SELECT COLUMN_NAME
  24. FROM INFORMATION_SCHEMA.COLUMNS
  25. WHERE TABLE_NAME = 'VENDOR_LIST'
  26. AND TABLE_SCHEMA = DATABASE()
  27. ORDER BY ORDINAL_POSITION;
  28. -- 2단계: 없는 컬럼만 개별 실행
  29. -- 위 주석 처리된 ALTER TABLE 문들을 필요에 따라 개별 실행
  30. -- ========================================
  31. -- 한번에 실행하는 버전 (컬럼이 없는 경우에만)
  32. -- ========================================
  33. -- CATEGORY 컬럼 존재 확인 및 추가
  34. SET @col_exists = 0;
  35. SELECT COUNT(*) INTO @col_exists
  36. FROM INFORMATION_SCHEMA.COLUMNS
  37. WHERE TABLE_NAME = 'VENDOR_LIST'
  38. AND COLUMN_NAME = 'CATEGORY'
  39. AND TABLE_SCHEMA = DATABASE();
  40. SET @sql = IF(@col_exists = 0,
  41. 'ALTER TABLE `VENDOR_LIST` ADD COLUMN `CATEGORY` varchar(50) DEFAULT NULL COMMENT ''사업 카테고리''',
  42. 'SELECT ''CATEGORY column already exists'' as message');
  43. PREPARE stmt FROM @sql;
  44. EXECUTE stmt;
  45. DEALLOCATE PREPARE stmt;
  46. -- REGION 컬럼 존재 확인 및 추가
  47. SET @col_exists = 0;
  48. SELECT COUNT(*) INTO @col_exists
  49. FROM INFORMATION_SCHEMA.COLUMNS
  50. WHERE TABLE_NAME = 'VENDOR_LIST'
  51. AND COLUMN_NAME = 'REGION'
  52. AND TABLE_SCHEMA = DATABASE();
  53. SET @sql = IF(@col_exists = 0,
  54. 'ALTER TABLE `VENDOR_LIST` ADD COLUMN `REGION` varchar(50) DEFAULT NULL COMMENT ''지역''',
  55. 'SELECT ''REGION column already exists'' as message');
  56. PREPARE stmt FROM @sql;
  57. EXECUTE stmt;
  58. DEALLOCATE PREPARE stmt;
  59. -- DESCRIPTION 컬럼 존재 확인 및 추가
  60. SET @col_exists = 0;
  61. SELECT COUNT(*) INTO @col_exists
  62. FROM INFORMATION_SCHEMA.COLUMNS
  63. WHERE TABLE_NAME = 'VENDOR_LIST'
  64. AND COLUMN_NAME = 'DESCRIPTION'
  65. AND TABLE_SCHEMA = DATABASE();
  66. SET @sql = IF(@col_exists = 0,
  67. 'ALTER TABLE `VENDOR_LIST` ADD COLUMN `DESCRIPTION` text DEFAULT NULL COMMENT ''벤더사 설명''',
  68. 'SELECT ''DESCRIPTION column already exists'' as message');
  69. PREPARE stmt FROM @sql;
  70. EXECUTE stmt;
  71. DEALLOCATE PREPARE stmt;
  72. -- TAGS 컬럼 존재 확인 및 추가
  73. SET @col_exists = 0;
  74. SELECT COUNT(*) INTO @col_exists
  75. FROM INFORMATION_SCHEMA.COLUMNS
  76. WHERE TABLE_NAME = 'VENDOR_LIST'
  77. AND COLUMN_NAME = 'TAGS'
  78. AND TABLE_SCHEMA = DATABASE();
  79. SET @sql = IF(@col_exists = 0,
  80. 'ALTER TABLE `VENDOR_LIST` ADD COLUMN `TAGS` varchar(500) DEFAULT NULL COMMENT ''검색 태그''',
  81. 'SELECT ''TAGS column already exists'' as message');
  82. PREPARE stmt FROM @sql;
  83. EXECUTE stmt;
  84. DEALLOCATE PREPARE stmt;
  85. -- LOGO 컬럼 존재 확인 및 추가
  86. SET @col_exists = 0;
  87. SELECT COUNT(*) INTO @col_exists
  88. FROM INFORMATION_SCHEMA.COLUMNS
  89. WHERE TABLE_NAME = 'VENDOR_LIST'
  90. AND COLUMN_NAME = 'LOGO'
  91. AND TABLE_SCHEMA = DATABASE();
  92. SET @sql = IF(@col_exists = 0,
  93. 'ALTER TABLE `VENDOR_LIST` ADD COLUMN `LOGO` varchar(500) DEFAULT NULL COMMENT ''로고 이미지 URL''',
  94. 'SELECT ''LOGO column already exists'' as message');
  95. PREPARE stmt FROM @sql;
  96. EXECUTE stmt;
  97. DEALLOCATE PREPARE stmt;
  98. -- APPROVAL_STATUS 컬럼 존재 확인 및 추가
  99. SET @col_exists = 0;
  100. SELECT COUNT(*) INTO @col_exists
  101. FROM INFORMATION_SCHEMA.COLUMNS
  102. WHERE TABLE_NAME = 'VENDOR_LIST'
  103. AND COLUMN_NAME = 'APPROVAL_STATUS'
  104. AND TABLE_SCHEMA = DATABASE();
  105. SET @sql = IF(@col_exists = 0,
  106. 'ALTER TABLE `VENDOR_LIST` ADD COLUMN `APPROVAL_STATUS` varchar(20) DEFAULT ''PENDING'' COMMENT ''승인 상태''',
  107. 'SELECT ''APPROVAL_STATUS column already exists'' as message');
  108. PREPARE stmt FROM @sql;
  109. EXECUTE stmt;
  110. DEALLOCATE PREPARE stmt;