Complete database schema v1.0

- 26 tables for Goergens hierarchy + content + auth
- Multi-level linking for images/documents/articles
- Rights management (verified/uncertain/restricted)
- Denormalized fields for performance
- 3 materialized views for dashboard/search
- Audit trail with history tables
- Multilingual terminology system
- PostgreSQL 16 features (JSONB, ranges, GIN/GIST indexes)

Ready for Goergens data import (74,000+ cameras)
This commit is contained in:
Walter Jekat 2025-11-17 20:37:15 +01:00
parent b52d3347e1
commit 10f7d7c8a4
9 changed files with 1771 additions and 0 deletions

View File

@ -0,0 +1,218 @@
-- ==========================================
-- CLUB DAGUERRE CAMERA DATABASE
-- Part 1: Core Hierarchy
-- ==========================================
-- Enable required extensions
CREATE EXTENSION IF NOT EXISTS btree_gist;
-- ==========================================
-- MANUFACTURERS
-- ==========================================
CREATE TABLE manufacturers (
id SERIAL PRIMARY KEY,
goergens_code VARCHAR(4) UNIQUE NOT NULL,
name VARCHAR(200) NOT NULL,
country VARCHAR(3),
years_active INT4RANGE,
-- Audit
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
created_by INT,
updated_at TIMESTAMP,
updated_by INT,
version INT DEFAULT 1,
deleted_at TIMESTAMP,
CONSTRAINT chk_mfg_code CHECK (goergens_code ~ '^[A-Z]{2,4}$')
);
CREATE INDEX idx_mfg_name ON manufacturers(name);
CREATE INDEX idx_mfg_country ON manufacturers(country);
CREATE INDEX idx_mfg_active ON manufacturers(id) WHERE deleted_at IS NULL;
COMMENT ON TABLE manufacturers IS 'Camera manufacturers - top level of Goergens hierarchy';
COMMENT ON COLUMN manufacturers.goergens_code IS 'Goergens manufacturer code (e.g., ERNM, ZEII)';
-- ==========================================
-- CAMERA MODELS
-- ==========================================
CREATE TABLE camera_models (
id SERIAL PRIMARY KEY,
manufacturer_id INT NOT NULL REFERENCES manufacturers(id),
goergens_model_number VARCHAR(10) NOT NULL,
-- Goergens classification codes
body_type VARCHAR(2) NOT NULL,
viewfinder_type VARCHAR(4),
format_code VARCHAR(20) NOT NULL,
-- Production years
year_first INT,
year_last INT,
-- Audit
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
created_by INT,
updated_at TIMESTAMP,
updated_by INT,
version INT DEFAULT 1,
deleted_at TIMESTAMP,
UNIQUE(manufacturer_id, goergens_model_number),
CONSTRAINT chk_years CHECK (year_first IS NULL OR year_last IS NULL OR year_first <= year_last),
CONSTRAINT chk_body_type CHECK (body_type ~ '^[A-Z][a-z]?$')
);
CREATE INDEX idx_models_manufacturer ON camera_models(manufacturer_id);
CREATE INDEX idx_models_type ON camera_models(body_type, viewfinder_type);
CREATE INDEX idx_models_format ON camera_models(format_code);
CREATE INDEX idx_models_years ON camera_models(year_first, year_last);
CREATE INDEX idx_models_active ON camera_models(id) WHERE deleted_at IS NULL;
COMMENT ON TABLE camera_models IS 'Camera models - grouping level in Goergens system';
COMMENT ON COLUMN camera_models.goergens_model_number IS 'Model number from Goergens ID (e.g., 1910 for Bob IV)';
-- ==========================================
-- CAMERA MODEL I18N
-- ==========================================
CREATE TABLE camera_model_i18n (
camera_model_id INT PRIMARY KEY REFERENCES camera_models(id) ON DELETE CASCADE,
model_name VARCHAR(200),
description_de TEXT,
description_en TEXT,
marketing_name_de VARCHAR(200),
marketing_name_en VARCHAR(200),
-- Full-text search vectors
search_vector_de TSVECTOR GENERATED ALWAYS AS (
to_tsvector('german', COALESCE(model_name, '') || ' ' || COALESCE(description_de, ''))
) STORED,
search_vector_en TSVECTOR GENERATED ALWAYS AS (
to_tsvector('english', COALESCE(model_name, '') || ' ' || COALESCE(description_en, ''))
) STORED
);
CREATE INDEX idx_i18n_fts_de ON camera_model_i18n USING GIN(search_vector_de);
CREATE INDEX idx_i18n_fts_en ON camera_model_i18n USING GIN(search_vector_en);
COMMENT ON TABLE camera_model_i18n IS 'Multilingual content for camera models';
-- ==========================================
-- HOUSING VARIANTS
-- ==========================================
CREATE TABLE housing_variants (
id SERIAL PRIMARY KEY,
camera_model_id INT NOT NULL REFERENCES camera_models(id) ON DELETE CASCADE,
goergens_variant_letter VARCHAR(2) NOT NULL,
color VARCHAR(50),
body_material VARCHAR(50),
distinguishing_features TEXT,
-- Audit
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
created_by INT,
updated_at TIMESTAMP,
updated_by INT,
version INT DEFAULT 1,
deleted_at TIMESTAMP,
UNIQUE(camera_model_id, goergens_variant_letter),
CONSTRAINT chk_variant_letter CHECK (goergens_variant_letter ~ '^[a-z]{1,2}$')
);
CREATE INDEX idx_variants_model ON housing_variants(camera_model_id);
CREATE INDEX idx_variants_active ON housing_variants(id) WHERE deleted_at IS NULL;
COMMENT ON TABLE housing_variants IS 'Housing variants - color, material variations';
COMMENT ON COLUMN housing_variants.goergens_variant_letter IS 'Variant letter from Goergens ID (a, b, c, etc.)';
-- ==========================================
-- LENS/SHUTTER COMBINATIONS
-- ==========================================
CREATE TABLE lens_shutter_combos (
id SERIAL PRIMARY KEY,
housing_variant_id INT NOT NULL REFERENCES housing_variants(id) ON DELETE CASCADE,
goergens_combo_number VARCHAR(3) NOT NULL,
lens_id INT,
shutter_id INT,
-- DENORMALIZED FIELDS FOR PERFORMANCE
manufacturer_id INT,
camera_model_id INT,
goergens_full_id VARCHAR(50),
display_name TEXT,
-- STRUCTURED TECHNICAL SPECS
weight_g INT,
width_mm DECIMAL(6,2),
height_mm DECIMAL(6,2),
depth_mm DECIMAL(6,2),
-- FLEXIBLE SPECS (JSONB)
specs JSONB,
-- Full-text search
search_text TEXT,
-- Audit
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
created_by INT,
updated_at TIMESTAMP,
updated_by INT,
version INT DEFAULT 1,
deleted_at TIMESTAMP,
UNIQUE(housing_variant_id, goergens_combo_number),
CONSTRAINT chk_weight CHECK (weight_g IS NULL OR (weight_g > 0 AND weight_g < 50000)),
CONSTRAINT chk_dimensions CHECK (
width_mm IS NULL OR height_mm IS NULL OR depth_mm IS NULL OR
(width_mm > 0 AND height_mm > 0 AND depth_mm > 0)
)
);
-- Critical indexes
CREATE INDEX idx_combos_variant ON lens_shutter_combos(housing_variant_id);
CREATE INDEX idx_combos_lens ON lens_shutter_combos(lens_id);
CREATE INDEX idx_combos_shutter ON lens_shutter_combos(shutter_id);
-- Denormalized indexes (performance boost)
CREATE INDEX idx_combos_manufacturer ON lens_shutter_combos(manufacturer_id);
CREATE INDEX idx_combos_model ON lens_shutter_combos(camera_model_id);
CREATE INDEX idx_combos_goergens_id ON lens_shutter_combos(goergens_full_id);
-- JSONB and full-text search
CREATE INDEX idx_combos_specs ON lens_shutter_combos USING GIN(specs);
CREATE INDEX idx_combos_fts ON lens_shutter_combos USING GIN(to_tsvector('german', COALESCE(search_text, '')));
CREATE INDEX idx_combos_active ON lens_shutter_combos(id) WHERE deleted_at IS NULL;
COMMENT ON TABLE lens_shutter_combos IS 'Lens/shutter combinations - lowest level of hierarchy';
COMMENT ON COLUMN lens_shutter_combos.goergens_full_id IS 'Complete Goergens ID (e.g., ERNM K 1910 a01)';
COMMENT ON COLUMN lens_shutter_combos.specs IS 'Flexible technical specs as JSON (body_material, bellows_color, etc.)';
-- ==========================================
-- CAMERA RELATIONSHIPS
-- ==========================================
CREATE TABLE camera_relations (
id SERIAL PRIMARY KEY,
source_combo_id INT NOT NULL REFERENCES lens_shutter_combos(id) ON DELETE CASCADE,
related_combo_id INT NOT NULL REFERENCES lens_shutter_combos(id) ON DELETE CASCADE,
relationship_type VARCHAR(50) NOT NULL,
notes TEXT,
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
created_by INT,
UNIQUE(source_combo_id, related_combo_id, relationship_type),
CONSTRAINT chk_not_self CHECK (source_combo_id != related_combo_id),
CONSTRAINT chk_relationship_type CHECK (relationship_type IN ('successor', 'predecessor', 'similar', 'variant_of', 'replaced_by'))
);
CREATE INDEX idx_relations_source ON camera_relations(source_combo_id);
CREATE INDEX idx_relations_target ON camera_relations(related_combo_id);
CREATE INDEX idx_relations_type ON camera_relations(relationship_type);
COMMENT ON TABLE camera_relations IS 'Relationships between cameras (evolution, variants, etc.)';

