Some checks failed
Deploy to Test Environment / deploy-to-test (push) Failing after 1m10s
190 lines
12 KiB
SQL
190 lines
12 KiB
SQL
-- sql/migrations/002_expiry_tracking.sql
|
|
-- ============================================================================
|
|
-- EXPIRY DATE TRACKING FEATURE MIGRATION
|
|
-- ============================================================================
|
|
-- Purpose:
|
|
-- This migration adds tables and enhancements for expiry date tracking:
|
|
-- 1. expiry_date_ranges - Reference table for typical shelf life by item/category
|
|
-- 2. expiry_alerts - User notification preferences for expiry warnings
|
|
-- 3. Enhancements to pantry_items for better expiry tracking
|
|
--
|
|
-- Existing tables used:
|
|
-- - pantry_items (already has best_before_date)
|
|
-- - pantry_locations (already exists for fridge/freezer/pantry)
|
|
-- - receipts and receipt_items (already exist for receipt scanning)
|
|
-- ============================================================================
|
|
|
|
-- 1. Expiry Date Ranges - reference table for typical shelf life
|
|
-- This table stores expected shelf life for items based on storage location
|
|
-- Used to auto-calculate expiry dates when users add items to inventory
|
|
CREATE TABLE IF NOT EXISTS public.expiry_date_ranges (
|
|
expiry_range_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
|
master_item_id BIGINT REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE CASCADE,
|
|
category_id BIGINT REFERENCES public.categories(category_id) ON DELETE CASCADE,
|
|
item_pattern TEXT,
|
|
storage_location TEXT NOT NULL,
|
|
min_days INTEGER NOT NULL,
|
|
max_days INTEGER NOT NULL,
|
|
typical_days INTEGER NOT NULL,
|
|
notes TEXT,
|
|
source TEXT,
|
|
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
|
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
|
-- Validate storage location is one of the allowed values
|
|
CONSTRAINT expiry_date_ranges_storage_location_check CHECK (storage_location IN ('fridge', 'freezer', 'pantry', 'room_temp')),
|
|
-- Validate day ranges are logical
|
|
CONSTRAINT expiry_date_ranges_min_days_check CHECK (min_days >= 0),
|
|
CONSTRAINT expiry_date_ranges_max_days_check CHECK (max_days >= min_days),
|
|
CONSTRAINT expiry_date_ranges_typical_days_check CHECK (typical_days >= min_days AND typical_days <= max_days),
|
|
-- At least one identifier must be present
|
|
CONSTRAINT expiry_date_ranges_identifier_check CHECK (
|
|
master_item_id IS NOT NULL OR category_id IS NOT NULL OR item_pattern IS NOT NULL
|
|
),
|
|
-- Validate source is one of the known sources
|
|
CONSTRAINT expiry_date_ranges_source_check CHECK (source IS NULL OR source IN ('usda', 'fda', 'manual', 'community'))
|
|
);
|
|
COMMENT ON TABLE public.expiry_date_ranges IS 'Reference table storing typical shelf life for grocery items based on storage location.';
|
|
COMMENT ON COLUMN public.expiry_date_ranges.master_item_id IS 'Specific item this range applies to (most specific).';
|
|
COMMENT ON COLUMN public.expiry_date_ranges.category_id IS 'Category this range applies to (fallback if no item match).';
|
|
COMMENT ON COLUMN public.expiry_date_ranges.item_pattern IS 'Regex pattern to match item names (fallback if no item/category match).';
|
|
COMMENT ON COLUMN public.expiry_date_ranges.storage_location IS 'Where the item is stored: fridge, freezer, pantry, or room_temp.';
|
|
COMMENT ON COLUMN public.expiry_date_ranges.min_days IS 'Minimum shelf life in days under proper storage.';
|
|
COMMENT ON COLUMN public.expiry_date_ranges.max_days IS 'Maximum shelf life in days under proper storage.';
|
|
COMMENT ON COLUMN public.expiry_date_ranges.typical_days IS 'Most common/recommended shelf life in days.';
|
|
COMMENT ON COLUMN public.expiry_date_ranges.notes IS 'Additional storage tips or warnings.';
|
|
COMMENT ON COLUMN public.expiry_date_ranges.source IS 'Data source: usda, fda, manual, or community.';
|
|
|
|
-- Indexes for expiry_date_ranges
|
|
CREATE INDEX IF NOT EXISTS idx_expiry_date_ranges_master_item_id ON public.expiry_date_ranges(master_item_id) WHERE master_item_id IS NOT NULL;
|
|
CREATE INDEX IF NOT EXISTS idx_expiry_date_ranges_category_id ON public.expiry_date_ranges(category_id) WHERE category_id IS NOT NULL;
|
|
CREATE INDEX IF NOT EXISTS idx_expiry_date_ranges_storage_location ON public.expiry_date_ranges(storage_location);
|
|
|
|
-- Unique constraint to prevent duplicate entries for same item/location combo
|
|
CREATE UNIQUE INDEX IF NOT EXISTS idx_expiry_date_ranges_unique_item_location
|
|
ON public.expiry_date_ranges(master_item_id, storage_location)
|
|
WHERE master_item_id IS NOT NULL;
|
|
CREATE UNIQUE INDEX IF NOT EXISTS idx_expiry_date_ranges_unique_category_location
|
|
ON public.expiry_date_ranges(category_id, storage_location)
|
|
WHERE category_id IS NOT NULL AND master_item_id IS NULL;
|
|
|
|
|
|
-- 2. Expiry Alerts - user notification preferences for expiry warnings
|
|
-- This table stores user preferences for when and how to receive expiry notifications
|
|
CREATE TABLE IF NOT EXISTS public.expiry_alerts (
|
|
expiry_alert_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
|
user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE,
|
|
days_before_expiry INTEGER NOT NULL DEFAULT 3,
|
|
alert_method TEXT NOT NULL,
|
|
is_enabled BOOLEAN DEFAULT TRUE NOT NULL,
|
|
last_alert_sent_at TIMESTAMPTZ,
|
|
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
|
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
|
-- Validate days before expiry is reasonable
|
|
CONSTRAINT expiry_alerts_days_before_check CHECK (days_before_expiry >= 0 AND days_before_expiry <= 30),
|
|
-- Validate alert method is one of the allowed values
|
|
CONSTRAINT expiry_alerts_method_check CHECK (alert_method IN ('email', 'push', 'in_app')),
|
|
-- Each user can only have one setting per alert method
|
|
UNIQUE(user_id, alert_method)
|
|
);
|
|
COMMENT ON TABLE public.expiry_alerts IS 'User preferences for expiry date notifications and alerts.';
|
|
COMMENT ON COLUMN public.expiry_alerts.days_before_expiry IS 'How many days before expiry to send alert (0-30).';
|
|
COMMENT ON COLUMN public.expiry_alerts.alert_method IS 'How to notify: email, push, or in_app.';
|
|
COMMENT ON COLUMN public.expiry_alerts.is_enabled IS 'Whether this alert type is currently enabled.';
|
|
COMMENT ON COLUMN public.expiry_alerts.last_alert_sent_at IS 'Timestamp of the last alert sent to prevent duplicate notifications.';
|
|
|
|
-- Indexes for expiry_alerts
|
|
CREATE INDEX IF NOT EXISTS idx_expiry_alerts_user_id ON public.expiry_alerts(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_expiry_alerts_enabled ON public.expiry_alerts(user_id, is_enabled) WHERE is_enabled = TRUE;
|
|
|
|
|
|
-- 3. Expiry Alert Log - tracks sent notifications (for auditing and preventing duplicates)
|
|
CREATE TABLE IF NOT EXISTS public.expiry_alert_log (
|
|
alert_log_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
|
user_id UUID NOT NULL REFERENCES public.users(user_id) ON DELETE CASCADE,
|
|
pantry_item_id BIGINT REFERENCES public.pantry_items(pantry_item_id) ON DELETE SET NULL,
|
|
alert_type TEXT NOT NULL,
|
|
alert_method TEXT NOT NULL,
|
|
item_name TEXT NOT NULL,
|
|
expiry_date DATE,
|
|
days_until_expiry INTEGER,
|
|
sent_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
|
-- Validate alert type
|
|
CONSTRAINT expiry_alert_log_type_check CHECK (alert_type IN ('expiring_soon', 'expired', 'expiry_reminder')),
|
|
-- Validate alert method
|
|
CONSTRAINT expiry_alert_log_method_check CHECK (alert_method IN ('email', 'push', 'in_app')),
|
|
-- Validate item_name is not empty
|
|
CONSTRAINT expiry_alert_log_item_name_check CHECK (TRIM(item_name) <> '')
|
|
);
|
|
COMMENT ON TABLE public.expiry_alert_log IS 'Log of all expiry notifications sent to users for auditing and duplicate prevention.';
|
|
COMMENT ON COLUMN public.expiry_alert_log.pantry_item_id IS 'The pantry item that triggered the alert (may be null if item deleted).';
|
|
COMMENT ON COLUMN public.expiry_alert_log.alert_type IS 'Type of alert: expiring_soon, expired, or expiry_reminder.';
|
|
COMMENT ON COLUMN public.expiry_alert_log.alert_method IS 'How the alert was sent: email, push, or in_app.';
|
|
COMMENT ON COLUMN public.expiry_alert_log.item_name IS 'Snapshot of item name at time of alert (in case item is deleted).';
|
|
COMMENT ON COLUMN public.expiry_alert_log.expiry_date IS 'The expiry date that triggered the alert.';
|
|
COMMENT ON COLUMN public.expiry_alert_log.days_until_expiry IS 'Days until expiry at time alert was sent (negative = expired).';
|
|
|
|
-- Indexes for expiry_alert_log
|
|
CREATE INDEX IF NOT EXISTS idx_expiry_alert_log_user_id ON public.expiry_alert_log(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_expiry_alert_log_pantry_item_id ON public.expiry_alert_log(pantry_item_id) WHERE pantry_item_id IS NOT NULL;
|
|
CREATE INDEX IF NOT EXISTS idx_expiry_alert_log_sent_at ON public.expiry_alert_log(sent_at DESC);
|
|
|
|
|
|
-- 4. Enhancements to pantry_items table
|
|
-- Add columns to better support expiry tracking from receipts and UPC scans
|
|
|
|
-- Add purchase_date column to track when item was bought
|
|
ALTER TABLE public.pantry_items
|
|
ADD COLUMN IF NOT EXISTS purchase_date DATE;
|
|
COMMENT ON COLUMN public.pantry_items.purchase_date IS 'Date the item was purchased (from receipt or manual entry).';
|
|
|
|
-- Add source column to track how item was added
|
|
ALTER TABLE public.pantry_items
|
|
ADD COLUMN IF NOT EXISTS source TEXT DEFAULT 'manual';
|
|
-- Note: Cannot add CHECK constraint via ALTER in PostgreSQL, will validate in application
|
|
|
|
-- Add receipt_item_id to link back to receipt if added from receipt scan
|
|
ALTER TABLE public.pantry_items
|
|
ADD COLUMN IF NOT EXISTS receipt_item_id BIGINT REFERENCES public.receipt_items(receipt_item_id) ON DELETE SET NULL;
|
|
COMMENT ON COLUMN public.pantry_items.receipt_item_id IS 'Link to receipt_items if this pantry item was created from a receipt scan.';
|
|
|
|
-- Add product_id to link to specific product if known from UPC scan
|
|
ALTER TABLE public.pantry_items
|
|
ADD COLUMN IF NOT EXISTS product_id BIGINT REFERENCES public.products(product_id) ON DELETE SET NULL;
|
|
COMMENT ON COLUMN public.pantry_items.product_id IS 'Link to products if this pantry item was created from a UPC scan.';
|
|
|
|
-- Add expiry_source to track how expiry date was determined
|
|
ALTER TABLE public.pantry_items
|
|
ADD COLUMN IF NOT EXISTS expiry_source TEXT;
|
|
COMMENT ON COLUMN public.pantry_items.expiry_source IS 'How expiry was determined: manual, calculated, package, receipt.';
|
|
|
|
-- Add is_consumed column if not exists (check for existing)
|
|
ALTER TABLE public.pantry_items
|
|
ADD COLUMN IF NOT EXISTS is_consumed BOOLEAN DEFAULT FALSE;
|
|
COMMENT ON COLUMN public.pantry_items.is_consumed IS 'Whether the item has been fully consumed.';
|
|
|
|
-- Add consumed_at timestamp
|
|
ALTER TABLE public.pantry_items
|
|
ADD COLUMN IF NOT EXISTS consumed_at TIMESTAMPTZ;
|
|
COMMENT ON COLUMN public.pantry_items.consumed_at IS 'When the item was marked as consumed.';
|
|
|
|
-- New indexes for pantry_items expiry queries
|
|
CREATE INDEX IF NOT EXISTS idx_pantry_items_best_before_date ON public.pantry_items(best_before_date)
|
|
WHERE best_before_date IS NOT NULL AND (is_consumed IS NULL OR is_consumed = FALSE);
|
|
CREATE INDEX IF NOT EXISTS idx_pantry_items_expiring_soon ON public.pantry_items(user_id, best_before_date)
|
|
WHERE best_before_date IS NOT NULL AND (is_consumed IS NULL OR is_consumed = FALSE);
|
|
CREATE INDEX IF NOT EXISTS idx_pantry_items_receipt_item_id ON public.pantry_items(receipt_item_id)
|
|
WHERE receipt_item_id IS NOT NULL;
|
|
CREATE INDEX IF NOT EXISTS idx_pantry_items_product_id ON public.pantry_items(product_id)
|
|
WHERE product_id IS NOT NULL;
|
|
|
|
|
|
-- 5. Add UPC scan support to receipt_items table
|
|
-- When receipt items are matched via UPC, store the reference
|
|
ALTER TABLE public.receipt_items
|
|
ADD COLUMN IF NOT EXISTS upc_code TEXT;
|
|
COMMENT ON COLUMN public.receipt_items.upc_code IS 'UPC code if extracted from receipt or matched during processing.';
|
|
|
|
-- Add constraint for upc_code format (cannot add via ALTER, will validate in app)
|
|
CREATE INDEX IF NOT EXISTS idx_receipt_items_upc_code ON public.receipt_items(upc_code)
|
|
WHERE upc_code IS NOT NULL;
|