Phase 2: Household Creation & Invites - 6 plans in 4 waves covering SHARE-01 through SHARE-05 - Data models, repository pattern, and Supabase integration - Database schema with RLS policies for multi-tenant isolation - State management with Riverpod and business logic use cases - Complete UI components for household management - Navigation integration with authentication flow Ready for execution: /gsd:execute-phase 2
433 lines
15 KiB
Markdown
433 lines
15 KiB
Markdown
---
|
|
phase: 02-household-creation
|
|
plan: 02
|
|
type: execute
|
|
wave: 1
|
|
depends_on: []
|
|
files_modified:
|
|
- lib/features/household/data/datasources/household_remote_datasource.dart
|
|
- lib/features/household/domain/repositories/household_repository.dart
|
|
- lib/features/household/data/repositories/household_repository_impl.dart
|
|
- lib/features/household/domain/models/household_models.dart
|
|
- lib/features/household/domain/entities/household_entity.dart
|
|
autonomous: true
|
|
|
|
must_haves:
|
|
truths:
|
|
- "Supabase database schema supports households, members, and invite codes with proper relationships"
|
|
- "Row-Level Security policies isolate household data at database layer"
|
|
- "Database constraints prevent duplicate members and invalid invite codes"
|
|
- "Realtime subscriptions enable household member sync"
|
|
artifacts:
|
|
- path: "supabase/migrations/001_create_household_tables.sql"
|
|
provides: "Database schema for household functionality"
|
|
contains: "CREATE TABLE households", "CREATE TABLE household_members", "CREATE TABLE invite_codes"
|
|
- path: "supabase/migrations/002_household_rls_policies.sql"
|
|
provides: "Row-Level Security policies for household data isolation"
|
|
contains: "CREATE POLICY", "ROW LEVEL SECURITY"
|
|
- path: "supabase/migrations/003_household_indexes.sql"
|
|
provides: "Performance indexes for household queries"
|
|
contains: "CREATE INDEX", "household_id", "user_id"
|
|
key_links:
|
|
- from: "lib/features/household/data/repositories/household_repository_impl.dart"
|
|
to: "supabase/migrations/001_create_household_tables.sql"
|
|
via: "table operations"
|
|
pattern: "from.*households"
|
|
- from: "supabase/migrations/002_household_rls_policies.sql"
|
|
to: "supabase/migrations/001_create_household_tables.sql"
|
|
via: "security policies"
|
|
pattern: "POLICY.*FOR.*households"
|
|
---
|
|
|
|
<objective>
|
|
Create Supabase database schema with proper household isolation, member relationships, and invite code management.
|
|
|
|
Purpose: Establish database foundation that enforces multi-tenant security and supports real-time household synchronization requirements.
|
|
Output: Complete database schema with tables, RLS policies, and indexes for household operations.
|
|
</objective>
|
|
|
|
<execution_context>
|
|
@~/.opencode/get-shit-done/workflows/execute-plan.md
|
|
@~/.opencode/get-shit-done/templates/summary.md
|
|
</execution_context>
|
|
|
|
<context>
|
|
@.planning/PROJECT.md
|
|
@.planning/ROADMAP.md
|
|
@.planning/STATE.md
|
|
@.planning/research/ARCHITECTURE.md
|
|
|
|
# Database Architecture References
|
|
@lib/features/authentication/data/repositories/auth_repository_impl.dart
|
|
</context>
|
|
|
|
<tasks>
|
|
|
|
<task type="auto">
|
|
<name>Create Household Tables Migration</name>
|
|
<files>supabase/migrations/001_create_household_tables.sql</files>
|
|
<action>
|
|
Create database schema for household functionality:
|
|
|
|
1. households table:
|
|
```sql
|
|
CREATE TABLE households (
|
|
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
|
name TEXT NOT NULL CHECK (length(name) >= 1 AND length(name) <= 100),
|
|
created_by UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
|
|
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
|
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
|
);
|
|
|
|
CREATE TRIGGER households_updated_at
|
|
BEFORE UPDATE ON households
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
```
|
|
|
|
2. household_members table:
|
|
```sql
|
|
CREATE TABLE household_members (
|
|
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
|
household_id UUID NOT NULL REFERENCES households(id) ON DELETE CASCADE,
|
|
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
|
|
role TEXT NOT NULL CHECK (role IN ('owner', 'editor', 'viewer')),
|
|
joined_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
|
UNIQUE(household_id, user_id)
|
|
);
|
|
```
|
|
|
|
3. invite_codes table:
|
|
```sql
|
|
CREATE TABLE invite_codes (
|
|
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
|
household_id UUID NOT NULL REFERENCES households(id) ON DELETE CASCADE,
|
|
code TEXT NOT NULL UNIQUE CHECK (length(code) = 8),
|
|
created_by UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
|
|
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
|
expires_at TIMESTAMPTZ NOT NULL,
|
|
used_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
|
|
used_at TIMESTAMPTZ,
|
|
CONSTRAINT valid_invite_code CHECK (
|
|
(used_by IS NULL AND used_at IS NULL) OR
|
|
(used_by IS NOT NULL AND used_at IS NOT NULL)
|
|
)
|
|
);
|
|
```
|
|
|
|
Follow Supabase migration patterns and include proper constraints.
|
|
</action>
|
|
<verify>supabase db push --dry-run shows valid SQL syntax</verify>
|
|
<done>Household tables created with proper relationships and constraints</done>
|
|
</task>
|
|
|
|
<task type="auto">
|
|
<name>Create Household RLS Policies</name>
|
|
<files>supabase/migrations/002_household_rls_policies.sql</files>
|
|
<action>
|
|
Create Row-Level Security policies for household data isolation:
|
|
|
|
1. Enable RLS on all household tables:
|
|
```sql
|
|
ALTER TABLE households ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE household_members ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE invite_codes ENABLE ROW LEVEL SECURITY;
|
|
```
|
|
|
|
2. households table policies:
|
|
```sql
|
|
-- Users can view households they belong to
|
|
CREATE POLICY "Users can view their households" ON households
|
|
FOR SELECT USING (
|
|
id IN (
|
|
SELECT household_id FROM household_members
|
|
WHERE user_id = auth.uid()
|
|
)
|
|
);
|
|
|
|
-- Users can insert households (will be owner via member insertion)
|
|
CREATE POLICY "Users can create households" ON households
|
|
FOR INSERT WITH CHECK (created_by = auth.uid());
|
|
|
|
-- Only household owners can update households
|
|
CREATE POLICY "Owners can update households" ON households
|
|
FOR UPDATE USING (
|
|
id IN (
|
|
SELECT household_id FROM household_members
|
|
WHERE user_id = auth.uid() AND role = 'owner'
|
|
)
|
|
);
|
|
```
|
|
|
|
3. household_members table policies:
|
|
```sql
|
|
-- Users can view members of their households
|
|
CREATE POLICY "Users can view household members" ON household_members
|
|
FOR SELECT USING (
|
|
household_id IN (
|
|
SELECT household_id FROM household_members
|
|
WHERE user_id = auth.uid()
|
|
)
|
|
);
|
|
|
|
-- Users can insert themselves as members (via join flow)
|
|
CREATE POLICY "Users can join households" ON household_members
|
|
FOR INSERT WITH CHECK (user_id = auth.uid());
|
|
|
|
-- Only owners can manage member roles and remove members
|
|
CREATE POLICY "Owners can manage members" ON household_members
|
|
FOR UPDATE USING (
|
|
household_id IN (
|
|
SELECT household_id FROM household_members
|
|
WHERE user_id = auth.uid() AND role = 'owner'
|
|
)
|
|
);
|
|
|
|
-- Only owners can remove members (except themselves if last owner handled in app logic)
|
|
CREATE POLICY "Owners can remove members" ON household_members
|
|
FOR DELETE USING (
|
|
household_id IN (
|
|
SELECT household_id FROM household_members
|
|
WHERE user_id = auth.uid() AND role = 'owner'
|
|
)
|
|
);
|
|
```
|
|
|
|
4. invite_codes table policies:
|
|
```sql
|
|
-- Users can view invite codes for their households
|
|
CREATE POLICY "Users can view household invite codes" ON invite_codes
|
|
FOR SELECT USING (
|
|
household_id IN (
|
|
SELECT household_id FROM household_members
|
|
WHERE user_id = auth.uid()
|
|
)
|
|
);
|
|
|
|
-- Only owners can create invite codes
|
|
CREATE POLICY "Owners can create invite codes" ON invite_codes
|
|
FOR INSERT WITH CHECK (
|
|
created_by = auth.uid() AND
|
|
household_id IN (
|
|
SELECT household_id FROM household_members
|
|
WHERE user_id = auth.uid() AND role = 'owner'
|
|
)
|
|
);
|
|
|
|
-- Only owners can revoke invite codes
|
|
CREATE POLICY "Owners can revoke invite codes" ON invite_codes
|
|
FOR DELETE USING (
|
|
created_by = auth.uid()
|
|
);
|
|
```
|
|
|
|
Ensure policies enforce multi-tenant isolation at database layer.
|
|
</action>
|
|
<verify>supabase db push --dry-run shows valid RLS policies</verify>
|
|
<done>Row-Level Security policies enforce household data isolation with proper role-based access</done>
|
|
</task>
|
|
|
|
<task type="auto">
|
|
<name>Create Household Performance Indexes</name>
|
|
<files>supabase/migrations/003_household_indexes.sql</files>
|
|
<action>
|
|
Create performance indexes for household operations:
|
|
|
|
1. households table indexes:
|
|
```sql
|
|
-- For finding households by creator
|
|
CREATE INDEX idx_households_created_by ON households(created_by);
|
|
|
|
-- For household sorting by creation date
|
|
CREATE INDEX idx_households_created_at ON households(created_at);
|
|
```
|
|
|
|
2. household_members table indexes:
|
|
```sql
|
|
-- For finding user's households (primary query)
|
|
CREATE INDEX idx_household_members_user_id ON household_members(user_id);
|
|
|
|
-- For finding household members (primary query)
|
|
CREATE INDEX idx_household_members_household_id ON household_members(household_id);
|
|
|
|
-- Composite index for member role queries
|
|
CREATE INDEX idx_household_members_household_role ON household_members(household_id, role);
|
|
|
|
-- For checking if user is member of household
|
|
CREATE UNIQUE INDEX idx_household_members_unique ON household_members(household_id, user_id);
|
|
```
|
|
|
|
3. invite_codes table indexes:
|
|
```sql
|
|
-- For invite code lookup (primary query)
|
|
CREATE UNIQUE INDEX idx_invite_codes_code ON invite_codes(code);
|
|
|
|
-- For finding household's active invites
|
|
CREATE INDEX idx_invite_codes_household_id ON invite_codes(household_id);
|
|
|
|
-- For cleaning expired invites
|
|
CREATE INDEX idx_invite_codes_expires_at ON invite_codes(expires_at);
|
|
|
|
-- For finding unused invites
|
|
CREATE INDEX idx_invite_codes_unused ON invite_codes(used_by) WHERE used_by IS NULL;
|
|
```
|
|
|
|
4. Realtime function for household changes:
|
|
```sql
|
|
-- Function to broadcast household member changes
|
|
CREATE OR REPLACE FUNCTION broadcast_household_change()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
-- This will be used by Supabase Realtime
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Trigger for household member changes
|
|
CREATE TRIGGER household_members_broadcast
|
|
AFTER INSERT OR UPDATE OR DELETE ON household_members
|
|
FOR EACH ROW EXECUTE FUNCTION broadcast_household_change();
|
|
```
|
|
|
|
Include indexes that support the most common household queries and real-time sync.
|
|
</action>
|
|
<verify>supabase db push --dry-run shows valid index creation</verify>
|
|
<done>Performance indexes optimize household queries and support real-time synchronization</done>
|
|
</task>
|
|
|
|
<task type="auto">
|
|
<name>Create Household Database Functions</name>
|
|
<files>supabase/migrations/004_household_functions.sql</files>
|
|
<action>
|
|
Create database functions for household operations:
|
|
|
|
1. Generate unique invite code function:
|
|
```sql
|
|
CREATE OR REPLACE FUNCTION generate_invite_code()
|
|
RETURNS TEXT AS $$
|
|
DECLARE
|
|
new_code TEXT;
|
|
code_exists BOOLEAN;
|
|
BEGIN
|
|
LOOP
|
|
-- Generate 8-character alphanumeric code
|
|
new_code := upper(substring(encode(gen_random_bytes(4), 'hex'), 1, 8));
|
|
|
|
-- Check for collision
|
|
SELECT EXISTS(SELECT 1 FROM invite_codes WHERE code = new_code AND used_by IS NULL) INTO code_exists;
|
|
|
|
EXIT WHEN NOT code_exists;
|
|
END LOOP;
|
|
|
|
RETURN new_code;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
```
|
|
|
|
2. Get user's households with member info:
|
|
```sql
|
|
CREATE OR REPLACE FUNCTION get_user_households(user_uuid UUID)
|
|
RETURNS TABLE (
|
|
household_id UUID,
|
|
household_name TEXT,
|
|
user_role TEXT,
|
|
member_count BIGINT,
|
|
created_at TIMESTAMPTZ
|
|
) AS $$
|
|
BEGIN
|
|
RETURN QUERY
|
|
SELECT
|
|
h.id,
|
|
h.name,
|
|
hm.role,
|
|
(SELECT COUNT(*) FROM household_members WHERE household_id = h.id),
|
|
h.created_at
|
|
FROM households h
|
|
JOIN household_members hm ON h.id = hm.household_id
|
|
WHERE hm.user_id = user_uuid
|
|
ORDER BY h.created_at DESC;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
```
|
|
|
|
3. Validate and consume invite code:
|
|
```sql
|
|
CREATE OR REPLACE FUNCTION join_household_by_code(
|
|
invite_code TEXT,
|
|
user_uuid UUID
|
|
)
|
|
RETURNS TABLE (
|
|
success BOOLEAN,
|
|
household_id UUID,
|
|
household_name TEXT,
|
|
error_message TEXT
|
|
) AS $$
|
|
DECLARE
|
|
invite_record RECORD;
|
|
household_record RECORD;
|
|
is_already_member BOOLEAN;
|
|
BEGIN
|
|
-- Find valid invite code
|
|
SELECT ic.*, h.name as household_name INTO invite_record
|
|
FROM invite_codes ic
|
|
JOIN households h ON ic.household_id = h.id
|
|
WHERE ic.code = upper(invite_code)
|
|
AND ic.used_by IS NULL
|
|
AND ic.expires_at > now();
|
|
|
|
IF NOT FOUND THEN
|
|
RETURN QUERY SELECT false, NULL::UUID, NULL::TEXT, 'Invalid or expired invite code'::TEXT;
|
|
RETURN;
|
|
END IF;
|
|
|
|
-- Check if already member
|
|
SELECT EXISTS(
|
|
SELECT 1 FROM household_members
|
|
WHERE household_id = invite_record.household_id AND user_id = user_uuid
|
|
) INTO is_already_member;
|
|
|
|
IF is_already_member THEN
|
|
RETURN QUERY SELECT false, NULL::UUID, NULL::TEXT, 'Already a member of this household'::TEXT;
|
|
RETURN;
|
|
END IF;
|
|
|
|
-- Add as member with editor role
|
|
INSERT INTO household_members (household_id, user_id, role)
|
|
VALUES (invite_record.household_id, user_uuid, 'editor');
|
|
|
|
-- Mark invite as used
|
|
UPDATE invite_codes
|
|
SET used_by = user_uuid, used_at = now()
|
|
WHERE id = invite_record.id;
|
|
|
|
-- Get household info
|
|
SELECT id, name INTO household_record
|
|
FROM households WHERE id = invite_record.household_id;
|
|
|
|
RETURN QUERY SELECT true, household_record.id, household_record.name, NULL::TEXT;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
```
|
|
|
|
Include proper SECURITY DEFINER settings and error handling.
|
|
</action>
|
|
<verify>supabase db push --dry-run shows valid function creation</verify>
|
|
<done>Database functions provide efficient household operations with proper security</done>
|
|
</task>
|
|
|
|
</tasks>
|
|
|
|
<verification>
|
|
1. Database schema supports all household operations from SHARE-01 through SHARE-05
|
|
2. RLS policies enforce multi-tenant isolation at database layer
|
|
3. Performance indexes optimize common household queries
|
|
4. Database functions provide efficient invite code generation and validation
|
|
5. Realtime triggers support household member synchronization
|
|
</verification>
|
|
|
|
<success_criteria>
|
|
Supabase database schema is complete with household tables, security policies, indexes, and functions ready for application integration.
|
|
</success_criteria>
|
|
|
|
<output>
|
|
After completion, create `.planning/phases/02-household-creation/02-02-SUMMARY.md` with database schema implementation summary
|
|
</output> |