Fix dashboard views for consolidated schema
This commit is contained in:
@@ -846,5 +846,57 @@ INSERT INTO public.users (email, password_hash, role)
|
|||||||
SELECT 'admin@example.com', '$2b$10$K8/KqJyNqJKqJyNqJKqJyOqJKqJyNqJKqJyNqJKqJyNqJKqJyNqJK', 'admin'
|
SELECT 'admin@example.com', '$2b$10$K8/KqJyNqJKqJyNqJKqJyOqJKqJyNqJKqJyNqJKqJyNqJKqJyNqJK', 'admin'
|
||||||
WHERE NOT EXISTS (SELECT 1 FROM public.users WHERE email = 'admin@example.com');
|
WHERE NOT EXISTS (SELECT 1 FROM public.users WHERE email = 'admin@example.com');
|
||||||
|
|
||||||
|
-- ============================================
|
||||||
|
-- Dashboard views (consolidated schema)
|
||||||
|
-- ============================================
|
||||||
|
|
||||||
|
DROP VIEW IF EXISTS public.v_dashboard_stats CASCADE;
|
||||||
|
DROP VIEW IF EXISTS public.v_latest_snapshots CASCADE;
|
||||||
|
DROP VIEW IF EXISTS public.v_product_brands CASCADE;
|
||||||
|
DROP VIEW IF EXISTS public.v_product_categories CASCADE;
|
||||||
|
|
||||||
|
-- Latest snapshot per product (most recent crawl data)
|
||||||
|
CREATE OR REPLACE VIEW public.v_latest_snapshots AS
|
||||||
|
SELECT DISTINCT ON (dutchie_product_id)
|
||||||
|
s.*
|
||||||
|
FROM public.dutchie_product_snapshots s
|
||||||
|
ORDER BY dutchie_product_id, crawled_at DESC;
|
||||||
|
|
||||||
|
-- Dashboard stats
|
||||||
|
CREATE OR REPLACE VIEW public.v_dashboard_stats AS
|
||||||
|
SELECT
|
||||||
|
(SELECT COUNT(*) FROM public.dispensaries WHERE state = 'AZ') as dispensary_count,
|
||||||
|
(SELECT COUNT(*) FROM public.dutchie_products) as product_count,
|
||||||
|
(SELECT COUNT(*) FROM public.dutchie_product_snapshots WHERE crawled_at > NOW() - INTERVAL '24 hours') as snapshots_24h,
|
||||||
|
(SELECT MAX(crawled_at) FROM public.dutchie_product_snapshots) as last_crawl_time,
|
||||||
|
(SELECT COUNT(*) FROM public.crawl_jobs WHERE status = 'failed' AND created_at > NOW() - INTERVAL '24 hours') as failed_jobs_24h,
|
||||||
|
(SELECT COUNT(DISTINCT brand_name) FROM public.dutchie_products WHERE brand_name IS NOT NULL) as brand_count,
|
||||||
|
(SELECT COUNT(DISTINCT (type, subcategory)) FROM public.dutchie_products WHERE type IS NOT NULL) as category_count;
|
||||||
|
|
||||||
|
-- Brands derived from products
|
||||||
|
CREATE OR REPLACE VIEW public.v_product_brands AS
|
||||||
|
SELECT
|
||||||
|
brand_name,
|
||||||
|
brand_id,
|
||||||
|
COUNT(*) as product_count,
|
||||||
|
COUNT(DISTINCT dispensary_id) as dispensary_count,
|
||||||
|
ARRAY_AGG(DISTINCT type) FILTER (WHERE type IS NOT NULL) as product_types
|
||||||
|
FROM public.dutchie_products
|
||||||
|
WHERE brand_name IS NOT NULL
|
||||||
|
GROUP BY brand_name, brand_id
|
||||||
|
ORDER BY product_count DESC;
|
||||||
|
|
||||||
|
-- Categories derived from products
|
||||||
|
CREATE OR REPLACE VIEW public.v_product_categories AS
|
||||||
|
SELECT
|
||||||
|
type,
|
||||||
|
subcategory,
|
||||||
|
COUNT(*) as product_count,
|
||||||
|
COUNT(DISTINCT dispensary_id) as dispensary_count,
|
||||||
|
COUNT(DISTINCT brand_name) as brand_count
|
||||||
|
FROM public.dutchie_products
|
||||||
|
GROUP BY type, subcategory
|
||||||
|
ORDER BY product_count DESC;
|
||||||
|
|
||||||
-- Done!
|
-- Done!
|
||||||
SELECT 'Migration 031 completed successfully' as status;
|
SELECT 'Migration 031 completed successfully' as status;
|
||||||
|
|||||||
Reference in New Issue
Block a user