118 lines
4.3 KiB
PL/PgSQL
118 lines
4.3 KiB
PL/PgSQL
-- サーバーAPI変更要求書対応データベース移行スクリプト
|
|
-- 2025年8月27日
|
|
|
|
BEGIN;
|
|
|
|
-- 1. NewEvent2テーブルにstatusフィールド追加
|
|
DO $$
|
|
BEGIN
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM information_schema.columns
|
|
WHERE table_name = 'rog_newevent2' AND column_name = 'status'
|
|
) THEN
|
|
ALTER TABLE rog_newevent2 ADD COLUMN status VARCHAR(20) DEFAULT 'draft'
|
|
CHECK (status IN ('public', 'private', 'draft', 'closed'));
|
|
|
|
-- 既存のpublicフィールドからstatusフィールドへの移行
|
|
UPDATE rog_newevent2 SET status = CASE
|
|
WHEN public = true THEN 'public'
|
|
ELSE 'draft'
|
|
END;
|
|
|
|
COMMENT ON COLUMN rog_newevent2.status IS 'イベントステータス (public/private/draft/closed)';
|
|
END IF;
|
|
END $$;
|
|
|
|
-- 2. Entryテーブルにスタッフ権限フィールド追加
|
|
DO $$
|
|
BEGIN
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM information_schema.columns
|
|
WHERE table_name = 'rog_entry' AND column_name = 'staff_privileges'
|
|
) THEN
|
|
ALTER TABLE rog_entry ADD COLUMN staff_privileges BOOLEAN DEFAULT FALSE;
|
|
COMMENT ON COLUMN rog_entry.staff_privileges IS 'スタッフ権限フラグ';
|
|
END IF;
|
|
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM information_schema.columns
|
|
WHERE table_name = 'rog_entry' AND column_name = 'can_access_private_events'
|
|
) THEN
|
|
ALTER TABLE rog_entry ADD COLUMN can_access_private_events BOOLEAN DEFAULT FALSE;
|
|
COMMENT ON COLUMN rog_entry.can_access_private_events IS '非公開イベント参加権限';
|
|
END IF;
|
|
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM information_schema.columns
|
|
WHERE table_name = 'rog_entry' AND column_name = 'team_validation_status'
|
|
) THEN
|
|
ALTER TABLE rog_entry ADD COLUMN team_validation_status VARCHAR(20) DEFAULT 'approved'
|
|
CHECK (team_validation_status IN ('approved', 'pending', 'rejected'));
|
|
COMMENT ON COLUMN rog_entry.team_validation_status IS 'チーム承認状況';
|
|
END IF;
|
|
END $$;
|
|
|
|
-- 3. インデックス追加
|
|
CREATE INDEX IF NOT EXISTS idx_newevent2_status ON rog_newevent2(status);
|
|
CREATE INDEX IF NOT EXISTS idx_entry_staff_privileges ON rog_entry(staff_privileges) WHERE staff_privileges = TRUE;
|
|
CREATE INDEX IF NOT EXISTS idx_entry_validation_status ON rog_entry(team_validation_status);
|
|
|
|
-- 4. データ整合性チェック
|
|
DO $$
|
|
DECLARE
|
|
rec RECORD;
|
|
inconsistent_count INTEGER := 0;
|
|
BEGIN
|
|
-- publicフィールドとstatusフィールドの整合性チェック
|
|
FOR rec IN (
|
|
SELECT id, event_name, public, status
|
|
FROM rog_newevent2
|
|
WHERE (public = TRUE AND status != 'public')
|
|
OR (public = FALSE AND status = 'public')
|
|
) LOOP
|
|
RAISE NOTICE 'Inconsistent status for event %: public=%, status=%',
|
|
rec.event_name, rec.public, rec.status;
|
|
inconsistent_count := inconsistent_count + 1;
|
|
END LOOP;
|
|
|
|
IF inconsistent_count > 0 THEN
|
|
RAISE NOTICE 'Found % events with inconsistent public/status values', inconsistent_count;
|
|
ELSE
|
|
RAISE NOTICE 'All events have consistent public/status values';
|
|
END IF;
|
|
END $$;
|
|
|
|
-- 5. 統計情報更新
|
|
ANALYZE rog_newevent2;
|
|
ANALYZE rog_entry;
|
|
|
|
-- 6. 移行結果サマリー
|
|
DO $$
|
|
DECLARE
|
|
event_count INTEGER;
|
|
entry_count INTEGER;
|
|
public_events INTEGER;
|
|
private_events INTEGER;
|
|
draft_events INTEGER;
|
|
staff_entries INTEGER;
|
|
BEGIN
|
|
SELECT COUNT(*) INTO event_count FROM rog_newevent2;
|
|
SELECT COUNT(*) INTO entry_count FROM rog_entry;
|
|
SELECT COUNT(*) INTO public_events FROM rog_newevent2 WHERE status = 'public';
|
|
SELECT COUNT(*) INTO private_events FROM rog_newevent2 WHERE status = 'private';
|
|
SELECT COUNT(*) INTO draft_events FROM rog_newevent2 WHERE status = 'draft';
|
|
SELECT COUNT(*) INTO staff_entries FROM rog_entry WHERE staff_privileges = TRUE;
|
|
|
|
RAISE NOTICE '';
|
|
RAISE NOTICE '=== 移行完了サマリー ===';
|
|
RAISE NOTICE 'イベント総数: %', event_count;
|
|
RAISE NOTICE ' - Public: %', public_events;
|
|
RAISE NOTICE ' - Private: %', private_events;
|
|
RAISE NOTICE ' - Draft: %', draft_events;
|
|
RAISE NOTICE 'エントリー総数: %', entry_count;
|
|
RAISE NOTICE ' - スタッフ権限付与: %', staff_entries;
|
|
RAISE NOTICE '';
|
|
END $$;
|
|
|
|
COMMIT;
|