Files
rogaining_srv/rog/postgres_views.sql
2024-11-08 14:33:46 +09:00

189 lines
6.1 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

-- まず既存のビューをすべて削除
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_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_code, zekken_number;
-- カテゴリー内ランキング計算用ビュー
CREATE VIEW v_category_rankings 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 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.start_datetime,
ev.end_datetime,
ev."deadlineDateTime",
-- カテゴリー情報
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.total_points, 0) as total_points,
COALESCE(cs.normal_points, 0) as normal_points,
COALESCE(cs.bonus_points, 0) as bonus_points,
COALESCE(cs.penalty_points, 0) as penalty_points,
COALESCE(cs.total_checkins, 0) as checkin_count,
COALESCE(cs.purchase_count, 0) as purchase_count,
-- ゴール情報
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_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 ev.event_name = cs.event_code
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
GROUP BY
e.id, e.zekken_number, e.is_active, e."hasParticipated", e."hasGoaled", e.date,
ev.event_name, 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.ranking, cr.total_participants,
gi.goalimage, gi.goaltime,
e.owner_id;
-- インデックスの再作成
CREATE UNIQUE INDEX idx_mv_entry_details_event_zekken
ON mv_entry_details(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);
*/