88 lines
3.5 KiB
PL/PgSQL
88 lines
3.5 KiB
PL/PgSQL
-- 画像管理テーブル作成
|
||
-- サーバーAPI変更要求書対応 - 最優先項目
|
||
|
||
CREATE TABLE IF NOT EXISTS rog_uploaded_images (
|
||
id SERIAL PRIMARY KEY,
|
||
|
||
-- 基本情報
|
||
original_filename VARCHAR(255) NOT NULL,
|
||
server_filename VARCHAR(255) NOT NULL UNIQUE,
|
||
file_url TEXT NOT NULL,
|
||
file_size BIGINT NOT NULL,
|
||
mime_type VARCHAR(50) NOT NULL,
|
||
|
||
-- 関連情報
|
||
event_code VARCHAR(50),
|
||
team_name VARCHAR(255),
|
||
cp_number INTEGER,
|
||
|
||
-- アップロード情報
|
||
upload_source VARCHAR(50) DEFAULT 'direct', -- 'direct', 'sharing_intent', 'bulk_upload'
|
||
device_platform VARCHAR(20), -- 'ios', 'android'
|
||
|
||
-- メタデータ
|
||
capture_timestamp TIMESTAMP WITH TIME ZONE,
|
||
upload_timestamp TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||
device_info TEXT,
|
||
|
||
-- 処理状況
|
||
processing_status VARCHAR(20) DEFAULT 'uploaded', -- 'uploaded', 'processing', 'processed', 'failed'
|
||
thumbnail_url TEXT,
|
||
|
||
-- 外部キー
|
||
gpslog_id INTEGER REFERENCES rog_gpslog(id) ON DELETE SET NULL,
|
||
entry_id INTEGER REFERENCES rog_entry(id) ON DELETE SET NULL,
|
||
|
||
-- システム情報
|
||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
||
);
|
||
|
||
-- インデックス作成
|
||
CREATE INDEX idx_uploaded_images_event_team ON rog_uploaded_images(event_code, team_name);
|
||
CREATE INDEX idx_uploaded_images_cp_number ON rog_uploaded_images(cp_number);
|
||
CREATE INDEX idx_uploaded_images_upload_timestamp ON rog_uploaded_images(upload_timestamp);
|
||
CREATE INDEX idx_uploaded_images_processing_status ON rog_uploaded_images(processing_status);
|
||
CREATE INDEX idx_uploaded_images_gpslog ON rog_uploaded_images(gpslog_id);
|
||
|
||
-- コメント追加
|
||
COMMENT ON TABLE rog_uploaded_images IS '画像アップロード管理テーブル - マルチアップロード対応';
|
||
COMMENT ON COLUMN rog_uploaded_images.original_filename IS '元のファイル名';
|
||
COMMENT ON COLUMN rog_uploaded_images.server_filename IS 'サーバー上のファイル名';
|
||
COMMENT ON COLUMN rog_uploaded_images.file_url IS '画像URL';
|
||
COMMENT ON COLUMN rog_uploaded_images.file_size IS 'ファイルサイズ(バイト)';
|
||
COMMENT ON COLUMN rog_uploaded_images.upload_source IS 'アップロード方法';
|
||
COMMENT ON COLUMN rog_uploaded_images.device_platform IS 'デバイスプラットフォーム';
|
||
COMMENT ON COLUMN rog_uploaded_images.processing_status IS '処理状況';
|
||
|
||
-- 制約追加
|
||
ALTER TABLE rog_uploaded_images ADD CONSTRAINT chk_file_size
|
||
CHECK (file_size > 0 AND file_size <= 10485760); -- 最大10MB
|
||
|
||
ALTER TABLE rog_uploaded_images ADD CONSTRAINT chk_mime_type
|
||
CHECK (mime_type IN ('image/jpeg', 'image/png', 'image/heic', 'image/webp'));
|
||
|
||
ALTER TABLE rog_uploaded_images ADD CONSTRAINT chk_upload_source
|
||
CHECK (upload_source IN ('direct', 'sharing_intent', 'bulk_upload'));
|
||
|
||
ALTER TABLE rog_uploaded_images ADD CONSTRAINT chk_device_platform
|
||
CHECK (device_platform IN ('ios', 'android', 'web'));
|
||
|
||
ALTER TABLE rog_uploaded_images ADD CONSTRAINT chk_processing_status
|
||
CHECK (processing_status IN ('uploaded', 'processing', 'processed', 'failed'));
|
||
|
||
-- トリガー関数:updated_at自動更新
|
||
CREATE OR REPLACE FUNCTION update_uploaded_images_updated_at()
|
||
RETURNS TRIGGER AS $$
|
||
BEGIN
|
||
NEW.updated_at = NOW();
|
||
RETURN NEW;
|
||
END;
|
||
$$ LANGUAGE plpgsql;
|
||
|
||
-- トリガー作成
|
||
CREATE TRIGGER trigger_update_uploaded_images_updated_at
|
||
BEFORE UPDATE ON rog_uploaded_images
|
||
FOR EACH ROW
|
||
EXECUTE FUNCTION update_uploaded_images_updated_at();
|