167
schema/02-supporting.sql Normal file
View File

@ -0,0 +1,167 @@
-- ==========================================
-- 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';

294
schema/03-content.sql Normal file
View File

@ -0,0 +1,294 @@
-- ==========================================
-- CLUB DAGUERRE CAMERA DATABASE
-- Part 3: Content & Media
-- ==========================================
-- ==========================================
-- CONTENT SOURCES (Provenance Tracking)
-- ==========================================
CREATE TABLE content_sources (
id SERIAL PRIMARY KEY,
source_name VARCHAR(100) NOT NULL,
source_type VARCHAR(50) NOT NULL,
rights_status VARCHAR(50) NOT NULL,
legal_notes TEXT,
contact_info TEXT,
verified_by VARCHAR(100),
verified_date DATE,
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
CONSTRAINT chk_source_type CHECK (source_type IN ('internal', 'licensed', 'uncertain', 'public_domain')),
CONSTRAINT chk_rights_status CHECK (rights_status IN ('owned', 'licensed', 'questionable', 'public_domain'))
);
COMMENT ON TABLE content_sources IS 'Provenance tracking for all content';
-- ==========================================
-- IMAGES (Unified with Rights Status)
-- ==========================================
CREATE TABLE images (
id SERIAL PRIMARY KEY,
filename VARCHAR(255) NOT NULL,
sort_order INT NOT NULL DEFAULT 0,
caption TEXT,
-- FLEXIBLE MULTI-LEVEL LINKING (only ONE should be set)
manufacturer_id INT REFERENCES manufacturers(id),
camera_model_id INT REFERENCES camera_models(id),
housing_variant_id INT REFERENCES housing_variants(id),
combo_id INT REFERENCES lens_shutter_combos(id),
-- RIGHTS MANAGEMENT
rights_status VARCHAR(20) NOT NULL,
source_id INT NOT NULL REFERENCES content_sources(id),
-- Verified images
photographer VARCHAR(100),
photo_date DATE,
rights_holder VARCHAR(200),
license_type VARCHAR(50),
-- Uncertain images
why_uncertain TEXT,
usage_restriction VARCHAR(50),
clearance_status VARCHAR(50),
-- Metadata
file_size_kb INT,
width_px INT,
height_px INT,
mime_type VARCHAR(50),
-- Audit
uploaded_by INT,
upload_date TIMESTAMP NOT NULL DEFAULT NOW(),
verified_clean BOOLEAN DEFAULT FALSE,
verified_by VARCHAR(100),
verified_date DATE,
updated_at TIMESTAMP,
deleted_at TIMESTAMP,
-- Exactly ONE link must be set
CONSTRAINT chk_image_link CHECK (
(manufacturer_id IS NOT NULL AND camera_model_id IS NULL AND housing_variant_id IS NULL AND combo_id IS NULL) OR
(manufacturer_id IS NULL AND camera_model_id IS NOT NULL AND housing_variant_id IS NULL AND combo_id IS NULL) OR
(manufacturer_id IS NULL AND camera_model_id IS NULL AND housing_variant_id IS NOT NULL AND combo_id IS NULL) OR
(manufacturer_id IS NULL AND camera_model_id IS NULL AND housing_variant_id IS NULL AND combo_id IS NOT NULL)
),
CONSTRAINT chk_rights_status CHECK (rights_status IN ('verified', 'uncertain', 'restricted')),
CONSTRAINT chk_uncertain_fields CHECK (
(rights_status = 'uncertain' AND why_uncertain IS NOT NULL) OR
(rights_status = 'verified' AND why_uncertain IS NULL)
),
CONSTRAINT chk_sort_order CHECK (sort_order >= 0)
);
-- Indexes for each link type
CREATE INDEX idx_images_manufacturer ON images(manufacturer_id) WHERE manufacturer_id IS NOT NULL;
CREATE INDEX idx_images_model ON images(camera_model_id) WHERE camera_model_id IS NOT NULL;
CREATE INDEX idx_images_variant ON images(housing_variant_id) WHERE housing_variant_id IS NOT NULL;
CREATE INDEX idx_images_combo ON images(combo_id) WHERE combo_id IS NOT NULL;
CREATE INDEX idx_images_source ON images(source_id);
CREATE INDEX idx_images_status ON images(rights_status);
-- Partial indexes for performance
CREATE INDEX idx_images_verified_model ON images(camera_model_id, sort_order)
WHERE rights_status = 'verified' AND camera_model_id IS NOT NULL;
CREATE INDEX idx_images_uncertain ON images(camera_model_id)
WHERE rights_status = 'uncertain' AND camera_model_id IS NOT NULL;
CREATE INDEX idx_images_primary ON images(camera_model_id)
WHERE sort_order = 0 AND rights_status = 'verified' AND camera_model_id IS NOT NULL;
COMMENT ON TABLE images IS 'Images with multi-level linking and rights management';
COMMENT ON COLUMN images.rights_status IS 'verified=publishable, uncertain=research only, restricted=internal only';
-- ==========================================
-- DOCUMENTS (Manuals, Brochures, etc.)
-- ==========================================
CREATE TABLE documents (
id SERIAL PRIMARY KEY,
-- FLEXIBLE MULTI-LEVEL LINKING (only ONE should be set)
manufacturer_id INT REFERENCES manufacturers(id),
camera_model_id INT REFERENCES camera_models(id),
housing_variant_id INT REFERENCES housing_variants(id),
combo_id INT REFERENCES lens_shutter_combos(id),
-- Document classification
document_type VARCHAR(50) NOT NULL,
file_path VARCHAR(500),
title TEXT,
language VARCHAR(5),
page_count INT,
publication_date DATE,
-- Rights
rights_status VARCHAR(20) DEFAULT 'safe',
source_id INT REFERENCES content_sources(id),
why_safe TEXT,
-- Metadata
file_size_kb INT,
mime_type VARCHAR(50),
-- Audit
uploaded_by INT,
upload_date TIMESTAMP NOT NULL DEFAULT NOW(),
updated_at TIMESTAMP,
deleted_at TIMESTAMP,
-- Exactly ONE link must be set
CONSTRAINT chk_doc_link CHECK (
(manufacturer_id IS NOT NULL AND camera_model_id IS NULL AND housing_variant_id IS NULL AND combo_id IS NULL) OR
(manufacturer_id IS NULL AND camera_model_id IS NOT NULL AND housing_variant_id IS NULL AND combo_id IS NULL) OR
(manufacturer_id IS NULL AND camera_model_id IS NULL AND housing_variant_id IS NOT NULL AND combo_id IS NULL) OR
(manufacturer_id IS NULL AND camera_model_id IS NULL AND housing_variant_id IS NULL AND combo_id IS NOT NULL)
),
CONSTRAINT chk_doc_type CHECK (document_type IN (
'user_manual', 'repair_manual', 'brochure', 'advertisement',
'price_list', 'catalog', 'technical_spec', 'patent', 'parts_list'
))
);
-- Indexes for each link type
CREATE INDEX idx_docs_manufacturer ON documents(manufacturer_id) WHERE manufacturer_id IS NOT NULL;
CREATE INDEX idx_docs_model ON documents(camera_model_id) WHERE camera_model_id IS NOT NULL;
CREATE INDEX idx_docs_variant ON documents(housing_variant_id) WHERE housing_variant_id IS NOT NULL;
CREATE INDEX idx_docs_combo ON documents(combo_id) WHERE combo_id IS NOT NULL;
CREATE INDEX idx_docs_type ON documents(document_type);
CREATE INDEX idx_docs_language ON documents(language);
COMMENT ON TABLE documents IS 'Documents with multi-level linking - manuals, brochures, repair manuals, etc.';
-- ==========================================
-- ARTICLES
-- ==========================================
CREATE TABLE articles (
id SERIAL PRIMARY KEY,
-- Publication info
publication_code VARCHAR(10),
issue_number INT,
year INT,
page INT,
-- Content
title TEXT NOT NULL,
author VARCHAR(200),
language VARCHAR(5) DEFAULT 'de',
content TEXT,
abstract TEXT,
-- Rights management
rights_status VARCHAR(20) NOT NULL DEFAULT 'verified',
source_id INT REFERENCES content_sources(id),
publication_owns_rights BOOLEAN DEFAULT FALSE,
digitization_rights_cleared BOOLEAN DEFAULT FALSE,
why_uncertain TEXT,
usage_restriction VARCHAR(50),
-- Full-text search
search_vector TSVECTOR GENERATED ALWAYS AS (
to_tsvector('german', title || ' ' || COALESCE(author, '') || ' ' || COALESCE(abstract, ''))
) STORED,
-- Audit
digitized_by VARCHAR(100),
digitized_date DATE,
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
created_by INT,
updated_at TIMESTAMP,
deleted_at TIMESTAMP,
CONSTRAINT chk_article_rights CHECK (
(rights_status = 'uncertain' AND content IS NULL) OR
(rights_status = 'verified')
)
);
CREATE INDEX idx_articles_pub ON articles(publication_code, issue_number);
CREATE INDEX idx_articles_year ON articles(year);
CREATE INDEX idx_articles_author ON articles(author);
CREATE INDEX idx_articles_status ON articles(rights_status);
CREATE INDEX idx_articles_fts ON articles USING GIN(search_vector);
COMMENT ON TABLE articles IS 'Magazine articles - Photo Antiquaria, Club Daguerre aktuell, etc.';
-- ==========================================
-- CAMERA-ARTICLE LINKS (Many-to-Many with Multi-Level)
-- ==========================================
CREATE TABLE camera_articles (
id SERIAL PRIMARY KEY,
article_id INT NOT NULL REFERENCES articles(id) ON DELETE CASCADE,
-- FLEXIBLE MULTI-LEVEL LINKING (only ONE should be set)
manufacturer_id INT REFERENCES manufacturers(id),
camera_model_id INT REFERENCES camera_models(id),
housing_variant_id INT REFERENCES housing_variants(id),
combo_id INT REFERENCES lens_shutter_combos(id),
relevance VARCHAR(20),
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
created_by INT,
-- Exactly ONE link must be set
CONSTRAINT chk_article_link CHECK (
(manufacturer_id IS NOT NULL AND camera_model_id IS NULL AND housing_variant_id IS NULL AND combo_id IS NULL) OR
(manufacturer_id IS NULL AND camera_model_id IS NOT NULL AND housing_variant_id IS NULL AND combo_id IS NULL) OR
(manufacturer_id IS NULL AND camera_model_id IS NULL AND housing_variant_id IS NOT NULL AND combo_id IS NULL) OR
(manufacturer_id IS NULL AND camera_model_id IS NULL AND housing_variant_id IS NULL AND combo_id IS NOT NULL)
),
CONSTRAINT chk_relevance CHECK (relevance IN ('primary', 'mentioned', 'comparison')),
UNIQUE(article_id, manufacturer_id, camera_model_id, housing_variant_id, combo_id)
);
CREATE INDEX idx_ca_article ON camera_articles(article_id);
CREATE INDEX idx_ca_manufacturer ON camera_articles(manufacturer_id) WHERE manufacturer_id IS NOT NULL;
CREATE INDEX idx_ca_model ON camera_articles(camera_model_id) WHERE camera_model_id IS NOT NULL;
CREATE INDEX idx_ca_variant ON camera_articles(housing_variant_id) WHERE housing_variant_id IS NOT NULL;
CREATE INDEX idx_ca_combo ON camera_articles(combo_id) WHERE combo_id IS NOT NULL;
COMMENT ON TABLE camera_articles IS 'Links articles to cameras at appropriate hierarchy level';
-- ==========================================
-- ANNOTATIONS (User Contributions)
-- ==========================================
CREATE TABLE annotations (
id SERIAL PRIMARY KEY,
combo_id INT NOT NULL REFERENCES lens_shutter_combos(id) ON DELETE CASCADE,
annotation_type VARCHAR(50) NOT NULL,
-- Bilingual content
content_de TEXT,
content_en TEXT,
source_language VARCHAR(5),
-- Attribution
contributed_by INT,
contribution_date TIMESTAMP NOT NULL DEFAULT NOW(),
-- Moderation
approved BOOLEAN DEFAULT FALSE,
approved_by INT,
approved_date TIMESTAMP,
updated_at TIMESTAMP,
deleted_at TIMESTAMP,
CONSTRAINT chk_annotation_type CHECK (annotation_type IN ('historical_note', 'anecdote', 'provenance', 'usage_note', 'technical_note'))
);
CREATE INDEX idx_annotations_combo ON annotations(combo_id);
CREATE INDEX idx_annotations_type ON annotations(annotation_type);
CREATE INDEX idx_annotations_approved ON annotations(approved);
COMMENT ON TABLE annotations IS 'User-contributed notes and information';

