Fix ranking on Excel

This commit is contained in:
2024-11-10 23:01:32 +09:00
parent 18f3370f29
commit 10bf6e8fa1
2 changed files with 98 additions and 6 deletions

View File

@ -22,7 +22,7 @@ GROUP BY
event_id,event_code, zekken_number;
-- カテゴリー内ランキング計算用ビュー
CREATE VIEW v_category_rankings AS
CREATE VIEW v_category_rankings_old AS
SELECT
e.id,
e.event_id,
@ -41,8 +41,100 @@ FROM
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
*,
-- 総合ポイントの再計算(遅刻ペナルティを含む)
GREATEST(
raw_points - late_penalty_points,
0
) 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
-- 既存のフィールド
@ -102,7 +194,7 @@ SELECT
-- ランキング情報
cr.ranking as category_rank,
cr.total_participants,
cr.total_valid_participants,
-- チームメンバー情報JSON形式で格納
jsonb_agg(
@ -138,7 +230,7 @@ FROM
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_id = e.event_id -- ゴール情報の結合条件も修正
AND gi.event_code = ev.event_name -- ゴール情報の結合条件も修正
GROUP BY
e.id, e.zekken_number, e.is_active, e."hasParticipated", e."hasGoaled", e.date,
@ -149,13 +241,13 @@ GROUP BY
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.ranking, cr.total_participants,
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);
ON mv_entry_details(id, event_name, zekken_number);
-- ビューの更新
REFRESH MATERIALIZED VIEW mv_entry_details;