implement sumaexcel step-1
This commit is contained in:
@ -42,11 +42,9 @@ WHERE
|
||||
|
||||
-- マテリアライズドビューの作成
|
||||
-- マテリアライズドビューの再作成
|
||||
DROP MATERIALIZED VIEW IF EXISTS mv_entry_details;
|
||||
|
||||
CREATE MATERIALIZED VIEW mv_entry_details AS
|
||||
SELECT
|
||||
-- エントリー基本情報
|
||||
-- 既存のフィールド
|
||||
e.id,
|
||||
CAST(e.zekken_number AS TEXT) as zekken_number,
|
||||
e.is_active,
|
||||
@ -86,6 +84,19 @@ SELECT
|
||||
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,
|
||||
@ -123,6 +134,8 @@ FROM
|
||||
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 ev.event_name = gi.event_code
|
||||
AND CAST(e.zekken_number AS TEXT) = gi.zekken_number
|
||||
|
||||
GROUP BY
|
||||
e.id, e.zekken_number, e.is_active, e."hasParticipated", e."hasGoaled", e.date,
|
||||
@ -134,11 +147,43 @@ GROUP BY
|
||||
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,
|
||||
e.owner_id; -- オーナーIDをGROUP BYに追加
|
||||
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;
|
||||
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
|
||||
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);
|
||||
*/
|
||||
Reference in New Issue
Block a user