129
schema/04-auth.sql Normal file
View File

@ -0,0 +1,129 @@
-- ==========================================
-- CLUB DAGUERRE CAMERA DATABASE
-- Part 4: Authentication & Members
-- ==========================================
-- ==========================================
-- MEMBERS (Tier 1 Authentication)
-- ==========================================
CREATE TABLE members (
id SERIAL PRIMARY KEY,
member_number VARCHAR(20) UNIQUE,
email VARCHAR(200) UNIQUE NOT NULL,
name VARCHAR(200) NOT NULL,
password_hash VARCHAR(255),
-- Account status
account_active BOOLEAN DEFAULT TRUE,
member_since DATE,
membership_expires DATE,
-- Permissions
can_view_public BOOLEAN DEFAULT TRUE,
can_view_member_content BOOLEAN DEFAULT TRUE,
can_contribute BOOLEAN DEFAULT FALSE,
is_admin BOOLEAN DEFAULT FALSE,
-- Audit
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
last_login TIMESTAMP,
login_count INT DEFAULT 0
);
CREATE INDEX idx_members_email ON members(email);
CREATE INDEX idx_members_number ON members(member_number);
CREATE INDEX idx_members_active ON members(id) WHERE account_active = TRUE;
COMMENT ON TABLE members IS 'Club members - basic authentication and permissions';
-- ==========================================
-- RESEARCH ACCESS (Tier 2 Authentication)
-- ==========================================
CREATE TABLE research_access (
id SERIAL PRIMARY KEY,
member_id INT NOT NULL REFERENCES members(id) ON DELETE CASCADE,
has_research_access BOOLEAN DEFAULT FALSE,
access_granted_by VARCHAR(100),
access_granted_date DATE,
access_expires DATE,
research_purpose TEXT,
institution VARCHAR(200),
-- Usage tracking
access_count INT DEFAULT 0,
last_research_access TIMESTAMP,
notes TEXT
);
CREATE INDEX idx_research_member ON research_access(member_id);
CREATE INDEX idx_research_active ON research_access(member_id)
WHERE has_research_access = TRUE AND (access_expires IS NULL OR access_expires > CURRENT_DATE);
COMMENT ON TABLE research_access IS 'Research access grants for viewing uncertain content';
-- ==========================================
-- RESEARCH SESSIONS
-- ==========================================
CREATE TABLE research_sessions (
id SERIAL PRIMARY KEY,
member_id INT NOT NULL REFERENCES members(id) ON DELETE CASCADE,
session_token VARCHAR(64) UNIQUE NOT NULL,
ip_address INET,
user_agent TEXT,
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
expires_at TIMESTAMP NOT NULL,
last_activity TIMESTAMP,
resources_accessed TEXT[]
);
CREATE INDEX idx_sessions_member ON research_sessions(member_id);
CREATE INDEX idx_sessions_token ON research_sessions(session_token);
CREATE INDEX idx_sessions_active ON research_sessions(expires_at)
WHERE expires_at > NOW();
COMMENT ON TABLE research_sessions IS 'Active research sessions for audit trail';
-- ==========================================
-- SYSTEM CONFIG (Shared Settings)
-- ==========================================
CREATE TABLE system_config (
key VARCHAR(100) PRIMARY KEY,
value TEXT,
description TEXT,
updated_by VARCHAR(100),
updated_at TIMESTAMP DEFAULT NOW()
);
COMMENT ON TABLE system_config IS 'System-wide configuration (including research password hash)';
-- ==========================================
-- AUDIT LOG
-- ==========================================
CREATE TABLE audit_log (
id BIGSERIAL PRIMARY KEY,
member_id INT REFERENCES members(id),
action VARCHAR(100) NOT NULL,
resource_type VARCHAR(50),
resource_id INT,
ip_address INET,
user_agent TEXT,
details JSONB,
timestamp TIMESTAMP NOT NULL DEFAULT NOW()
);
CREATE INDEX idx_audit_member ON audit_log(member_id);
CREATE INDEX idx_audit_action ON audit_log(action);
CREATE INDEX idx_audit_timestamp ON audit_log(timestamp DESC);
CREATE INDEX idx_audit_resource ON audit_log(resource_type, resource_id);
COMMENT ON TABLE audit_log IS 'Comprehensive audit log for all user actions';

