-- sql/migrations/001_upc_scanning.sql -- ============================================================================ -- UPC SCANNING FEATURE MIGRATION -- ============================================================================ -- Purpose: -- This migration adds tables to support UPC barcode scanning functionality: -- 1. upc_scan_history - Audit trail of all UPC scans performed by users -- 2. upc_external_lookups - Cache for external UPC database API responses -- -- The products.upc_code column already exists in the schema. -- These tables extend the functionality to track scans and cache lookups. -- ============================================================================ -- 1. UPC Scan History - tracks all UPC scans performed by users -- This table provides an audit trail and allows users to see their scan history CREATE TABLE IF NOT EXISTS public.upc_scan_history ( scan_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE, upc_code TEXT NOT NULL, product_id BIGINT REFERENCES public.products(product_id) ON DELETE SET NULL, scan_source TEXT NOT NULL, scan_confidence NUMERIC(5,4), raw_image_path TEXT, lookup_successful BOOLEAN DEFAULT FALSE NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, -- Validate UPC code format (8-14 digits for UPC-A, UPC-E, EAN-8, EAN-13, etc.) CONSTRAINT upc_scan_history_upc_code_check CHECK (upc_code ~ '^[0-9]{8,14}$'), -- Validate scan source is one of the allowed values CONSTRAINT upc_scan_history_scan_source_check CHECK (scan_source IN ('image_upload', 'manual_entry', 'phone_app', 'camera_scan')), -- Confidence score must be between 0 and 1 if provided CONSTRAINT upc_scan_history_scan_confidence_check CHECK (scan_confidence IS NULL OR (scan_confidence >= 0 AND scan_confidence <= 1)) ); COMMENT ON TABLE public.upc_scan_history IS 'Audit trail of all UPC barcode scans performed by users, tracking scan source and results.'; COMMENT ON COLUMN public.upc_scan_history.upc_code IS 'The scanned UPC/EAN barcode (8-14 digits).'; COMMENT ON COLUMN public.upc_scan_history.product_id IS 'Reference to the matched product, if found in our database.'; COMMENT ON COLUMN public.upc_scan_history.scan_source IS 'How the scan was performed: image_upload, manual_entry, phone_app, or camera_scan.'; COMMENT ON COLUMN public.upc_scan_history.scan_confidence IS 'Confidence score from barcode detection (0.0-1.0), null for manual entry.'; COMMENT ON COLUMN public.upc_scan_history.raw_image_path IS 'Path to the uploaded barcode image, if applicable.'; COMMENT ON COLUMN public.upc_scan_history.lookup_successful IS 'Whether the UPC was successfully matched to a product (internal or external).'; -- Indexes for upc_scan_history CREATE INDEX IF NOT EXISTS idx_upc_scan_history_user_id ON public.upc_scan_history(user_id); CREATE INDEX IF NOT EXISTS idx_upc_scan_history_upc_code ON public.upc_scan_history(upc_code); CREATE INDEX IF NOT EXISTS idx_upc_scan_history_created_at ON public.upc_scan_history(created_at DESC); CREATE INDEX IF NOT EXISTS idx_upc_scan_history_product_id ON public.upc_scan_history(product_id) WHERE product_id IS NOT NULL; -- 2. UPC External Lookups - cache for external UPC database API responses -- This table caches results from external UPC databases (OpenFoodFacts, UPC Item DB, etc.) -- to reduce API calls and improve response times for repeated lookups CREATE TABLE IF NOT EXISTS public.upc_external_lookups ( lookup_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, upc_code TEXT NOT NULL UNIQUE, product_name TEXT, brand_name TEXT, category TEXT, description TEXT, image_url TEXT, external_source TEXT NOT NULL, lookup_data JSONB, lookup_successful BOOLEAN DEFAULT FALSE NOT NULL, created_at TIMESTAMPTZ DEFAULT now() NOT NULL, updated_at TIMESTAMPTZ DEFAULT now() NOT NULL, -- Validate UPC code format CONSTRAINT upc_external_lookups_upc_code_check CHECK (upc_code ~ '^[0-9]{8,14}$'), -- Validate external source is one of the supported APIs CONSTRAINT upc_external_lookups_external_source_check CHECK (external_source IN ('openfoodfacts', 'upcitemdb', 'manual', 'unknown')), -- If lookup was successful, product_name should be present CONSTRAINT upc_external_lookups_name_check CHECK (NOT lookup_successful OR product_name IS NOT NULL) ); COMMENT ON TABLE public.upc_external_lookups IS 'Cache for external UPC database API responses to reduce API calls and improve lookup speed.'; COMMENT ON COLUMN public.upc_external_lookups.upc_code IS 'The UPC/EAN barcode that was looked up.'; COMMENT ON COLUMN public.upc_external_lookups.product_name IS 'Product name returned from external API.'; COMMENT ON COLUMN public.upc_external_lookups.brand_name IS 'Brand name returned from external API.'; COMMENT ON COLUMN public.upc_external_lookups.category IS 'Product category returned from external API.'; COMMENT ON COLUMN public.upc_external_lookups.description IS 'Product description returned from external API.'; COMMENT ON COLUMN public.upc_external_lookups.image_url IS 'Product image URL returned from external API.'; COMMENT ON COLUMN public.upc_external_lookups.external_source IS 'Which external API provided this data: openfoodfacts, upcitemdb, manual, unknown.'; COMMENT ON COLUMN public.upc_external_lookups.lookup_data IS 'Full raw JSON response from the external API for reference.'; COMMENT ON COLUMN public.upc_external_lookups.lookup_successful IS 'Whether the external lookup found product information.'; -- Index for upc_external_lookups CREATE INDEX IF NOT EXISTS idx_upc_external_lookups_upc_code ON public.upc_external_lookups(upc_code); CREATE INDEX IF NOT EXISTS idx_upc_external_lookups_external_source ON public.upc_external_lookups(external_source); -- 3. Add index to existing products.upc_code if not exists -- This speeds up lookups when matching scanned UPCs to existing products CREATE INDEX IF NOT EXISTS idx_products_upc_code ON public.products(upc_code) WHERE upc_code IS NOT NULL;