-- まず既存のビューをすべて削除 DROP MATERIALIZED VIEW IF EXISTS mv_entry_details CASCADE; DROP VIEW IF EXISTS v_category_rankings CASCADE; DROP VIEW IF EXISTS v_checkin_summary CASCADE; -- チェックポイントの集計用ビュー CREATE VIEW v_checkin_summary AS SELECT event_id, event_code, zekken_number, -- 文字列として保持 COUNT(*) as total_checkins, COUNT(CASE WHEN buy_flag THEN 1 END) as purchase_count, SUM(points) as total_points, SUM(CASE WHEN buy_flag THEN points ELSE 0 END) as bonus_points, SUM(CASE WHEN NOT buy_flag THEN points ELSE 0 END) as normal_points, SUM(COALESCE(late_point, 0)) as penalty_points, MAX(create_at) as last_checkin FROM gps_checkins GROUP BY event_id,event_code, zekken_number; -- カテゴリー内ランキング計算用ビュー CREATE VIEW v_category_rankings_old AS SELECT e.id, e.event_id, ev.event_name, e.category_id, CAST(e.zekken_number AS TEXT) as zekken_number, -- 数値を文字列に変換 COALESCE(cs.total_points, 0) as total_score, RANK() OVER (PARTITION BY e.event_id, e.category_id ORDER BY COALESCE(cs.total_points, 0) DESC) as ranking, COUNT(*) OVER (PARTITION BY e.event_id, e.category_id) as total_participants FROM rog_entry e JOIN rog_newevent2 ev ON e.event_id = ev.id LEFT JOIN v_checkin_summary cs ON ev.event_name = cs.event_code AND CAST(e.zekken_number AS TEXT) = cs.zekken_number WHERE e.is_active = true; -- 完走状態を含むカテゴリーランキングビューの作成 -- 完走状態を含むカテゴリーランキングビューの作成 CREATE OR REPLACE VIEW v_category_rankings AS WITH completion_status AS ( SELECT e.id, e.event_id, e.category_id, CAST(e.zekken_number AS TEXT) as zekken_number, CASE WHEN gi.goaltime IS NULL THEN '棄権' WHEN gi.goaltime <= ev.end_datetime THEN '完走' WHEN gi.goaltime > ev.end_datetime AND gi.goaltime <= ev.end_datetime + INTERVAL '15 minutes' THEN '完走(遅刻)' ELSE '失格' END as completion_status, COALESCE(cs.total_points, 0) as raw_points, COALESCE(cs.normal_points, 0) as normal_points, COALESCE(cs.bonus_points, 0) as bonus_points, COALESCE(cs.penalty_points, 0) as original_penalty_points, -- 遅刻ペナルティの計算(1秒でも遅れたら、その分数に応じて-50点/分) CASE WHEN gi.goaltime > ev.end_datetime THEN (CEIL(EXTRACT(EPOCH FROM (gi.goaltime - ev.end_datetime)) / 60)) * (-50) ELSE 0 END as late_penalty_points, gi.goaltime, ev.end_datetime FROM rog_entry e JOIN rog_newevent2 ev ON e.event_id = ev.id LEFT JOIN v_checkin_summary cs ON ev.event_name = cs.event_code AND CAST(e.zekken_number AS TEXT) = cs.zekken_number LEFT JOIN rog_goalimages gi ON e.owner_id = gi.user_id AND gi.event_code = ev.event_name WHERE e.is_active = true ), points_calculation AS ( SELECT *, -- 総合ポイントの再計算(遅刻ペナルティを含む) raw_points + late_penalty_points as total_points FROM completion_status ), valid_rankings AS ( -- 完走者のみを対象とした順位付け SELECT *, DENSE_RANK() OVER ( PARTITION BY event_id, category_id ORDER BY total_points DESC, CASE WHEN completion_status = '完走' THEN 1 WHEN completion_status = '完走(遅刻)' THEN 2 END, goaltime ) as valid_rank FROM points_calculation WHERE completion_status IN ('完走', '完走(遅刻)') ) SELECT cs.id, cs.event_id, cs.category_id, cs.zekken_number, cs.raw_points as original_total_points, cs.normal_points, cs.bonus_points, cs.original_penalty_points, CASE WHEN cs.completion_status IN ('完走(遅刻)', '失格') AND cs.goaltime IS NOT NULL THEN cs.late_penalty_points ELSE 0 END as late_penalty_points, ROUND(pc.total_points) as total_points, cs.completion_status, CASE WHEN cs.completion_status IN ('完走', '完走(遅刻)') THEN CAST(vr.valid_rank AS TEXT) WHEN cs.completion_status = '失格' THEN '失格' WHEN cs.completion_status = '棄権' THEN '棄権' END as ranking, COUNT(*) FILTER (WHERE cs.completion_status IN ('完走', '完走(遅刻)')) OVER (PARTITION BY cs.event_id, cs.category_id) as total_valid_participants FROM completion_status cs JOIN points_calculation pc ON cs.id = pc.id LEFT JOIN valid_rankings vr ON cs.id = vr.id; -- マテリアライズドビューの作成 CREATE MATERIALIZED VIEW mv_entry_details AS SELECT -- 既存のフィールド e.id, CAST(e.zekken_number AS TEXT) as zekken_number, e.is_active, e."hasParticipated", e."hasGoaled", e.date as entry_date, -- イベント情報 ev.event_name, ev.event_description, ev.start_datetime, ev.end_datetime, ev."deadlineDateTime", TO_CHAR(ev.start_datetime::date, 'YYYY/MM/DD') as event_date, -- カテゴリー情報 nc.category_name, nc.category_number, nc.duration, nc.num_of_member, nc.family as is_family_category, nc.female as is_female_category, -- チーム情報 t.team_name, -- オーナー情報 cu.email as owner_email, cu.firstname as owner_firstname, cu.lastname as owner_lastname, cu.date_of_birth as owner_birth_date, cu.female as owner_is_female, -- スコア情報 COALESCE(cs.normal_points, 0) as normal_points, COALESCE(cs.bonus_points, 0) as bonus_points, COALESCE(cs.total_checkins, 0) as checkin_count, COALESCE(cs.purchase_count, 0) as purchase_count, cr.late_penalty_points as penalty_points, -- 遅刻ペナルティを使用 cr.total_points as total_points, -- v_category_rankingsの総合ポイントを使用 -- ゴール情報 gi.goalimage as goal_image, gi.goaltime as goal_time, -- 完走状態の判定を追加 CASE WHEN gi.goaltime IS NULL THEN '棄権' WHEN gi.goaltime <= ev.end_datetime THEN '完走' WHEN gi.goaltime > ev.end_datetime AND gi.goaltime <= ev.end_datetime + INTERVAL '15 minutes' THEN '完走(遅刻)' ELSE '失格' END as validation, -- ランキング情報 cr.ranking as category_rank, cr.total_valid_participants, -- チームメンバー情報(JSON形式で格納) jsonb_agg( jsonb_build_object( 'email', m.user_id, 'firstname', m.firstname, 'lastname', m.lastname, 'birth_date', m.date_of_birth, 'is_female', m.female, 'is_temporary', m.is_temporary, 'status', CASE WHEN m.is_temporary THEN 'TEMPORARY' WHEN m.date_of_birth IS NULL THEN 'PENDING' ELSE 'ACTIVE' END, 'member_type', CASE WHEN m.user_id = e.owner_id THEN 'OWNER' ELSE 'MEMBER' END ) ORDER BY CASE WHEN m.user_id = e.owner_id THEN 0 ELSE 1 END, -- オーナーを最初に m.id ) FILTER (WHERE m.id IS NOT NULL) as team_members FROM rog_entry e INNER JOIN rog_newevent2 ev ON e.event_id = ev.id INNER JOIN rog_newcategory nc ON e.category_id = nc.id INNER JOIN rog_team t ON e.team_id = t.id LEFT JOIN rog_customuser cu ON e.owner_id = cu.id LEFT JOIN v_checkin_summary cs ON e.event_id = cs.event_id -- この行を変更 AND CAST(e.zekken_number AS TEXT) = cs.zekken_number LEFT JOIN v_category_rankings cr ON e.id = cr.id LEFT JOIN rog_member m ON t.id = m.team_id LEFT JOIN rog_goalimages gi ON e.owner_id = gi.user_id AND gi.event_code = ev.event_name -- ゴール情報の結合条件も修正 GROUP BY e.id, e.zekken_number, e.is_active, e."hasParticipated", e."hasGoaled", e.date, ev.event_name,ev.event_description, ev.start_datetime, ev.end_datetime, ev."deadlineDateTime", nc.category_name, nc.category_number, nc.duration, nc.num_of_member, nc.family, nc.female, t.team_name, cu.email, cu.firstname, cu.lastname, cu.date_of_birth, cu.female, cs.total_points, cs.normal_points, cs.bonus_points, cs.penalty_points, cs.total_checkins, cs.purchase_count, cs.last_checkin, cr.original_total_points, cr.late_penalty_points, cr.total_points, cr.completion_status, cr.ranking, cr.total_valid_participants, gi.goalimage, gi.goaltime, e.owner_id; -- インデックスの再作成 CREATE UNIQUE INDEX idx_mv_entry_details_event_zekken ON mv_entry_details(id, event_name, zekken_number); -- ビューの更新 REFRESH MATERIALIZED VIEW mv_entry_details; -- チェックインと位置情報を結合したビューを作成 DROP VIEW IF EXISTS v_checkins_locations CASCADE; CREATE OR REPLACE VIEW v_checkins_locations AS SELECT g.event_code, g.zekken_number, g.path_order, g.cp_number, l.sub_loc_id, l.location_name, l.photos, g.image_address, g.create_at, g.buy_flag, g.validate_location, g.points FROM gps_checkins g LEFT JOIN rog_location l ON g.cp_number = l.cp AND l."group" LIKE '%' || g.event_code || '%' ORDER BY g.event_code, g.zekken_number, g.path_order; -- インデックスのサジェスチョン(実際のテーブルに適用する必要があります) /* CREATE INDEX idx_gps_checkins_cp_number ON gps_checkins(cp_number); CREATE INDEX idx_rog_location_cp ON rog_location(cp); */ -- チェックポイントごとの集計VIEW -- チェックポイントごとの集計ビューを作成 DROP VIEW IF EXISTS v_checkpoint_summary CASCADE; CREATE OR REPLACE VIEW v_checkpoint_summary AS WITH checkpoint_counts AS ( SELECT e.event_id, ev.event_name, gc.cp_number, l.sub_loc_id, l.location_name, e.category_id, nc.category_name, COUNT(CASE WHEN gc.validate_location = true AND gc.buy_flag = false THEN 1 END) as normal_checkins, COUNT(CASE WHEN gc.validate_location = true AND gc.buy_flag = true THEN 1 END) as purchase_checkins FROM rog_entry e JOIN rog_newevent2 ev ON e.event_id = ev.id JOIN rog_newcategory nc ON e.category_id = nc.id JOIN gps_checkins gc ON ev.event_name = gc.event_code AND CAST(e.zekken_number AS TEXT) = gc.zekken_number LEFT JOIN rog_location l ON gc.cp_number = l.cp AND l."group" LIKE '%' || gc.event_code || '%' WHERE e.is_active = true AND gc.validate_location = true GROUP BY e.event_id, ev.event_name, gc.cp_number, l.sub_loc_id, l.location_name, e.category_id, nc.category_name ) SELECT event_id, event_name, cp_number, sub_loc_id, location_name, category_id, category_name, normal_checkins, purchase_checkins FROM checkpoint_counts ORDER BY event_name, cp_number, category_id;