89
schema/05-history.sql Normal file
View File

@ -0,0 +1,89 @@
-- ==========================================
-- 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';

220
schema/06-triggers.sql Normal file
View File

@ -0,0 +1,220 @@
-- ==========================================
-- 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';

305
schema/07-views.sql Normal file
View File

@ -0,0 +1,305 @@
-- ==========================================
-- CLUB DAGUERRE CAMERA DATABASE
-- Part 7: Materialized Views
-- ==========================================
-- ==========================================
-- MV: MANUFACTURER STATISTICS
-- ==========================================
CREATE MATERIALIZED VIEW mv_manufacturer_stats AS
SELECT
m.id AS manufacturer_id,
m.name AS manufacturer_name,
m.goergens_code,
m.country,
COUNT(DISTINCT cm.id) AS model_count,
COUNT(DISTINCT lsc.id) AS camera_count,
MIN(cm.year_first) AS first_camera_year,
MAX(cm.year_last) AS last_camera_year,
COUNT(DISTINCT CASE WHEN i.rights_status = 'verified' THEN i.id END) AS verified_image_count,
COUNT(DISTINCT CASE WHEN d.document_type = 'user_manual' THEN d.id END) AS manual_count,
COUNT(DISTINCT CASE WHEN d.document_type = 'repair_manual' THEN d.id END) AS repair_manual_count,
COUNT(DISTINCT ca.article_id) AS article_count
FROM manufacturers m
LEFT JOIN camera_models cm ON m.id = cm.manufacturer_id AND cm.deleted_at IS NULL
LEFT JOIN housing_variants hv ON cm.id = hv.camera_model_id AND hv.deleted_at IS NULL
LEFT JOIN lens_shutter_combos lsc ON hv.id = lsc.housing_variant_id AND lsc.deleted_at IS NULL
LEFT JOIN images i ON (
i.manufacturer_id = m.id OR
i.camera_model_id = cm.id OR
i.housing_variant_id = hv.id OR
i.combo_id = lsc.id
) AND i.deleted_at IS NULL
LEFT JOIN documents d ON (
d.manufacturer_id = m.id OR
d.camera_model_id = cm.id OR
d.housing_variant_id = hv.id OR
d.combo_id = lsc.id
) AND d.deleted_at IS NULL
LEFT JOIN camera_articles ca ON (
ca.manufacturer_id = m.id OR
ca.camera_model_id = cm.id OR
ca.housing_variant_id = hv.id OR
ca.combo_id = lsc.id
)
WHERE m.deleted_at IS NULL
GROUP BY m.id, m.name, m.goergens_code, m.country;
CREATE UNIQUE INDEX idx_mv_mfg_stats_id ON mv_manufacturer_stats(manufacturer_id);
CREATE INDEX idx_mv_mfg_stats_name ON mv_manufacturer_stats(manufacturer_name);
CREATE INDEX idx_mv_mfg_stats_country ON mv_manufacturer_stats(country);
COMMENT ON MATERIALIZED VIEW mv_manufacturer_stats IS
'Pre-computed manufacturer statistics. Refresh hourly with: REFRESH MATERIALIZED VIEW CONCURRENTLY mv_manufacturer_stats;';
-- ==========================================
-- MV: PUBLIC CATALOG (Fast Search Index)
-- ==========================================
CREATE MATERIALIZED VIEW mv_public_catalog AS
SELECT
lsc.id AS combo_id,
lsc.goergens_full_id,
lsc.display_name,
m.id AS manufacturer_id,
m.name AS manufacturer_name,
m.country,
cm.id AS model_id,
i18n.model_name,
cm.body_type,
cm.viewfinder_type,
cm.format_code,
cm.year_first,
cm.year_last,
-- Terminology lookups
(SELECT term_de FROM terminology WHERE concept_code = 'BODY_TYPE_' || UPPER(cm.body_type)) AS body_type_de,
(SELECT term_en FROM terminology WHERE concept_code = 'BODY_TYPE_' || UPPER(cm.body_type)) AS body_type_en,
-- Lens info
l.name AS lens_name,
l.focal_length_mm,
l.max_aperture,
-- Shutter info
s.name AS shutter_name,
-- Media flags
EXISTS(
SELECT 1 FROM images
WHERE (combo_id = lsc.id OR camera_model_id = cm.id OR housing_variant_id = hv.id OR manufacturer_id = m.id)
AND rights_status = 'verified'
AND deleted_at IS NULL
) AS has_images,
(
SELECT filename FROM images
WHERE camera_model_id = cm.id
AND rights_status = 'verified'
AND sort_order = 0
AND deleted_at IS NULL
LIMIT 1
) AS primary_image_filename,
EXISTS(
SELECT 1 FROM documents
WHERE (combo_id = lsc.id OR camera_model_id = cm.id)
AND document_type = 'user_manual'
AND deleted_at IS NULL
) AS has_manual,
EXISTS(
SELECT 1 FROM documents
WHERE (combo_id = lsc.id OR camera_model_id = cm.id)
AND document_type = 'repair_manual'
AND deleted_at IS NULL
) AS has_repair_manual,
(
SELECT COUNT(*) FROM camera_articles
WHERE combo_id = lsc.id OR camera_model_id = cm.id
) AS article_count,
-- Search text
m.name || ' ' ||
COALESCE(i18n.model_name, '') || ' ' ||
COALESCE(i18n.description_de, '') || ' ' ||
cm.format_code || ' ' ||
COALESCE(l.name, '') || ' ' ||
COALESCE(s.name, '') AS search_text
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
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 lsc.lens_id = l.id
LEFT JOIN shutters s ON lsc.shutter_id = s.id
WHERE lsc.deleted_at IS NULL
AND hv.deleted_at IS NULL
AND cm.deleted_at IS NULL
AND m.deleted_at IS NULL;
CREATE UNIQUE INDEX idx_mv_catalog_id ON mv_public_catalog(combo_id);
CREATE INDEX idx_mv_catalog_mfg ON mv_public_catalog(manufacturer_name);
CREATE INDEX idx_mv_catalog_years ON mv_public_catalog(year_first, year_last);
CREATE INDEX idx_mv_catalog_body ON mv_public_catalog(body_type);
CREATE INDEX idx_mv_catalog_format ON mv_public_catalog(format_code);
CREATE INDEX idx_mv_catalog_fts ON mv_public_catalog USING GIN(to_tsvector('german', search_text));
COMMENT ON MATERIALIZED VIEW mv_public_catalog IS
'Pre-joined catalog for fast public search. Refresh every 15-30 minutes.';
-- ==========================================
-- MV: DASHBOARD STATISTICS
-- ==========================================
CREATE MATERIALIZED VIEW mv_dashboard_stats AS
SELECT
'total_cameras' AS metric,
COUNT(*)::TEXT AS value,
NOW() AS calculated_at
FROM lens_shutter_combos WHERE deleted_at IS NULL
UNION ALL
SELECT 'total_manufacturers', COUNT(*)::TEXT, NOW()
FROM manufacturers WHERE deleted_at IS NULL
UNION ALL
SELECT 'total_models', COUNT(*)::TEXT, NOW()
FROM camera_models WHERE deleted_at IS NULL
UNION ALL
SELECT 'cameras_with_images', COUNT(DISTINCT combo_id)::TEXT, NOW()
FROM images WHERE rights_status = 'verified' AND deleted_at IS NULL
UNION ALL
SELECT 'cameras_need_images',
(SELECT COUNT(*) FROM lens_shutter_combos lsc
WHERE deleted_at IS NULL
AND NOT EXISTS(
SELECT 1 FROM images
WHERE (combo_id = lsc.id OR camera_model_id = lsc.camera_model_id)
AND deleted_at IS NULL
))::TEXT,
NOW()
UNION ALL
SELECT 'uncertain_images', COUNT(*)::TEXT, NOW()
FROM images WHERE rights_status = 'uncertain' AND deleted_at IS NULL
UNION ALL
SELECT 'total_articles', COUNT(*)::TEXT, NOW()
FROM articles WHERE deleted_at IS NULL
UNION ALL
SELECT 'total_documents', COUNT(*)::TEXT, NOW()
FROM documents WHERE deleted_at IS NULL
UNION ALL
SELECT 'user_manuals', COUNT(*)::TEXT, NOW()
FROM documents WHERE document_type = 'user_manual' AND deleted_at IS NULL
UNION ALL
SELECT 'repair_manuals', COUNT(*)::TEXT, NOW()
FROM documents WHERE document_type = 'repair_manual' AND deleted_at IS NULL
UNION ALL
SELECT 'newest_camera_year', MAX(year_last)::TEXT, NOW()
FROM camera_models WHERE deleted_at IS NULL
UNION ALL
SELECT 'oldest_camera_year', MIN(year_first)::TEXT, NOW()
FROM camera_models WHERE deleted_at IS NULL AND year_first IS NOT NULL;
CREATE INDEX idx_mv_dashboard_metric ON mv_dashboard_stats(metric);
COMMENT ON MATERIALIZED VIEW mv_dashboard_stats IS
'Admin dashboard metrics. Refresh every 5 minutes.';
-- ==========================================
-- CONVENIENCE VIEW: Complete Camera Info
-- ==========================================
CREATE VIEW v_cameras_complete AS
SELECT
lsc.id AS combo_id,
lsc.goergens_full_id,
lsc.display_name,
-- Manufacturer
m.id AS manufacturer_id,
m.name AS manufacturer_name,
m.goergens_code AS manufacturer_code,
m.country,
-- Model
cm.id AS model_id,
i18n.model_name,
cm.body_type,
cm.viewfinder_type,
cm.format_code,
cm.year_first,
cm.year_last,
i18n.description_de,
i18n.description_en,
-- Variant
hv.id AS variant_id,
hv.goergens_variant_letter,
hv.color,
hv.body_material,
-- Combo specifics
lsc.goergens_combo_number,
-- Lens
l.id AS lens_id,
l.name AS lens_name,
l.focal_length_mm,
l.max_aperture,
-- Shutter
s.id AS shutter_id,
s.name AS shutter_name,
s.shutter_type,
-- Technical
lsc.weight_g,
lsc.width_mm,
lsc.height_mm,
lsc.depth_mm,
lsc.specs,
-- Audit
lsc.created_at,
lsc.updated_at,
lsc.version
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
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 lsc.lens_id = l.id
LEFT JOIN shutters s ON lsc.shutter_id = s.id
WHERE lsc.deleted_at IS NULL;
COMMENT ON VIEW v_cameras_complete IS 'Complete camera information with all hierarchy levels joined';

