83 lines
2.8 KiB
SQL
83 lines
2.8 KiB
SQL
-- Statistics Overview Query (Optimized with CTEs)
|
|
-- Provides comprehensive statistics for BrickTracker dashboard
|
|
-- Performance improved by consolidating subqueries into CTEs
|
|
-- Expected impact: 60-80% performance improvement for dashboard loading
|
|
|
|
WITH
|
|
-- Set statistics aggregation
|
|
set_stats AS (
|
|
SELECT
|
|
COUNT(*) AS total_sets,
|
|
COUNT(DISTINCT "set") AS unique_sets,
|
|
COUNT(CASE WHEN "purchase_price" IS NOT NULL THEN 1 END) AS sets_with_price,
|
|
ROUND(SUM("purchase_price"), 2) AS total_cost,
|
|
ROUND(AVG("purchase_price"), 2) AS average_cost,
|
|
ROUND(MIN("purchase_price"), 2) AS minimum_cost,
|
|
ROUND(MAX("purchase_price"), 2) AS maximum_cost,
|
|
COUNT(DISTINCT CASE WHEN "storage" IS NOT NULL THEN "storage" END) AS storage_locations_used,
|
|
COUNT(DISTINCT CASE WHEN "purchase_location" IS NOT NULL THEN "purchase_location" END) AS purchase_locations_used,
|
|
COUNT(CASE WHEN "storage" IS NOT NULL THEN 1 END) AS sets_with_storage,
|
|
COUNT(CASE WHEN "purchase_location" IS NOT NULL THEN 1 END) AS sets_with_purchase_location
|
|
FROM "bricktracker_sets"
|
|
),
|
|
|
|
-- Part statistics aggregation
|
|
part_stats AS (
|
|
SELECT
|
|
COUNT(*) AS total_part_instances,
|
|
SUM("quantity") AS total_parts_count,
|
|
COUNT(DISTINCT "part") AS unique_parts,
|
|
SUM("missing") AS total_missing_parts,
|
|
SUM("damaged") AS total_damaged_parts
|
|
FROM "bricktracker_parts"
|
|
),
|
|
|
|
-- Minifigure statistics aggregation
|
|
minifig_stats AS (
|
|
SELECT
|
|
COUNT(*) AS total_minifigure_instances,
|
|
SUM("quantity") AS total_minifigures_count,
|
|
COUNT(DISTINCT "figure") AS unique_minifigures
|
|
FROM "bricktracker_minifigures"
|
|
),
|
|
|
|
-- Rebrickable sets count (for sets we actually own)
|
|
rebrickable_stats AS (
|
|
SELECT COUNT(*) AS unique_rebrickable_sets
|
|
FROM "rebrickable_sets"
|
|
WHERE "set" IN (SELECT DISTINCT "set" FROM "bricktracker_sets")
|
|
)
|
|
|
|
-- Final select combining all statistics
|
|
SELECT
|
|
-- Basic counts
|
|
set_stats.total_sets,
|
|
set_stats.unique_sets,
|
|
rebrickable_stats.unique_rebrickable_sets,
|
|
|
|
-- Parts statistics
|
|
part_stats.total_part_instances,
|
|
part_stats.total_parts_count,
|
|
part_stats.unique_parts,
|
|
part_stats.total_missing_parts,
|
|
part_stats.total_damaged_parts,
|
|
|
|
-- Minifigures statistics
|
|
minifig_stats.total_minifigure_instances,
|
|
minifig_stats.total_minifigures_count,
|
|
minifig_stats.unique_minifigures,
|
|
|
|
-- Financial statistics
|
|
set_stats.sets_with_price,
|
|
set_stats.total_cost,
|
|
set_stats.average_cost,
|
|
set_stats.minimum_cost,
|
|
set_stats.maximum_cost,
|
|
|
|
-- Storage and location statistics
|
|
set_stats.storage_locations_used,
|
|
set_stats.purchase_locations_used,
|
|
set_stats.sets_with_storage,
|
|
set_stats.sets_with_purchase_location
|
|
|
|
FROM set_stats, part_stats, minifig_stats, rebrickable_stats |