WellNuo/backend/migrations/006_complete_schema.sql
Sergei ec63a2c1e2 Add admin panel, optimized API, OTP auth, migrations
Admin Panel (Next.js):
- Dashboard with stats
- Users list with relationships (watches/watched_by)
- User detail pages
- Deployments list and detail pages
- Devices, Orders, Subscriptions pages
- OTP-based admin authentication

Backend Optimizations:
- Fixed N+1 query problem in admin APIs
- Added pagination support
- Added .range() and count support to Supabase wrapper
- Optimized batch queries with lookup maps

Database:
- Added migrations for schema evolution
- New tables: push_tokens, notification_settings
- Updated access model

iOS Build Scripts:
- build-ios.sh, clear-apple-cache.sh
- EAS configuration updates

🤖 Generated with [Claude Code](https://claude.com/claude-code)

Co-Authored-By: Claude <noreply@anthropic.com>
2025-12-20 11:05:39 -08:00

291 lines
10 KiB
PL/PgSQL

-- ============================================================
-- Migration 006: Complete Schema
-- Description: Add missing tables for full app functionality
-- - otp_codes (authentication)
-- - orders (e-commerce)
-- - subscriptions (billing)
-- - push_tokens (notifications)
-- - Fix owner_user_id in deployments
-- Date: 2025-12-19
-- ============================================================
-- ============================================================
-- 1. OTP_CODES - For email-based authentication
-- ============================================================
CREATE TABLE IF NOT EXISTS otp_codes (
id SERIAL PRIMARY KEY,
email VARCHAR(255) NOT NULL,
code VARCHAR(6) NOT NULL,
expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
used_at TIMESTAMP WITH TIME ZONE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- Prevent brute force: max 5 codes per email per hour
-- (enforced in application logic)
CONSTRAINT code_format CHECK (code ~ '^[0-9]{6}$')
);
CREATE INDEX IF NOT EXISTS idx_otp_email ON otp_codes(email);
CREATE INDEX IF NOT EXISTS idx_otp_code ON otp_codes(code);
CREATE INDEX IF NOT EXISTS idx_otp_expires ON otp_codes(expires_at);
-- Clean up expired codes automatically (optional, via cron or app)
-- DELETE FROM otp_codes WHERE expires_at < NOW() - INTERVAL '1 day';
-- ============================================================
-- 2. ORDERS - For sensor kit purchases
-- ============================================================
CREATE TABLE IF NOT EXISTS orders (
id SERIAL PRIMARY KEY,
order_number VARCHAR(20) UNIQUE NOT NULL, -- WN-2025-0001
-- Who placed the order
user_id INTEGER NOT NULL REFERENCES users(id),
-- For whom (beneficiary)
beneficiary_id INTEGER REFERENCES users(id),
beneficiary_name VARCHAR(200), -- Name before user created
beneficiary_address JSONB, -- Shipping address for sensors
-- Order details
items JSONB NOT NULL, -- [{sku, name, quantity, price}]
subtotal INTEGER NOT NULL, -- cents
shipping_cost INTEGER DEFAULT 0,
tax INTEGER DEFAULT 0,
total_amount INTEGER NOT NULL, -- cents
currency VARCHAR(3) DEFAULT 'USD',
-- Payment
stripe_session_id VARCHAR(255),
stripe_payment_intent VARCHAR(255),
paid_at TIMESTAMP WITH TIME ZONE,
-- Status flow: pending -> paid -> preparing -> shipped -> delivered -> installed
status VARCHAR(20) NOT NULL DEFAULT 'pending' CHECK (status IN (
'pending', -- awaiting payment
'paid', -- payment received
'preparing', -- packing order
'shipped', -- in transit
'delivered', -- at destination
'installed', -- sensors set up
'cancelled', -- order cancelled
'refunded' -- money returned
)),
-- Shipping
shipping_address JSONB, -- {street, city, state, zip, country}
shipping_method VARCHAR(50),
tracking_number VARCHAR(100),
carrier VARCHAR(50), -- UPS, FedEx, USPS
shipped_at TIMESTAMP WITH TIME ZONE,
delivered_at TIMESTAMP WITH TIME ZONE,
-- Notes
notes TEXT,
admin_notes TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
CREATE INDEX IF NOT EXISTS idx_orders_user ON orders(user_id);
CREATE INDEX IF NOT EXISTS idx_orders_beneficiary ON orders(beneficiary_id);
CREATE INDEX IF NOT EXISTS idx_orders_status ON orders(status);
CREATE INDEX IF NOT EXISTS idx_orders_number ON orders(order_number);
CREATE INDEX IF NOT EXISTS idx_orders_stripe ON orders(stripe_session_id);
-- Function to generate order number
CREATE OR REPLACE FUNCTION generate_order_number()
RETURNS TRIGGER AS $$
BEGIN
IF NEW.order_number IS NULL THEN
NEW.order_number := 'WN-' || TO_CHAR(NOW(), 'YYYY') || '-' ||
LPAD(nextval('orders_id_seq')::TEXT, 4, '0');
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS set_order_number ON orders;
CREATE TRIGGER set_order_number
BEFORE INSERT ON orders
FOR EACH ROW
EXECUTE FUNCTION generate_order_number();
-- ============================================================
-- 3. SUBSCRIPTIONS - For Premium plans
-- ============================================================
CREATE TABLE IF NOT EXISTS subscriptions (
id SERIAL PRIMARY KEY,
-- Who pays
user_id INTEGER NOT NULL REFERENCES users(id),
-- For whom
beneficiary_id INTEGER NOT NULL REFERENCES users(id),
-- Plan: free or premium
plan VARCHAR(20) NOT NULL DEFAULT 'free' CHECK (plan IN ('free', 'premium')),
-- Stripe
stripe_subscription_id VARCHAR(255),
stripe_customer_id VARCHAR(255),
stripe_price_id VARCHAR(255),
-- Status
status VARCHAR(20) NOT NULL DEFAULT 'active' CHECK (status IN (
'active', -- subscription is active
'past_due', -- payment failed, grace period
'canceled', -- user canceled
'unpaid', -- payment failed, access restricted
'trialing' -- in trial period
)),
-- Billing cycle
current_period_start TIMESTAMP WITH TIME ZONE,
current_period_end TIMESTAMP WITH TIME ZONE,
cancel_at_period_end BOOLEAN DEFAULT false,
canceled_at TIMESTAMP WITH TIME ZONE,
-- Trial
trial_start TIMESTAMP WITH TIME ZONE,
trial_end TIMESTAMP WITH TIME ZONE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- One active subscription per user-beneficiary pair
UNIQUE(user_id, beneficiary_id)
);
CREATE INDEX IF NOT EXISTS idx_subs_user ON subscriptions(user_id);
CREATE INDEX IF NOT EXISTS idx_subs_beneficiary ON subscriptions(beneficiary_id);
CREATE INDEX IF NOT EXISTS idx_subs_stripe ON subscriptions(stripe_subscription_id);
CREATE INDEX IF NOT EXISTS idx_subs_status ON subscriptions(status);
-- ============================================================
-- 4. PUSH_TOKENS - For mobile notifications
-- ============================================================
CREATE TABLE IF NOT EXISTS push_tokens (
id SERIAL PRIMARY KEY,
user_id INTEGER NOT NULL REFERENCES users(id) ON DELETE CASCADE,
-- Expo push token
token VARCHAR(255) NOT NULL,
-- Device info
platform VARCHAR(10) CHECK (platform IN ('ios', 'android', 'web')),
device_name VARCHAR(100),
-- Status
is_active BOOLEAN DEFAULT true,
last_used_at TIMESTAMP WITH TIME ZONE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- One token per device
UNIQUE(token)
);
CREATE INDEX IF NOT EXISTS idx_push_user ON push_tokens(user_id);
CREATE INDEX IF NOT EXISTS idx_push_token ON push_tokens(token);
CREATE INDEX IF NOT EXISTS idx_push_active ON push_tokens(is_active) WHERE is_active = true;
-- ============================================================
-- 5. NOTIFICATION_SETTINGS - Per-user notification preferences
-- ============================================================
CREATE TABLE IF NOT EXISTS notification_settings (
id SERIAL PRIMARY KEY,
user_id INTEGER NOT NULL REFERENCES users(id) ON DELETE CASCADE,
-- What to notify about
notify_no_activity BOOLEAN DEFAULT true, -- No movement for X hours
notify_unusual_pattern BOOLEAN DEFAULT true, -- Unusual behavior
notify_sensor_offline BOOLEAN DEFAULT true, -- Device went offline
notify_weekly_report BOOLEAN DEFAULT true, -- Weekly summary
-- Thresholds
no_activity_hours INTEGER DEFAULT 6, -- Alert after X hours
-- Quiet hours (no notifications)
quiet_hours_enabled BOOLEAN DEFAULT false,
quiet_hours_start TIME DEFAULT '22:00',
quiet_hours_end TIME DEFAULT '07:00',
-- Channels
push_enabled BOOLEAN DEFAULT true,
email_enabled BOOLEAN DEFAULT true,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
UNIQUE(user_id)
);
CREATE INDEX IF NOT EXISTS idx_notif_user ON notification_settings(user_id);
-- ============================================================
-- 6. TRY TO ADD owner_user_id TO deployments
-- (May fail if not owner - that's OK, will need admin access)
-- ============================================================
DO $$
BEGIN
-- Check if column exists
IF NOT EXISTS (
SELECT 1 FROM information_schema.columns
WHERE table_name = 'deployments' AND column_name = 'owner_user_id'
) THEN
-- Try to add column
BEGIN
ALTER TABLE deployments ADD COLUMN owner_user_id INTEGER REFERENCES users(id);
CREATE INDEX idx_deployments_owner ON deployments(owner_user_id);
RAISE NOTICE 'Added owner_user_id to deployments';
EXCEPTION WHEN insufficient_privilege THEN
RAISE WARNING 'Cannot add owner_user_id to deployments - need table owner access';
END;
ELSE
RAISE NOTICE 'owner_user_id already exists in deployments';
END IF;
END $$;
-- ============================================================
-- 7. HELPER FUNCTIONS
-- ============================================================
-- Function to check if user has access to beneficiary
CREATE OR REPLACE FUNCTION user_has_access(
p_accessor_id INTEGER,
p_beneficiary_id INTEGER,
p_required_role VARCHAR DEFAULT NULL
) RETURNS BOOLEAN AS $$
BEGIN
RETURN EXISTS (
SELECT 1 FROM user_access
WHERE accessor_id = p_accessor_id
AND beneficiary_id = p_beneficiary_id
AND (p_required_role IS NULL OR role = p_required_role)
);
END;
$$ LANGUAGE plpgsql;
-- Function to get all deployments user can access
CREATE OR REPLACE FUNCTION get_accessible_deployments(p_user_id INTEGER)
RETURNS TABLE (deployment_id INTEGER, owner_email VARCHAR, role VARCHAR) AS $$
BEGIN
RETURN QUERY
SELECT d.deployment_id, u.email, ua.role
FROM deployments d
JOIN users u ON u.legacy_person_id = (
SELECT dd.beneficiary_id FROM deployment_details dd
WHERE dd.deployment_id = d.deployment_id LIMIT 1
)
JOIN user_access ua ON ua.beneficiary_id = u.id
WHERE ua.accessor_id = p_user_id;
END;
$$ LANGUAGE plpgsql;
-- ============================================================
-- DONE
-- ============================================================