168 lines
5.3 KiB
SQL
168 lines
5.3 KiB
SQL
-- ==========================================
|
|
-- CLUB DAGUERRE CAMERA DATABASE
|
|
-- Part 2: Supporting Data
|
|
-- ==========================================
|
|
|
|
-- ==========================================
|
|
-- LENSES
|
|
-- ==========================================
|
|
CREATE TABLE lenses (
|
|
id SERIAL PRIMARY KEY,
|
|
name VARCHAR(200) NOT NULL,
|
|
manufacturer VARCHAR(100),
|
|
focal_length_mm INT,
|
|
max_aperture DECIMAL(3,1),
|
|
lens_type VARCHAR(50),
|
|
mount_type VARCHAR(50),
|
|
|
|
notes TEXT,
|
|
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
created_by INT,
|
|
updated_at TIMESTAMP,
|
|
updated_by INT,
|
|
|
|
CONSTRAINT chk_focal_length CHECK (focal_length_mm IS NULL OR focal_length_mm > 0),
|
|
CONSTRAINT chk_aperture CHECK (max_aperture IS NULL OR (max_aperture > 0 AND max_aperture < 32))
|
|
);
|
|
|
|
CREATE INDEX idx_lenses_name ON lenses(name);
|
|
CREATE INDEX idx_lenses_mfg ON lenses(manufacturer);
|
|
CREATE INDEX idx_lenses_focal ON lenses(focal_length_mm);
|
|
CREATE INDEX idx_lenses_aperture ON lenses(max_aperture);
|
|
|
|
COMMENT ON TABLE lenses IS 'Lens catalog - reusable across cameras';
|
|
|
|
-- Add foreign key to lens_shutter_combos
|
|
ALTER TABLE lens_shutter_combos
|
|
ADD CONSTRAINT fk_lens FOREIGN KEY (lens_id) REFERENCES lenses(id);
|
|
|
|
-- ==========================================
|
|
-- SHUTTERS
|
|
-- ==========================================
|
|
CREATE TABLE shutters (
|
|
id SERIAL PRIMARY KEY,
|
|
name VARCHAR(100) NOT NULL,
|
|
manufacturer VARCHAR(100),
|
|
shutter_type VARCHAR(50),
|
|
speed_range VARCHAR(100),
|
|
|
|
notes TEXT,
|
|
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
created_by INT,
|
|
updated_at TIMESTAMP,
|
|
updated_by INT
|
|
);
|
|
|
|
CREATE INDEX idx_shutters_name ON shutters(name);
|
|
CREATE INDEX idx_shutters_type ON shutters(shutter_type);
|
|
|
|
COMMENT ON TABLE shutters IS 'Shutter catalog - reusable across cameras';
|
|
|
|
-- Add foreign key to lens_shutter_combos
|
|
ALTER TABLE lens_shutter_combos
|
|
ADD CONSTRAINT fk_shutter FOREIGN KEY (shutter_id) REFERENCES shutters(id);
|
|
|
|
-- ==========================================
|
|
-- FILM FORMATS
|
|
-- ==========================================
|
|
CREATE TABLE formats (
|
|
id SERIAL PRIMARY KEY,
|
|
format_code VARCHAR(20) UNIQUE NOT NULL,
|
|
width_mm DECIMAL(6,2),
|
|
height_mm DECIMAL(6,2),
|
|
format_type VARCHAR(20),
|
|
|
|
description_de TEXT,
|
|
description_en TEXT,
|
|
|
|
sort_order INT
|
|
);
|
|
|
|
CREATE INDEX idx_formats_code ON formats(format_code);
|
|
CREATE INDEX idx_formats_type ON formats(format_type);
|
|
|
|
COMMENT ON TABLE formats IS 'Film format definitions';
|
|
|
|
-- ==========================================
|
|
-- CONCEPTS (Multilingual Terminology)
|
|
-- ==========================================
|
|
CREATE TABLE concepts (
|
|
id SERIAL PRIMARY KEY,
|
|
concept_code VARCHAR(50) UNIQUE NOT NULL,
|
|
category VARCHAR(50) NOT NULL,
|
|
sort_order INT DEFAULT 0
|
|
);
|
|
|
|
COMMENT ON TABLE concepts IS 'Terminology concepts - language-agnostic';
|
|
|
|
-- ==========================================
|
|
-- CONCEPT TERMS (Translations)
|
|
-- ==========================================
|
|
CREATE TABLE concept_terms (
|
|
id SERIAL PRIMARY KEY,
|
|
concept_id INT NOT NULL REFERENCES concepts(id) ON DELETE CASCADE,
|
|
language_code VARCHAR(5) NOT NULL,
|
|
term VARCHAR(200) NOT NULL,
|
|
term_type VARCHAR(20) NOT NULL,
|
|
|
|
UNIQUE(concept_id, language_code, term_type),
|
|
CONSTRAINT chk_term_type CHECK (term_type IN ('primary', 'abbreviation', 'synonym'))
|
|
);
|
|
|
|
CREATE INDEX idx_terms_concept ON concept_terms(concept_id);
|
|
CREATE INDEX idx_terms_language ON concept_terms(language_code);
|
|
CREATE INDEX idx_terms_term ON concept_terms(term);
|
|
|
|
COMMENT ON TABLE concept_terms IS 'Multilingual terms for concepts';
|
|
|
|
-- ==========================================
|
|
-- TERMINOLOGY VIEW (Backwards Compatibility)
|
|
-- ==========================================
|
|
CREATE VIEW terminology AS
|
|
SELECT
|
|
c.concept_code,
|
|
c.category,
|
|
MAX(CASE WHEN ct.language_code = 'de' AND ct.term_type = 'primary' THEN ct.term END) AS term_de,
|
|
MAX(CASE WHEN ct.language_code = 'en' AND ct.term_type = 'primary' THEN ct.term END) AS term_en,
|
|
MAX(CASE WHEN ct.language_code = 'de' AND ct.term_type = 'abbreviation' THEN ct.term END) AS abbreviation
|
|
FROM concepts c
|
|
LEFT JOIN concept_terms ct ON c.id = ct.concept_id
|
|
GROUP BY c.concept_code, c.category;
|
|
|
|
COMMENT ON VIEW terminology IS 'Simple view of German/English terms for quick lookups';
|
|
|
|
-- ==========================================
|
|
-- SERIAL NUMBERS (Authentication Database)
|
|
-- ==========================================
|
|
CREATE TABLE serial_numbers (
|
|
id SERIAL PRIMARY KEY,
|
|
camera_model_id INT NOT NULL REFERENCES camera_models(id) ON DELETE CASCADE,
|
|
|
|
-- PostgreSQL range types for proper validation
|
|
serial_range INT4RANGE NOT NULL,
|
|
year_range INT4RANGE NOT NULL,
|
|
|
|
variant_notes VARCHAR(200),
|
|
production_notes TEXT,
|
|
source VARCHAR(200),
|
|
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
created_by INT,
|
|
updated_at TIMESTAMP,
|
|
|
|
-- Prevent overlapping serial ranges
|
|
CONSTRAINT no_serial_overlap EXCLUDE USING GIST (
|
|
camera_model_id WITH =,
|
|
serial_range WITH &&
|
|
)
|
|
);
|
|
|
|
CREATE INDEX idx_serials_model ON serial_numbers(camera_model_id);
|
|
CREATE INDEX idx_serials_range ON serial_numbers USING GIST(serial_range);
|
|
CREATE INDEX idx_serials_year ON serial_numbers USING GIST(year_range);
|
|
|
|
COMMENT ON TABLE serial_numbers IS 'Serial number ranges for camera authentication';
|
|
COMMENT ON COLUMN serial_numbers.serial_range IS 'Query: WHERE serial_range @> 52103 to check if serial is genuine';
|