- BottleGrid: Implement blurred backdrop effect for bottle cards - Cascade OCR: TextDetector → RegEx → Fuzzy Match → window.ai pipeline - Smart Scan: Native OCR for Android, Live Text fallback for iOS - OCR Dashboard: Admin page at /admin/ocr-logs with stats and scan history - Features: Add feature flags in src/config/features.ts - SQL: Add ocr_logs table migration - Services: Update analyze-bottle to use OpenRouter, add save-ocr-log
79 lines
2.3 KiB
PL/PgSQL
79 lines
2.3 KiB
PL/PgSQL
-- OCR Logs Table for storing cascade OCR results
|
|
-- This allows admins to view OCR recognition results from mobile devices
|
|
|
|
CREATE TABLE IF NOT EXISTS ocr_logs (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_id UUID REFERENCES auth.users(id) ON DELETE SET NULL,
|
|
bottle_id UUID REFERENCES bottles(id) ON DELETE SET NULL,
|
|
|
|
-- Image data
|
|
image_url TEXT, -- URL to the scanned image
|
|
image_thumbnail TEXT, -- Base64 thumbnail for quick preview
|
|
|
|
-- Detected fields
|
|
raw_text TEXT, -- All detected text joined
|
|
detected_texts JSONB, -- Array of individual text detections
|
|
|
|
-- Extracted data
|
|
distillery TEXT,
|
|
distillery_source TEXT, -- 'fuzzy', 'ai', 'manual'
|
|
bottle_name TEXT,
|
|
abv DECIMAL(5,2),
|
|
age INTEGER,
|
|
vintage TEXT,
|
|
volume TEXT,
|
|
category TEXT,
|
|
|
|
-- Meta
|
|
confidence INTEGER, -- 0-100
|
|
device_info TEXT, -- User agent or device type
|
|
ocr_method TEXT, -- 'text_detector', 'fallback', etc.
|
|
processing_time_ms INTEGER,
|
|
|
|
-- Timestamps
|
|
created_at TIMESTAMPTZ DEFAULT now(),
|
|
updated_at TIMESTAMPTZ DEFAULT now()
|
|
);
|
|
|
|
-- Index for efficient queries
|
|
CREATE INDEX IF NOT EXISTS idx_ocr_logs_user_id ON ocr_logs(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_ocr_logs_created_at ON ocr_logs(created_at DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_ocr_logs_distillery ON ocr_logs(distillery);
|
|
|
|
-- RLS Policies
|
|
ALTER TABLE ocr_logs ENABLE ROW LEVEL SECURITY;
|
|
|
|
-- Users can view their own logs
|
|
CREATE POLICY "Users can view own ocr_logs"
|
|
ON ocr_logs FOR SELECT
|
|
USING (auth.uid() = user_id);
|
|
|
|
-- Users can insert their own logs
|
|
CREATE POLICY "Users can insert own ocr_logs"
|
|
ON ocr_logs FOR INSERT
|
|
WITH CHECK (auth.uid() = user_id);
|
|
|
|
-- Admins can view all logs
|
|
CREATE POLICY "Admins can view all ocr_logs"
|
|
ON ocr_logs FOR SELECT
|
|
USING (
|
|
EXISTS (
|
|
SELECT 1 FROM admin_users
|
|
WHERE admin_users.user_id = auth.uid()
|
|
)
|
|
);
|
|
|
|
-- Trigger for updated_at
|
|
CREATE OR REPLACE FUNCTION update_ocr_logs_updated_at()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = now();
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER trigger_ocr_logs_updated_at
|
|
BEFORE UPDATE ON ocr_logs
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_ocr_logs_updated_at();
|