151 lines
5.9 KiB
SQL
151 lines
5.9 KiB
SQL
-- gifuroge.event_table から rogdb.rog_newevent2 への移行SQL
|
||
--
|
||
-- 移行条件:
|
||
-- - event_day < '2024-10-01' のデータを移行
|
||
-- - self_rogaining = False として移行
|
||
-- - その他 = True として移行(コメントで記録)
|
||
--
|
||
-- 実行前の準備:
|
||
-- 1. gifurogeデータベースからrogdbデータベースへのdblink接続が必要
|
||
-- 2. または、両方のデータベースに同時アクセス可能な環境での実行
|
||
|
||
-- Step 1: 移行対象データの確認
|
||
-- gifurogeデータベースで実行
|
||
SELECT
|
||
event_code,
|
||
event_name,
|
||
start_time,
|
||
event_day,
|
||
-- 日時計算の確認
|
||
CASE
|
||
WHEN start_time IS NULL OR start_time = '' THEN
|
||
(event_day || ' 09:00:00')::timestamp
|
||
ELSE
|
||
(event_day || ' ' || start_time || ':00')::timestamp
|
||
END as start_datetime,
|
||
CASE
|
||
WHEN start_time IS NULL OR start_time = '' THEN
|
||
(event_day || ' 09:00:00')::timestamp + INTERVAL '5 hours'
|
||
ELSE
|
||
(event_day || ' ' || start_time || ':00')::timestamp + INTERVAL '5 hours'
|
||
END as end_datetime,
|
||
CASE
|
||
WHEN start_time IS NULL OR start_time = '' THEN
|
||
(event_day || ' 09:00:00')::timestamp - INTERVAL '3 days'
|
||
ELSE
|
||
(event_day || ' ' || start_time || ':00')::timestamp - INTERVAL '3 days'
|
||
END as deadline_datetime
|
||
FROM event_table
|
||
WHERE event_day < '2024-10-01'
|
||
AND event_code IS NOT NULL
|
||
AND event_code != ''
|
||
ORDER BY event_day;
|
||
|
||
-- Step 2: 実際の移行(rogdbデータベースで実行)
|
||
-- 注意: 以下のSQLはrogdbデータベースで実行する必要があります
|
||
-- gifurogeデータベースからのデータ取得にはdblinkまたは別の方法が必要です
|
||
|
||
-- dblinkを使用する場合の例:
|
||
-- SELECT dblink_connect('gifuroge_conn', 'host=postgres-db dbname=gifuroge user=admin password=admin123456');
|
||
|
||
-- 移行用のINSERT文(手動で値を入力する場合の例)
|
||
/*
|
||
INSERT INTO rog_newevent2 (
|
||
event_name, -- gifuroge.event_table.event_code
|
||
event_description, -- gifuroge.event_table.event_name
|
||
start_datetime, -- gifuroge.event_table.event_day + start_time
|
||
end_datetime, -- start_datetime + 5 hours
|
||
"deadlineDateTime", -- start_datetime - 3 days
|
||
self_rogaining, -- False
|
||
status, -- 'public'
|
||
public, -- True
|
||
hour_5, -- True
|
||
hour_3, -- False
|
||
class_general, -- True
|
||
class_family, -- True
|
||
class_solo_male, -- True
|
||
class_solo_female, -- True
|
||
event_code, -- gifuroge.event_table.event_code (MobServer統合)
|
||
start_time, -- gifuroge.event_table.start_time (MobServer統合)
|
||
event_day -- gifuroge.event_table.event_day (MobServer統合)
|
||
)
|
||
SELECT
|
||
et.event_code as event_name,
|
||
et.event_name as event_description,
|
||
CASE
|
||
WHEN et.start_time IS NULL OR et.start_time = '' THEN
|
||
(et.event_day || ' 09:00:00')::timestamp AT TIME ZONE 'Asia/Tokyo'
|
||
ELSE
|
||
(et.event_day || ' ' || et.start_time || ':00')::timestamp AT TIME ZONE 'Asia/Tokyo'
|
||
END as start_datetime,
|
||
CASE
|
||
WHEN et.start_time IS NULL OR et.start_time = '' THEN
|
||
(et.event_day || ' 09:00:00')::timestamp AT TIME ZONE 'Asia/Tokyo' + INTERVAL '5 hours'
|
||
ELSE
|
||
(et.event_day || ' ' || et.start_time || ':00')::timestamp AT TIME ZONE 'Asia/Tokyo' + INTERVAL '5 hours'
|
||
END as end_datetime,
|
||
CASE
|
||
WHEN et.start_time IS NULL OR et.start_time = '' THEN
|
||
(et.event_day || ' 09:00:00')::timestamp AT TIME ZONE 'Asia/Tokyo' - INTERVAL '3 days'
|
||
ELSE
|
||
(et.event_day || ' ' || et.start_time || ':00')::timestamp AT TIME ZONE 'Asia/Tokyo' - INTERVAL '3 days'
|
||
END as deadline_datetime,
|
||
false as self_rogaining, -- 指定条件
|
||
'public' as status, -- デフォルトステータス
|
||
true as public, -- 公開設定
|
||
true as hour_5, -- 5時間イベント
|
||
false as hour_3, -- 3時間イベントではない
|
||
true as class_general, -- 一般クラス有効
|
||
true as class_family, -- ファミリークラス有効
|
||
true as class_solo_male, -- 男子ソロクラス有効
|
||
true as class_solo_female, -- 女子ソロクラス有効
|
||
et.event_code, -- MobServer統合フィールド
|
||
et.start_time, -- MobServer統合フィールド
|
||
et.event_day -- MobServer統合フィールド
|
||
FROM dblink('gifuroge_conn',
|
||
'SELECT event_code, event_name, start_time, event_day
|
||
FROM event_table
|
||
WHERE event_day < ''2024-10-01''
|
||
AND event_code IS NOT NULL
|
||
AND event_code != ''''
|
||
ORDER BY event_day'
|
||
) AS et(event_code text, event_name text, start_time text, event_day text)
|
||
WHERE NOT EXISTS (
|
||
SELECT 1 FROM rog_newevent2 WHERE event_name = et.event_code
|
||
);
|
||
*/
|
||
|
||
-- dblinkの切断
|
||
-- SELECT dblink_disconnect('gifuroge_conn');
|
||
|
||
-- Step 3: 移行結果の確認
|
||
SELECT
|
||
id,
|
||
event_name,
|
||
event_description,
|
||
start_datetime,
|
||
end_datetime,
|
||
"deadlineDateTime",
|
||
self_rogaining,
|
||
status,
|
||
event_code,
|
||
start_time,
|
||
event_day
|
||
FROM rog_newevent2
|
||
WHERE self_rogaining = false
|
||
AND event_code IS NOT NULL
|
||
ORDER BY start_datetime;
|
||
|
||
-- 移行件数の確認
|
||
SELECT
|
||
COUNT(*) as total_migrated_events
|
||
FROM rog_newevent2
|
||
WHERE self_rogaining = false
|
||
AND event_code IS NOT NULL;
|
||
|
||
-- 注意事項:
|
||
-- 1. 上記のSQLは例であり、実際の実行環境に応じて調整が必要です
|
||
-- 2. dblinkを使用しない場合は、ETLツールやアプリケーションレベルでの移行を推奨します
|
||
-- 3. "その他=True"に相当するフィールドが見つからない場合、新しいフィールドの追加を検討してください
|
||
-- 4. 実行前に必ずバックアップを取ってください
|