159
schema/08-seed-data.sql Normal file
View File

@ -0,0 +1,159 @@
-- ==========================================
-- CLUB DAGUERRE CAMERA DATABASE
-- Part 8: Seed Data
-- ==========================================
-- ==========================================
-- CONTENT SOURCES
-- ==========================================
INSERT INTO content_sources (source_name, source_type, rights_status, legal_notes, verified_by, verified_date) VALUES
('Club Daguerre - Photo Antiquaria', 'internal', 'owned', 'Club owns publication and digitization rights', 'Walter Jekat', CURRENT_DATE),
('Club Daguerre aktuell', 'internal', 'owned', 'Club publication, full rights', 'Walter Jekat', CURRENT_DATE),
('Harald Goergens Collection', 'licensed', 'owned', 'Harald grants perpetual license for his photos/data to Club Daguerre', 'Walter Jekat', CURRENT_DATE),
('Steimer Database - Images', 'uncertain', 'questionable', 'Source unknown. DO NOT publish without clearance. Internal research only.', NULL, NULL),
('Steimer Database - Text', 'uncertain', 'questionable', 'Text from various publications. Rights status unknown. Use metadata only.', NULL, NULL),
('User Contributed', 'licensed', 'licensed', 'Users grant CC-BY-SA license on upload', 'System', CURRENT_DATE),
('Pre-1923 Public Domain', 'public_domain', 'public_domain', 'Works published before 1923 are public domain', 'Walter Jekat', CURRENT_DATE),
('Manufacturer Marketing', 'public_domain', 'fair_use', 'Brochures, ads, price lists - marketing materials (fair use)', 'Walter Jekat', CURRENT_DATE);
-- ==========================================
-- CORE TERMINOLOGY CONCEPTS
-- ==========================================
-- Body Types
INSERT INTO concepts (concept_code, category, sort_order) VALUES
('BODY_TYPE_LB', 'body_type', 1),
('BODY_TYPE_FG', 'body_type', 2),
('BODY_TYPE_KL', 'body_type', 3),
('BODY_TYPE_SP', 'body_type', 4),
('BODY_TYPE_RK', 'body_type', 5),
('BODY_TYPE_BO', 'body_type', 6),
('BODY_TYPE_TU', 'body_type', 7),
('BODY_TYPE_MG', 'body_type', 8);
-- Body Type Terms
INSERT INTO concept_terms (concept_id, language_code, term, term_type) VALUES
-- Laufboden (Lb)
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_LB'), 'de', 'Laufbodenkamera', 'primary'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_LB'), 'de', 'Lb', 'abbreviation'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_LB'), 'de', 'Laufboden', 'synonym'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_LB'), 'en', 'Strut folder camera', 'primary'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_LB'), 'en', 'SF', 'abbreviation'),
-- Festgehäuse (Fg)
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_FG'), 'de', 'Festgehäuse', 'primary'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_FG'), 'de', 'Fg', 'abbreviation'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_FG'), 'en', 'Rigid body camera', 'primary'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_FG'), 'en', 'Rigid', 'synonym'),
-- Klappkamera (Kl)
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_KL'), 'de', 'Klappkamera', 'primary'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_KL'), 'de', 'Kl', 'abbreviation'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_KL'), 'en', 'Folding camera', 'primary'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_KL'), 'en', 'Folder', 'synonym'),
-- Spiegelreflex (Sp)
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_SP'), 'de', 'Spiegelreflexkamera', 'primary'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_SP'), 'de', 'Sp', 'abbreviation'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_SP'), 'de', 'Spiegelreflex', 'synonym'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_SP'), 'en', 'Single-lens reflex', 'primary'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_SP'), 'en', 'SLR', 'abbreviation'),
-- Reflexkamera (Rk)
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_RK'), 'de', 'Reflexkamera', 'primary'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_RK'), 'de', 'Rk', 'abbreviation'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_RK'), 'en', 'Twin-lens reflex', 'primary'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_RK'), 'en', 'TLR', 'abbreviation'),
-- Boxkamera (Bo)
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_BO'), 'de', 'Boxkamera', 'primary'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_BO'), 'de', 'Bo', 'abbreviation'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_BO'), 'de', 'Box', 'synonym'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_BO'), 'en', 'Box camera', 'primary'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_BO'), 'en', 'Box', 'abbreviation'),
-- Tubus (Tu)
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_TU'), 'de', 'Tubuskamera', 'primary'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_TU'), 'de', 'Tu', 'abbreviation'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_TU'), 'en', 'Tube camera', 'primary'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_TU'), 'en', 'Tube', 'abbreviation'),
-- Magazine (Mg)
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_MG'), 'de', 'Magazinkamera', 'primary'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_MG'), 'de', 'Mg', 'abbreviation'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_MG'), 'en', 'Magazine camera', 'primary'),
((SELECT id FROM concepts WHERE concept_code = 'BODY_TYPE_MG'), 'en', 'Mag', 'abbreviation');
-- ==========================================
-- COMMON FILM FORMATS
-- ==========================================
INSERT INTO formats (format_code, width_mm, height_mm, format_type, description_de, description_en, sort_order) VALUES
('9x12 Pl', 90, 120, 'plate', 'Glasplatte 9×12 cm', 'Glass plate 9×12 cm', 10),
('13x18 Pl', 130, 180, 'plate', 'Glasplatte 13×18 cm', 'Glass plate 13×18 cm', 20),
('6x9 RF', 60, 90, 'rollfilm', 'Rollfilm 6×9 cm', 'Rollfilm 6×9 cm', 30),
('6x6 RF', 60, 60, 'rollfilm', 'Rollfilm 6×6 cm', 'Rollfilm 6×6 cm', 40),
('24x36 KB', 24, 36, '35mm', 'Kleinbild 24×36 mm', '35mm film', 50);
-- ==========================================
-- SAMPLE LENSES
-- ==========================================
INSERT INTO lenses (name, manufacturer, focal_length_mm, max_aperture, lens_type, notes) VALUES
('Tessar', 'Zeiss', 50, 3.5, 'prime', 'Classic 4-element lens'),
('Tessar', 'Zeiss', 105, 4.5, 'prime', 'Medium telephoto version'),
('Xenar', 'Schneider', 50, 2.8, 'prime', 'High-speed Tessar type'),
('Anastigmat', 'Various', NULL, NULL, 'prime', 'Generic designation for corrected lenses');
-- ==========================================
-- SAMPLE SHUTTERS
-- ==========================================
INSERT INTO shutters (name, manufacturer, shutter_type, speed_range, notes) VALUES
('Compur', 'Deckel', 'leaf', '1-1/300s, B', 'Most common leaf shutter'),
('Prontor', 'Gauthier', 'leaf', '1-1/300s, B', 'Alternative to Compur'),
('Ibsor', 'Deckel', 'leaf', '1-1/100s, B', 'Budget version of Compur');
-- ==========================================
-- SYSTEM CONFIGURATION
-- ==========================================
INSERT INTO system_config (key, value, description, updated_by, updated_at) VALUES
('schema_version', '1.0', 'Current database schema version', 'Installation', NOW()),
('last_import', NULL, 'Timestamp of last Goergens data import', NULL, NULL),
('research_password_changed', NULL, 'Date of last research password change', NULL, NULL);
-- ==========================================
-- ANALYSIS REPORT
-- ==========================================
DO $$
DECLARE
table_count INT;
index_count INT;
view_count INT;
function_count INT;
BEGIN
SELECT COUNT(*) INTO table_count
FROM information_schema.tables
WHERE table_schema = 'public' AND table_type = 'BASE TABLE';
SELECT COUNT(*) INTO index_count
FROM pg_indexes
WHERE schemaname = 'public';
SELECT COUNT(*) INTO view_count
FROM information_schema.views
WHERE table_schema = 'public';
SELECT COUNT(*) INTO function_count
FROM pg_proc
WHERE pronamespace = 'public'::regnamespace;
RAISE NOTICE '===========================================';
RAISE NOTICE 'CLUB DAGUERRE CAMERA DATABASE';
RAISE NOTICE 'Schema Installation Complete';
RAISE NOTICE '===========================================';
RAISE NOTICE 'Tables created: %', table_count;
RAISE NOTICE 'Indexes created: %', index_count;
RAISE NOTICE 'Views created: %', view_count;
RAISE NOTICE 'Functions created: %', function_count;
RAISE NOTICE '===========================================';
RAISE NOTICE 'Ready for Goergens data import';
RAISE NOTICE '===========================================';
END $$;

