camera-database/schema/05-history.sql

90 lines
2.6 KiB
SQL

-- ==========================================
-- CLUB DAGUERRE CAMERA DATABASE
-- Part 5: History Tables (Audit Trail)
-- ==========================================
-- ==========================================
-- CAMERA MODEL HISTORY
-- ==========================================
CREATE TABLE camera_models_history (
history_id BIGSERIAL PRIMARY KEY,
id INT NOT NULL,
manufacturer_id INT,
goergens_model_number VARCHAR(10),
body_type VARCHAR(2),
viewfinder_type VARCHAR(4),
format_code VARCHAR(20),
year_first INT,
year_last INT,
-- History metadata
version INT NOT NULL,
changed_at TIMESTAMP NOT NULL,
changed_by INT,
change_type VARCHAR(10) NOT NULL,
UNIQUE(id, version),
CONSTRAINT chk_change_type CHECK (change_type IN ('INSERT', 'UPDATE', 'DELETE'))
);
CREATE INDEX idx_models_hist_id ON camera_models_history(id);
CREATE INDEX idx_models_hist_time ON camera_models_history(changed_at DESC);
COMMENT ON TABLE camera_models_history IS 'Historical versions of camera models';
-- ==========================================
-- LENS/SHUTTER COMBO HISTORY
-- ==========================================
CREATE TABLE lens_shutter_combos_history (
history_id BIGSERIAL PRIMARY KEY,
id INT NOT NULL,
housing_variant_id INT,
goergens_combo_number VARCHAR(3),
lens_id INT,
shutter_id INT,
weight_g INT,
width_mm DECIMAL(6,2),
height_mm DECIMAL(6,2),
depth_mm DECIMAL(6,2),
specs JSONB,
version INT NOT NULL,
changed_at TIMESTAMP NOT NULL,
changed_by INT,
change_type VARCHAR(10) NOT NULL,
UNIQUE(id, version),
CONSTRAINT chk_change_type CHECK (change_type IN ('INSERT', 'UPDATE', 'DELETE'))
);
CREATE INDEX idx_combos_hist_id ON lens_shutter_combos_history(id);
CREATE INDEX idx_combos_hist_time ON lens_shutter_combos_history(changed_at DESC);
COMMENT ON TABLE lens_shutter_combos_history IS 'Historical versions of camera combinations';
-- ==========================================
-- ANNOTATION HISTORY
-- ==========================================
CREATE TABLE annotations_history (
history_id BIGSERIAL PRIMARY KEY,
id INT NOT NULL,
combo_id INT,
annotation_type VARCHAR(50),
content_de TEXT,
content_en TEXT,
contributed_by INT,
version INT NOT NULL,
changed_at TIMESTAMP NOT NULL,
changed_by INT,
change_type VARCHAR(10) NOT NULL,
UNIQUE(id, version),
CONSTRAINT chk_change_type CHECK (change_type IN ('INSERT', 'UPDATE', 'DELETE'))
);
CREATE INDEX idx_annotations_hist_id ON annotations_history(id);
CREATE INDEX idx_annotations_hist_time ON annotations_history(changed_at DESC);
COMMENT ON TABLE annotations_history IS 'Historical versions of user annotations';