Files
rogaining_srv/create_checkin_extended_table.sql
2025-08-27 15:01:06 +09:00

81 lines
3.4 KiB
PL/PgSQL
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.

-- チェックイン拡張情報テーブル作成
-- 2025年8月27日 - サーバーAPI変更要求書対応
CREATE TABLE IF NOT EXISTS rog_checkin_extended (
id SERIAL PRIMARY KEY,
gpslog_id INTEGER REFERENCES rog_gpslog(id) ON DELETE CASCADE,
-- GPS拡張情報
gps_latitude DECIMAL(10, 8),
gps_longitude DECIMAL(11, 8),
gps_accuracy DECIMAL(6, 2),
gps_timestamp TIMESTAMP WITH TIME ZONE,
-- カメラメタデータ
camera_capture_time TIMESTAMP WITH TIME ZONE,
device_info TEXT,
-- 審査・検証情報
validation_status VARCHAR(20) DEFAULT 'pending'
CHECK (validation_status IN ('pending', 'approved', 'rejected', 'requires_review')),
validation_comment TEXT,
validated_by INTEGER REFERENCES rog_customuser(id),
validated_at TIMESTAMP WITH TIME ZONE,
-- スコア情報
bonus_points INTEGER DEFAULT 0,
scoring_breakdown JSONB,
-- システム情報
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- インデックス作成
CREATE INDEX idx_checkin_extended_gpslog ON rog_checkin_extended(gpslog_id);
CREATE INDEX idx_checkin_extended_validation_status ON rog_checkin_extended(validation_status);
CREATE INDEX idx_checkin_extended_validated_by ON rog_checkin_extended(validated_by);
CREATE INDEX idx_checkin_extended_created_at ON rog_checkin_extended(created_at);
-- トリガー関数updated_at自動更新
CREATE OR REPLACE FUNCTION update_checkin_extended_updated_at()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- トリガー作成
CREATE TRIGGER trigger_update_checkin_extended_updated_at
BEFORE UPDATE ON rog_checkin_extended
FOR EACH ROW
EXECUTE FUNCTION update_checkin_extended_updated_at();
-- コメント追加
COMMENT ON TABLE rog_checkin_extended IS 'チェックイン拡張情報テーブル - GPS精度、カメラメタデータ、審査情報';
COMMENT ON COLUMN rog_checkin_extended.gpslog_id IS '関連するGPSログID';
COMMENT ON COLUMN rog_checkin_extended.gps_latitude IS 'GPS緯度';
COMMENT ON COLUMN rog_checkin_extended.gps_longitude IS 'GPS経度';
COMMENT ON COLUMN rog_checkin_extended.gps_accuracy IS 'GPS精度メートル';
COMMENT ON COLUMN rog_checkin_extended.gps_timestamp IS 'GPS取得時刻';
COMMENT ON COLUMN rog_checkin_extended.camera_capture_time IS 'カメラ撮影時刻';
COMMENT ON COLUMN rog_checkin_extended.device_info IS 'デバイス情報';
COMMENT ON COLUMN rog_checkin_extended.validation_status IS '審査ステータス';
COMMENT ON COLUMN rog_checkin_extended.validation_comment IS '審査コメント';
COMMENT ON COLUMN rog_checkin_extended.validated_by IS '審査者ID';
COMMENT ON COLUMN rog_checkin_extended.validated_at IS '審査日時';
COMMENT ON COLUMN rog_checkin_extended.bonus_points IS 'ボーナスポイント';
COMMENT ON COLUMN rog_checkin_extended.scoring_breakdown IS 'スコア詳細JSON';
-- 初期データ例
INSERT INTO rog_checkin_extended (
gpslog_id, gps_latitude, gps_longitude, gps_accuracy, gps_timestamp,
camera_capture_time, device_info, validation_status, bonus_points,
scoring_breakdown
) VALUES
(1, 35.4091, 136.7581, 5.2, '2025-09-15 11:30:00+09:00',
'2025-09-15 11:30:00+09:00', 'iPhone 12', 'pending', 5,
'{"base_points": 10, "camera_bonus": 5, "total_points": 15}'::jsonb)
ON CONFLICT DO NOTHING;