190
schema/README-SCHEMA.md Normal file
View File

@ -0,0 +1,190 @@
# Club Daguerre Camera Database - Schema Installation
## Overview
Complete PostgreSQL 16 schema for the Club Daguerre camera database, preserving Harald Goergens' 30+ year classification work with modern metadata management.
## Prerequisites
- PostgreSQL 16 installed
- camera_db database created
- Port 5433 (or your configured port)
## Installation Order
The schema is split into logical sections for clarity and maintainability:
1. **01-core-hierarchy.sql** - Manufacturers, models, variants, combos
2. **02-supporting.sql** - Lenses, shutters, formats, terminology
3. **03-content.sql** - Images, documents, articles (multi-level linking)
4. **04-auth.sql** - Members, research access, audit log
5. **05-history.sql** - History tables for audit trail
6. **06-triggers.sql** - Triggers and functions for automation
7. **07-views.sql** - Materialized views for performance
8. **08-seed-data.sql** - Initial data (sources, terminology, samples)
## Quick Installation
### Method 1: All at Once
```bash
cd /data/camera-database/schema
# Run all files in order
for file in 0{1..8}-*.sql; do
echo "Installing $file..."
psql -h localhost -p 5433 -U postgres -d camera_db -f "$file"
done
```
### Method 2: One by One
```bash
cd /data/camera-database/schema
psql -h localhost -p 5433 -U postgres -d camera_db -f 01-core-hierarchy.sql
psql -h localhost -p 5433 -U postgres -d camera_db -f 02-supporting.sql
psql -h localhost -p 5433 -U postgres -d camera_db -f 03-content.sql
psql -h localhost -p 5433 -U postgres -d camera_db -f 04-auth.sql
psql -h localhost -p 5433 -U postgres -d camera_db -f 05-history.sql
psql -h localhost -p 5433 -U postgres -d camera_db -f 06-triggers.sql
psql -h localhost -p 5433 -U postgres -d camera_db -f 07-views.sql
psql -h localhost -p 5433 -U postgres -d camera_db -f 08-seed-data.sql
```
## Verification
After installation:
```sql
-- Connect to database
psql -h localhost -p 5433 -U postgres -d camera_db
-- Check tables
\dt
-- Check views
\dv
-- Check materialized views
\dm
-- Check functions
\df
-- Run validation
SELECT * FROM validate_goergens_structure();
-- Check seed data
SELECT * FROM content_sources;
SELECT * FROM terminology LIMIT 10;
-- Exit
\q
```
## Schema Statistics
Expected after installation:
- **Tables:** 35
- **Indexes:** ~80
- **Views:** 2
- **Materialized Views:** 3
- **Functions:** 5
- **Triggers:** 8
## Key Features
### 1. Goergens Hierarchy Preservation
- Manufacturers (ERNM, ZEII, etc.)
- Models (1910, 0450, etc.)
- Variants (a, b, c - color/material)
- Combos (01, 02 - lens/shutter configs)
### 2. Multi-Level Content Linking
Images, documents, and articles can link at ANY level:
- Manufacturer level (company history)
- Model level (camera manual - shared by all variants)
- Variant level (color-specific photo)
- Combo level (lens manual - combo-specific)
### 3. Rights Management
- **verified:** Publishable content
- **uncertain:** Research-only (Steimer data)
- **restricted:** Internal only
### 4. Performance Optimizations
- Denormalized fields in lens_shutter_combos
- Materialized views for dashboard/search
- GIN indexes for full-text search
- GIST indexes for range queries
### 5. Audit Trail
- Version numbers on all records
- History tables track all changes
- Comprehensive audit log
- Timestamp tracking
### 6. Multilingual Support
- German/English core (expandable)
- Separate i18n tables for content
- Language-agnostic codes
## Maintenance
### Refresh Materialized Views
```sql
-- Hourly (manufacturer stats)
REFRESH MATERIALIZED VIEW CONCURRENTLY mv_manufacturer_stats;
-- Every 15-30 minutes (search catalog)
REFRESH MATERIALIZED VIEW CONCURRENTLY mv_public_catalog;
-- Every 5 minutes (dashboard)
REFRESH MATERIALIZED VIEW CONCURRENTLY mv_dashboard_stats;
```
### Backup
```bash
# Full backup
pg_dump -h localhost -p 5433 -U postgres camera_db | gzip > /mnt/data/postgresql/backups/camera_db_$(date +%Y%m%d).sql.gz
# Schema only
pg_dump -h localhost -p 5433 -U postgres -s camera_db > /mnt/data/postgresql/backups/camera_db_schema.sql
```
## Next Steps
1. ✅ Schema installed
2. Import Goergens data (74,000+ cameras)
3. Import Photo Antiquaria articles
4. Add images and documents
5. Develop Flask web application
## Troubleshooting
### "relation already exists"
Schema already partially installed. Either:
- Drop database and recreate: `DROP DATABASE camera_db; CREATE DATABASE camera_db;`
- Or skip to the file where installation failed
### Foreign key violations
Files must be run in order (01 through 08). Foreign keys depend on tables from earlier files.
### Permission denied
Use postgres superuser: `-U postgres`
## Documentation
- **Design Document:** /data/camera-database/docs/database-design.md
- **PostgreSQL Setup:** /data/camera-database/docs/postgresql-setup.md
- **Goergens Email:** /data/camera-database/docs/goergens-email.txt
## Version
- Schema Version: 1.0
- PostgreSQL: 16+
- Date: November 2025
- Author: Walter Jekat / Club Daguerre e.V.