- Add proxy_test task handler that fetches IP via proxy to verify connectivity - Add discovery_runs migration (083) for tracking store discovery progress - Register proxy_test in task service and worker 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
89 lines
2.8 KiB
SQL
89 lines
2.8 KiB
SQL
-- Migration 083: Discovery Run Tracking
|
|
-- Tracks progress of store discovery runs step-by-step
|
|
|
|
-- Main discovery runs table
|
|
CREATE TABLE IF NOT EXISTS discovery_runs (
|
|
id SERIAL PRIMARY KEY,
|
|
platform VARCHAR(50) NOT NULL DEFAULT 'dutchie',
|
|
status VARCHAR(20) NOT NULL DEFAULT 'running', -- running, completed, failed
|
|
started_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
finished_at TIMESTAMPTZ,
|
|
task_id INTEGER REFERENCES worker_task_queue(id),
|
|
|
|
-- Totals
|
|
states_total INTEGER DEFAULT 0,
|
|
states_completed INTEGER DEFAULT 0,
|
|
locations_discovered INTEGER DEFAULT 0,
|
|
locations_promoted INTEGER DEFAULT 0,
|
|
new_store_ids INTEGER[] DEFAULT '{}',
|
|
|
|
-- Error info
|
|
error_message TEXT,
|
|
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Per-state progress within a run
|
|
CREATE TABLE IF NOT EXISTS discovery_run_states (
|
|
id SERIAL PRIMARY KEY,
|
|
run_id INTEGER NOT NULL REFERENCES discovery_runs(id) ON DELETE CASCADE,
|
|
state_code VARCHAR(2) NOT NULL,
|
|
status VARCHAR(20) NOT NULL DEFAULT 'pending', -- pending, running, completed, failed
|
|
started_at TIMESTAMPTZ,
|
|
finished_at TIMESTAMPTZ,
|
|
|
|
-- Results
|
|
cities_found INTEGER DEFAULT 0,
|
|
locations_found INTEGER DEFAULT 0,
|
|
locations_upserted INTEGER DEFAULT 0,
|
|
new_dispensary_ids INTEGER[] DEFAULT '{}',
|
|
|
|
-- Error info
|
|
error_message TEXT,
|
|
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
|
|
UNIQUE(run_id, state_code)
|
|
);
|
|
|
|
-- Step-by-step log for detailed progress tracking
|
|
CREATE TABLE IF NOT EXISTS discovery_run_steps (
|
|
id SERIAL PRIMARY KEY,
|
|
run_id INTEGER NOT NULL REFERENCES discovery_runs(id) ON DELETE CASCADE,
|
|
state_code VARCHAR(2),
|
|
step_name VARCHAR(100) NOT NULL,
|
|
status VARCHAR(20) NOT NULL DEFAULT 'started', -- started, completed, failed
|
|
started_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
finished_at TIMESTAMPTZ,
|
|
|
|
-- Details (JSON for flexibility)
|
|
details JSONB DEFAULT '{}',
|
|
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Indexes for querying
|
|
CREATE INDEX IF NOT EXISTS idx_discovery_runs_status ON discovery_runs(status);
|
|
CREATE INDEX IF NOT EXISTS idx_discovery_runs_platform ON discovery_runs(platform);
|
|
CREATE INDEX IF NOT EXISTS idx_discovery_runs_started_at ON discovery_runs(started_at DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_discovery_run_states_run_id ON discovery_run_states(run_id);
|
|
CREATE INDEX IF NOT EXISTS idx_discovery_run_steps_run_id ON discovery_run_steps(run_id);
|
|
|
|
-- View for latest run status per platform
|
|
CREATE OR REPLACE VIEW v_latest_discovery_runs AS
|
|
SELECT DISTINCT ON (platform)
|
|
id,
|
|
platform,
|
|
status,
|
|
started_at,
|
|
finished_at,
|
|
states_total,
|
|
states_completed,
|
|
locations_discovered,
|
|
locations_promoted,
|
|
array_length(new_store_ids, 1) as new_stores_count,
|
|
error_message,
|
|
EXTRACT(EPOCH FROM (COALESCE(finished_at, NOW()) - started_at)) as duration_seconds
|
|
FROM discovery_runs
|
|
ORDER BY platform, started_at DESC;
|