221 lines
7.5 KiB
PL/PgSQL
221 lines
7.5 KiB
PL/PgSQL
-- ==========================================
|
|
-- CLUB DAGUERRE CAMERA DATABASE
|
|
-- Part 6: Triggers & Functions
|
|
-- ==========================================
|
|
|
|
-- ==========================================
|
|
-- FUNCTION: Update Denormalized Fields
|
|
-- ==========================================
|
|
CREATE OR REPLACE FUNCTION update_combo_denormalized()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
-- Get hierarchy IDs
|
|
SELECT
|
|
hv.camera_model_id,
|
|
cm.manufacturer_id
|
|
INTO
|
|
NEW.camera_model_id,
|
|
NEW.manufacturer_id
|
|
FROM housing_variants hv
|
|
JOIN camera_models cm ON hv.camera_model_id = cm.id
|
|
WHERE hv.id = NEW.housing_variant_id;
|
|
|
|
-- Generate Goergens ID
|
|
SELECT
|
|
m.goergens_code || ' K ' || cm.goergens_model_number || ' ' ||
|
|
hv.goergens_variant_letter || NEW.goergens_combo_number
|
|
INTO NEW.goergens_full_id
|
|
FROM housing_variants hv
|
|
JOIN camera_models cm ON hv.camera_model_id = cm.id
|
|
JOIN manufacturers m ON cm.manufacturer_id = m.id
|
|
WHERE hv.id = NEW.housing_variant_id;
|
|
|
|
-- Generate display name
|
|
SELECT
|
|
m.name || ' ' ||
|
|
COALESCE(i18n.model_name, '') ||
|
|
CASE WHEN hv.color IS NOT NULL THEN ' (' || hv.color || ')' ELSE '' END ||
|
|
CASE WHEN l.name IS NOT NULL THEN ' ' || l.name ELSE '' END ||
|
|
CASE WHEN l.focal_length_mm IS NOT NULL THEN ' ' || l.focal_length_mm || 'mm' ELSE '' END ||
|
|
CASE WHEN s.name IS NOT NULL THEN ' ' || s.name ELSE '' END
|
|
INTO NEW.display_name
|
|
FROM housing_variants hv
|
|
JOIN camera_models cm ON hv.camera_model_id = cm.id
|
|
JOIN manufacturers m ON cm.manufacturer_id = m.id
|
|
LEFT JOIN camera_model_i18n i18n ON cm.id = i18n.camera_model_id
|
|
LEFT JOIN lenses l ON NEW.lens_id = l.id
|
|
LEFT JOIN shutters s ON NEW.shutter_id = s.id
|
|
WHERE hv.id = NEW.housing_variant_id;
|
|
|
|
-- Generate search text
|
|
NEW.search_text := NEW.display_name || ' ' || COALESCE(NEW.goergens_full_id, '');
|
|
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Trigger on INSERT
|
|
CREATE TRIGGER trg_combo_denorm_insert
|
|
BEFORE INSERT ON lens_shutter_combos
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_combo_denormalized();
|
|
|
|
-- Trigger on UPDATE (only when relevant fields change)
|
|
CREATE TRIGGER trg_combo_denorm_update
|
|
BEFORE UPDATE ON lens_shutter_combos
|
|
FOR EACH ROW
|
|
WHEN (
|
|
OLD.housing_variant_id IS DISTINCT FROM NEW.housing_variant_id OR
|
|
OLD.lens_id IS DISTINCT FROM NEW.lens_id OR
|
|
OLD.shutter_id IS DISTINCT FROM NEW.shutter_id
|
|
)
|
|
EXECUTE FUNCTION update_combo_denormalized();
|
|
|
|
COMMENT ON FUNCTION update_combo_denormalized IS 'Maintains denormalized fields in lens_shutter_combos for query performance';
|
|
|
|
-- ==========================================
|
|
-- FUNCTION: Version Increment & Timestamp
|
|
-- ==========================================
|
|
CREATE OR REPLACE FUNCTION update_version_and_timestamp()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.version := OLD.version + 1;
|
|
NEW.updated_at := NOW();
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Apply to main tables
|
|
CREATE TRIGGER trg_mfg_version
|
|
BEFORE UPDATE ON manufacturers
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_version_and_timestamp();
|
|
|
|
CREATE TRIGGER trg_models_version
|
|
BEFORE UPDATE ON camera_models
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_version_and_timestamp();
|
|
|
|
CREATE TRIGGER trg_variants_version
|
|
BEFORE UPDATE ON housing_variants
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_version_and_timestamp();
|
|
|
|
CREATE TRIGGER trg_combos_version
|
|
BEFORE UPDATE ON lens_shutter_combos
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_version_and_timestamp();
|
|
|
|
COMMENT ON FUNCTION update_version_and_timestamp IS 'Increments version number and updates timestamp on every change';
|
|
|
|
-- ==========================================
|
|
-- FUNCTION: Maintain Camera Models History
|
|
-- ==========================================
|
|
CREATE OR REPLACE FUNCTION camera_models_to_history()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF TG_OP = 'UPDATE' THEN
|
|
INSERT INTO camera_models_history (
|
|
id, manufacturer_id, goergens_model_number, body_type,
|
|
viewfinder_type, format_code, year_first, year_last,
|
|
version, changed_at, changed_by, change_type
|
|
)
|
|
VALUES (
|
|
OLD.id, OLD.manufacturer_id, OLD.goergens_model_number, OLD.body_type,
|
|
OLD.viewfinder_type, OLD.format_code, OLD.year_first, OLD.year_last,
|
|
OLD.version, NOW(), NEW.updated_by, 'UPDATE'
|
|
);
|
|
ELSIF TG_OP = 'DELETE' THEN
|
|
INSERT INTO camera_models_history (
|
|
id, manufacturer_id, goergens_model_number, body_type,
|
|
viewfinder_type, format_code, year_first, year_last,
|
|
version, changed_at, changed_by, change_type
|
|
)
|
|
VALUES (
|
|
OLD.id, OLD.manufacturer_id, OLD.goergens_model_number, OLD.body_type,
|
|
OLD.viewfinder_type, OLD.format_code, OLD.year_first, OLD.year_last,
|
|
OLD.version, NOW(), NULL, 'DELETE'
|
|
);
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER trg_models_history
|
|
AFTER UPDATE OR DELETE ON camera_models
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION camera_models_to_history();
|
|
|
|
COMMENT ON FUNCTION camera_models_to_history IS 'Maintains historical versions of camera models';
|
|
|
|
-- ==========================================
|
|
-- FUNCTION: Maintain Combos History
|
|
-- ==========================================
|
|
CREATE OR REPLACE FUNCTION lens_shutter_combos_to_history()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF TG_OP = 'UPDATE' THEN
|
|
INSERT INTO lens_shutter_combos_history (
|
|
id, housing_variant_id, goergens_combo_number, lens_id, shutter_id,
|
|
weight_g, width_mm, height_mm, depth_mm, specs,
|
|
version, changed_at, changed_by, change_type
|
|
)
|
|
VALUES (
|
|
OLD.id, OLD.housing_variant_id, OLD.goergens_combo_number, OLD.lens_id, OLD.shutter_id,
|
|
OLD.weight_g, OLD.width_mm, OLD.height_mm, OLD.depth_mm, OLD.specs,
|
|
OLD.version, NOW(), NEW.updated_by, 'UPDATE'
|
|
);
|
|
ELSIF TG_OP = 'DELETE' THEN
|
|
INSERT INTO lens_shutter_combos_history (
|
|
id, housing_variant_id, goergens_combo_number, lens_id, shutter_id,
|
|
weight_g, width_mm, height_mm, depth_mm, specs,
|
|
version, changed_at, changed_by, change_type
|
|
)
|
|
VALUES (
|
|
OLD.id, OLD.housing_variant_id, OLD.goergens_combo_number, OLD.lens_id, OLD.shutter_id,
|
|
OLD.weight_g, OLD.width_mm, OLD.height_mm, OLD.depth_mm, OLD.specs,
|
|
OLD.version, NOW(), NULL, 'DELETE'
|
|
);
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER trg_combos_history
|
|
AFTER UPDATE OR DELETE ON lens_shutter_combos
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION lens_shutter_combos_to_history();
|
|
|
|
COMMENT ON FUNCTION lens_shutter_combos_to_history IS 'Maintains historical versions of camera combinations';
|
|
|
|
-- ==========================================
|
|
-- FUNCTION: Validate Goergens ID Structure
|
|
-- ==========================================
|
|
CREATE OR REPLACE FUNCTION validate_goergens_structure()
|
|
RETURNS TABLE(combo_id INT, goergens_id VARCHAR, issue TEXT) AS $$
|
|
BEGIN
|
|
-- Check model numbers are consistent
|
|
RETURN QUERY
|
|
SELECT
|
|
lsc.id,
|
|
lsc.goergens_full_id,
|
|
'Inconsistent model number in same camera_model'::TEXT AS issue
|
|
FROM lens_shutter_combos lsc
|
|
JOIN housing_variants hv ON lsc.housing_variant_id = hv.id
|
|
JOIN camera_models cm ON hv.camera_model_id = cm.id
|
|
WHERE split_part(lsc.goergens_full_id, ' ', 3) != cm.goergens_model_number;
|
|
|
|
-- Check variant letters are consistent
|
|
RETURN QUERY
|
|
SELECT
|
|
lsc.id,
|
|
lsc.goergens_full_id,
|
|
'Inconsistent variant letter'::TEXT AS issue
|
|
FROM lens_shutter_combos lsc
|
|
JOIN housing_variants hv ON lsc.housing_variant_id = hv.id
|
|
WHERE substring(split_part(lsc.goergens_full_id, ' ', 4), 1, 1) != hv.goergens_variant_letter;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
COMMENT ON FUNCTION validate_goergens_structure IS 'Validates that Goergens IDs match the hierarchy structure';
|