-- ========================================== -- 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';