295 lines
11 KiB
SQL
295 lines
11 KiB
SQL
-- ==========================================
|
|
-- 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';
|