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>
213 lines
7.8 KiB
SQL
213 lines
7.8 KiB
SQL
-- ============================================================
|
|
-- Migration 005: New Access Model
|
|
-- Description: Create users table, user_access table, invitations
|
|
-- and add owner_user_id to deployments
|
|
-- Date: 2025-12-19
|
|
-- ============================================================
|
|
|
|
-- ============================================================
|
|
-- 1. CREATE users TABLE (replaces person_details for auth)
|
|
-- ============================================================
|
|
CREATE TABLE IF NOT EXISTS users (
|
|
id SERIAL PRIMARY KEY,
|
|
email VARCHAR(255) UNIQUE NOT NULL,
|
|
phone VARCHAR(50),
|
|
first_name VARCHAR(100),
|
|
last_name VARCHAR(100),
|
|
-- NO password_hash - using OTP via email
|
|
|
|
-- Address (for user profile)
|
|
address_street VARCHAR(255),
|
|
address_city VARCHAR(100),
|
|
address_zip VARCHAR(20),
|
|
address_state VARCHAR(100),
|
|
address_country VARCHAR(100),
|
|
|
|
-- System fields
|
|
is_active BOOLEAN DEFAULT true,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
last_login_at TIMESTAMP WITH TIME ZONE,
|
|
|
|
-- Legacy reference for migration
|
|
legacy_person_id INTEGER,
|
|
|
|
CONSTRAINT email_format CHECK (email ~* '^[A-Za-z0-9._%+-]+@[A-Za-z0-9.-]+\.[A-Za-z]{2,}$')
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_users_email ON users(email);
|
|
CREATE INDEX IF NOT EXISTS idx_users_legacy ON users(legacy_person_id);
|
|
|
|
-- ============================================================
|
|
-- 2. ADD owner_user_id TO deployments
|
|
-- ============================================================
|
|
ALTER TABLE deployments
|
|
ADD COLUMN IF NOT EXISTS owner_user_id INTEGER REFERENCES users(id);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_deployments_owner ON deployments(owner_user_id);
|
|
|
|
-- ============================================================
|
|
-- 3. CREATE user_access TABLE (who can access whom)
|
|
-- ============================================================
|
|
CREATE TABLE IF NOT EXISTS user_access (
|
|
id SERIAL PRIMARY KEY,
|
|
|
|
-- Who is being accessed (beneficiary - the elderly person)
|
|
beneficiary_id INTEGER NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
|
|
-- Who has access (caretaker, owner, installer)
|
|
accessor_id INTEGER NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
|
|
-- What kind of access
|
|
role VARCHAR(20) NOT NULL CHECK (role IN (
|
|
'caretaker', -- can view data, receive alerts
|
|
'owner', -- can pay, invite others, manage subscription
|
|
'installer' -- can configure devices
|
|
)),
|
|
|
|
-- Who granted this access
|
|
granted_by INTEGER REFERENCES users(id),
|
|
granted_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
|
|
-- One accessor can have multiple roles for same beneficiary
|
|
UNIQUE(beneficiary_id, accessor_id, role)
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_ua_beneficiary ON user_access(beneficiary_id);
|
|
CREATE INDEX IF NOT EXISTS idx_ua_accessor ON user_access(accessor_id);
|
|
CREATE INDEX IF NOT EXISTS idx_ua_role ON user_access(role);
|
|
|
|
-- ============================================================
|
|
-- 4. CREATE invitations TABLE (for inviting new users)
|
|
-- ============================================================
|
|
CREATE TABLE IF NOT EXISTS invitations (
|
|
id SERIAL PRIMARY KEY,
|
|
|
|
-- Who to give access to (the beneficiary)
|
|
beneficiary_id INTEGER NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
|
|
-- Invited person's email
|
|
email VARCHAR(255) NOT NULL,
|
|
|
|
-- What role to grant
|
|
role VARCHAR(20) NOT NULL CHECK (role IN ('caretaker', 'owner', 'installer')),
|
|
|
|
-- Security token (64 char hex)
|
|
token VARCHAR(64) UNIQUE NOT NULL,
|
|
|
|
-- Who sent the invitation
|
|
invited_by INTEGER NOT NULL REFERENCES users(id),
|
|
|
|
-- Expiration
|
|
expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
|
|
|
|
-- When accepted
|
|
accepted_at TIMESTAMP WITH TIME ZONE,
|
|
accepted_by INTEGER REFERENCES users(id),
|
|
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_inv_token ON invitations(token);
|
|
CREATE INDEX IF NOT EXISTS idx_inv_email ON invitations(email);
|
|
CREATE INDEX IF NOT EXISTS idx_inv_beneficiary ON invitations(beneficiary_id);
|
|
|
|
-- ============================================================
|
|
-- 5. MIGRATE DATA from person_details to users
|
|
-- ============================================================
|
|
INSERT INTO users (
|
|
email, phone, first_name, last_name,
|
|
address_street, address_city, address_zip, address_state, address_country,
|
|
legacy_person_id, created_at
|
|
)
|
|
SELECT
|
|
COALESCE(email, user_name || '@legacy.wellnuo.local'),
|
|
phone_number,
|
|
first_name,
|
|
last_name,
|
|
address_street, address_city, address_zip, address_state, address_country,
|
|
user_id,
|
|
COALESCE(to_timestamp(time_edit), NOW())
|
|
FROM person_details
|
|
WHERE email IS NOT NULL OR user_name IS NOT NULL
|
|
ON CONFLICT (email) DO NOTHING;
|
|
|
|
-- ============================================================
|
|
-- 6. SET owner_user_id on deployments from deployment_details
|
|
-- ============================================================
|
|
UPDATE deployments d
|
|
SET owner_user_id = u.id
|
|
FROM deployment_details dd
|
|
JOIN users u ON u.legacy_person_id = dd.beneficiary_id
|
|
WHERE d.deployment_id = dd.deployment_id
|
|
AND d.owner_user_id IS NULL;
|
|
|
|
-- ============================================================
|
|
-- 7. MIGRATE ACCESS RELATIONSHIPS from deployment_details
|
|
-- ============================================================
|
|
|
|
-- Caretakers
|
|
INSERT INTO user_access (beneficiary_id, accessor_id, role)
|
|
SELECT
|
|
beneficiary_user.id,
|
|
caretaker_user.id,
|
|
'caretaker'
|
|
FROM deployment_details dd
|
|
JOIN users beneficiary_user ON beneficiary_user.legacy_person_id = dd.beneficiary_id
|
|
JOIN users caretaker_user ON caretaker_user.legacy_person_id = dd.caretaker_id
|
|
WHERE dd.beneficiary_id IS NOT NULL
|
|
AND dd.caretaker_id IS NOT NULL
|
|
AND dd.beneficiary_id != dd.caretaker_id
|
|
ON CONFLICT (beneficiary_id, accessor_id, role) DO NOTHING;
|
|
|
|
-- Owners
|
|
INSERT INTO user_access (beneficiary_id, accessor_id, role)
|
|
SELECT
|
|
beneficiary_user.id,
|
|
owner_user.id,
|
|
'owner'
|
|
FROM deployment_details dd
|
|
JOIN users beneficiary_user ON beneficiary_user.legacy_person_id = dd.beneficiary_id
|
|
JOIN users owner_user ON owner_user.legacy_person_id = dd.owner_id
|
|
WHERE dd.beneficiary_id IS NOT NULL
|
|
AND dd.owner_id IS NOT NULL
|
|
AND dd.beneficiary_id != dd.owner_id
|
|
ON CONFLICT (beneficiary_id, accessor_id, role) DO NOTHING;
|
|
|
|
-- Installers
|
|
INSERT INTO user_access (beneficiary_id, accessor_id, role)
|
|
SELECT
|
|
beneficiary_user.id,
|
|
installer_user.id,
|
|
'installer'
|
|
FROM deployment_details dd
|
|
JOIN users beneficiary_user ON beneficiary_user.legacy_person_id = dd.beneficiary_id
|
|
JOIN users installer_user ON installer_user.legacy_person_id = dd.installer_id
|
|
WHERE dd.beneficiary_id IS NOT NULL
|
|
AND dd.installer_id IS NOT NULL
|
|
AND dd.beneficiary_id != dd.installer_id
|
|
ON CONFLICT (beneficiary_id, accessor_id, role) DO NOTHING;
|
|
|
|
-- ============================================================
|
|
-- 8. MIGRATE access_to_deployments (legacy caretaker access)
|
|
-- ============================================================
|
|
-- This converts "21,38,29" style access to proper relationships
|
|
INSERT INTO user_access (beneficiary_id, accessor_id, role)
|
|
SELECT DISTINCT
|
|
deployment_owner.id,
|
|
accessor.id,
|
|
'caretaker'
|
|
FROM person_details pd
|
|
CROSS JOIN LATERAL unnest(string_to_array(pd.access_to_deployments, ',')) AS deployment_id_str
|
|
JOIN deployment_details dd ON dd.deployment_id = deployment_id_str::int
|
|
JOIN users deployment_owner ON deployment_owner.legacy_person_id = dd.beneficiary_id
|
|
JOIN users accessor ON accessor.legacy_person_id = pd.user_id
|
|
WHERE pd.access_to_deployments IS NOT NULL
|
|
AND pd.access_to_deployments != ''
|
|
AND deployment_owner.id != accessor.id
|
|
ON CONFLICT (beneficiary_id, accessor_id, role) DO NOTHING;
|
|
|
|
-- ============================================================
|
|
-- DONE
|
|
-- ============================================================
|