# Collaborative Webinar Implementation Guide (FIXED) **Project:** WithDwindi Learning Hub - Collaboration Feature **Date:** February 2, 2026 **Architecture:** Wallet-based profit tracking system **CRITICAL FIX:** Corrected migration order to resolve dependencies properly --- ## Migration Execution Order (READ THIS FIRST!) **Execute migrations in THIS exact order:** 1. ✅ Platform settings extension (no dependencies) 2. ✅ Profile fields (no dependencies) 3. ✅ User access enhancement (no dependencies) 4. ✅ Products collaboration fields (no dependencies) 5. ✅ **Wallet tables** (MUST be first - creates the tables others reference) 6. ✅ Wallet functions (needs wallet tables) 7. ✅ Order items profit fields (references wallet_transactions - now exists) 8. ✅ Withdrawals table (references wallet_transactions - now exists) 9. ✅ Collaborator profits view (references wallet_transactions - now exists) 10. ✅ Triggers (needs products and wallets) --- ## Migration 1: Extend Platform Settings (DO THIS FIRST) **Why first:** No dependencies, other migrations/functions will read these fields from `platform_settings` ```sql -- Add owner + collaboration fields into existing platform_settings table ALTER TABLE platform_settings ADD COLUMN IF NOT EXISTS owner_name TEXT DEFAULT 'Dwindi', ADD COLUMN IF NOT EXISTS owner_avatar_url TEXT DEFAULT '', ADD COLUMN IF NOT EXISTS collaboration_enabled BOOLEAN DEFAULT true, ADD COLUMN IF NOT EXISTS min_withdrawal_amount INTEGER DEFAULT 100000, ADD COLUMN IF NOT EXISTS default_profit_share INTEGER DEFAULT 50, ADD COLUMN IF NOT EXISTS max_pending_withdrawals INTEGER DEFAULT 1, ADD COLUMN IF NOT EXISTS withdrawal_processing_days INTEGER DEFAULT 3; -- Backfill nulls for existing rows UPDATE platform_settings SET owner_name = COALESCE(owner_name, 'Dwindi'), owner_avatar_url = COALESCE(owner_avatar_url, ''), collaboration_enabled = COALESCE(collaboration_enabled, true), min_withdrawal_amount = COALESCE(min_withdrawal_amount, 100000), default_profit_share = COALESCE(default_profit_share, 50), max_pending_withdrawals = COALESCE(max_pending_withdrawals, 1), withdrawal_processing_days = COALESCE(withdrawal_processing_days, 3); COMMENT ON COLUMN platform_settings.owner_name IS 'Owner/Host name displayed on webinar cards'; COMMENT ON COLUMN platform_settings.owner_avatar_url IS 'Owner/Host avatar URL displayed on webinar cards'; COMMENT ON COLUMN platform_settings.collaboration_enabled IS 'Enable collaboration feature globally'; COMMENT ON COLUMN platform_settings.min_withdrawal_amount IS 'Minimum withdrawal amount in IDR'; COMMENT ON COLUMN platform_settings.default_profit_share IS 'Default profit share percentage for collaborator'; COMMENT ON COLUMN platform_settings.max_pending_withdrawals IS 'Maximum pending withdrawals per collaborator'; COMMENT ON COLUMN platform_settings.withdrawal_processing_days IS 'Expected withdrawal processing time in business days'; ``` **Execute:** Copy-paste into Supabase SQL Editor → Run --- ## Migration 2: Add Collaborator Profile Fields **Why second:** No dependencies, needs to exist before collaborators can be created ```sql -- Add bank account fields to profiles table ALTER TABLE profiles ADD COLUMN IF NOT EXISTS bio TEXT, ADD COLUMN IF NOT EXISTS portfolio_url TEXT, ADD COLUMN IF NOT EXISTS bank_account_number VARCHAR(50), ADD COLUMN IF NOT EXISTS bank_account_name VARCHAR(100), ADD COLUMN IF NOT EXISTS bank_name VARCHAR(50); -- Add constraint for valid URLs DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM pg_constraint WHERE conname = 'valid_portfolio_url' ) THEN ALTER TABLE profiles ADD CONSTRAINT valid_portfolio_url CHECK (portfolio_url IS NULL OR portfolio_url ~* '^https?://'); END IF; END $$; -- Add comments COMMENT ON COLUMN profiles.bio IS 'Collaborator bio/description'; COMMENT ON COLUMN profiles.portfolio_url IS 'Collaborator portfolio URL'; COMMENT ON COLUMN profiles.bank_account_number IS 'Collaborator bank account for withdrawals'; COMMENT ON COLUMN profiles.bank_account_name IS 'Bank account holder name (must match ID)'; COMMENT ON COLUMN profiles.bank_name IS 'Bank name (e.g., BCA, Mandiri, BNI)'; ``` **Execute:** Copy-paste into Supabase SQL Editor → Run --- ## Migration 3: Enhance User Access Table **Why third:** No dependencies, needs to exist before we grant collaborator access ```sql -- Add tracking fields to user_access table ALTER TABLE user_access ADD COLUMN IF NOT EXISTS access_type VARCHAR(20) DEFAULT 'purchase' CHECK (access_type IN ('purchase', 'collaborator', 'admin', 'manual')), ADD COLUMN IF NOT EXISTS granted_by UUID REFERENCES auth.users(id); -- Update existing records to 'purchase' UPDATE user_access SET access_type = 'purchase' WHERE access_type IS NULL; -- Add index for collaborator access queries CREATE INDEX IF NOT EXISTS idx_user_access_type ON user_access(user_id, access_type); COMMENT ON COLUMN user_access.access_type IS 'How access was granted: purchase, collaborator, admin, or manual'; COMMENT ON COLUMN user_access.granted_by IS 'User who granted this access (for collaborator/manual)'; ``` **Execute:** Copy-paste into Supabase SQL Editor → Run --- ## Migration 4: Add Collaboration Fields to Products **Why fourth:** No dependencies, needs to exist before wallet trigger (Migration 10) ```sql -- Add collaboration fields to products table ALTER TABLE products ADD COLUMN IF NOT EXISTS collaborator_user_id UUID REFERENCES auth.users(id) ON DELETE SET NULL, ADD COLUMN IF NOT EXISTS profit_share_percentage INTEGER DEFAULT 0 CHECK (profit_share_percentage >= 0 AND profit_share_percentage <= 100), ADD COLUMN IF NOT EXISTS host_share_percentage INTEGER GENERATED ALWAYS AS (100 - profit_share_percentage) STORED, ADD COLUMN IF NOT EXISTS auto_grant_access BOOLEAN DEFAULT true; -- Add index for collaborator queries CREATE INDEX IF NOT EXISTS idx_products_collaborator ON products(collaborator_user_id) WHERE collaborator_user_id IS NOT NULL; COMMENT ON COLUMN products.collaborator_user_id IS 'Collaborator user ID (null if solo product)'; COMMENT ON COLUMN products.profit_share_percentage IS 'Profit share percentage for collaborator (0-100)'; COMMENT ON COLUMN products.auto_grant_access IS 'Automatically grant product access to collaborator'; ``` **Execute:** Copy-paste into Supabase SQL Editor → Run --- ## Migration 5: Create Wallet Tables (CRITICAL - DO THIS BEFORE ANYTHING ELSE) **Why fifth:** **Creates `wallet_transactions` and `collaborator_wallets`** that other migrations reference ```sql -- Create collaborator wallets table CREATE TABLE IF NOT EXISTS collaborator_wallets ( user_id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE, current_balance DECIMAL(12,2) NOT NULL DEFAULT 0, total_earned DECIMAL(12,2) NOT NULL DEFAULT 0, total_withdrawn DECIMAL(12,2) NOT NULL DEFAULT 0, pending_balance DECIMAL(12,2) NOT NULL DEFAULT 0, updated_at TIMESTAMPTZ DEFAULT NOW() ); -- Create index for balance queries CREATE INDEX IF NOT EXISTS idx_wallets_balance ON collaborator_wallets(current_balance); -- Enable RLS ALTER TABLE collaborator_wallets ENABLE ROW LEVEL SECURITY; DROP POLICY IF EXISTS "Users can view own wallet" ON collaborator_wallets; DROP POLICY IF EXISTS "Admins can view all wallets" ON collaborator_wallets; CREATE POLICY "Users can view own wallet" ON collaborator_wallets FOR SELECT USING (auth.uid() = user_id); CREATE POLICY "Admins can view all wallets" ON collaborator_wallets FOR SELECT USING ( EXISTS ( SELECT 1 FROM user_roles WHERE user_id = auth.uid() AND role = 'admin' ) ); COMMENT ON TABLE collaborator_wallets IS 'Collaborator wallet balances'; COMMENT ON COLUMN collaborator_wallets.current_balance IS 'Available balance (can be withdrawn)'; COMMENT ON COLUMN collaborator_wallets.pending_balance IS 'Balance in pending withdrawals'; COMMENT ON COLUMN collaborator_wallets.total_earned IS 'Lifetime earnings from all collaborative sales'; -- Create wallet transactions table (audit trail) CREATE TABLE IF NOT EXISTS wallet_transactions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, order_id UUID REFERENCES orders(id) ON DELETE SET NULL, order_item_id UUID REFERENCES order_items(id) ON DELETE SET NULL, -- Keep this as plain UUID for now; FK is added in Migration 8 after withdrawals exists withdrawal_id UUID, transaction_type VARCHAR(20) NOT NULL CHECK (transaction_type IN ('credit', 'debit', 'withdrawal', 'refund')), amount DECIMAL(12,2) NOT NULL CHECK (amount > 0), balance_after DECIMAL(12,2) NOT NULL, status VARCHAR(20) DEFAULT 'completed' CHECK (status IN ('pending', 'completed', 'failed', 'reversed')), description TEXT, metadata JSONB, created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); -- Create indexes CREATE INDEX IF NOT EXISTS idx_wallet_transactions_user ON wallet_transactions(user_id, created_at DESC); CREATE INDEX IF NOT EXISTS idx_wallet_transactions_order ON wallet_transactions(order_id); CREATE INDEX IF NOT EXISTS idx_wallet_transactions_withdrawal ON wallet_transactions(withdrawal_id) WHERE withdrawal_id IS NOT NULL; CREATE INDEX IF NOT EXISTS idx_wallet_transactions_type ON wallet_transactions(transaction_type, created_at DESC); -- Enable RLS ALTER TABLE wallet_transactions ENABLE ROW LEVEL SECURITY; DROP POLICY IF EXISTS "Users can view own transactions" ON wallet_transactions; DROP POLICY IF EXISTS "Admins can view all transactions" ON wallet_transactions; CREATE POLICY "Users can view own transactions" ON wallet_transactions FOR SELECT USING (auth.uid() = user_id); CREATE POLICY "Admins can view all transactions" ON wallet_transactions FOR SELECT USING ( EXISTS ( SELECT 1 FROM user_roles WHERE user_id = auth.uid() AND role = 'admin' ) ); COMMENT ON TABLE wallet_transactions IS 'Wallet transaction history for audit trail'; COMMENT ON COLUMN wallet_transactions.transaction_type IS 'credit: earned, debit: refunded, withdrawal: requested withdrawal'; COMMENT ON COLUMN wallet_transactions.balance_after IS 'Wallet balance after this transaction'; COMMENT ON COLUMN wallet_transactions.metadata IS 'Additional data (e.g., order details, product info)'; ``` **Execute:** Copy-paste into Supabase SQL Editor → Run **✅ CRITICAL:** **This must be completed BEFORE migrations 6-10!** --- ## Migration 6: Create Wallet Functions **Why sixth:** Needs `wallet_transactions` and `collaborator_wallets` tables (created in Migration 5) ```sql -- Function to credit wallet (called when order is paid) CREATE OR REPLACE FUNCTION credit_collaborator_wallet( p_user_id UUID, p_order_item_id UUID, p_amount DECIMAL(12,2), p_description TEXT ) RETURNS UUID AS $$ DECLARE v_transaction_id UUID; v_new_balance DECIMAL(12,2); BEGIN -- Lock wallet row LOCK TABLE collaborator_wallets IN EXCLUSIVE MODE; -- Get current balance or create wallet INSERT INTO collaborator_wallets (user_id, current_balance, total_earned) VALUES (p_user_id, 0, 0) ON CONFLICT (user_id) DO NOTHING; -- Update wallet balance UPDATE collaborator_wallets SET current_balance = current_balance + p_amount, total_earned = total_earned + p_amount, updated_at = NOW() WHERE user_id = p_user_id RETURNING current_balance INTO v_new_balance; -- Create transaction record INSERT INTO wallet_transactions ( user_id, order_item_id, transaction_type, amount, balance_after, description, metadata ) VALUES ( p_user_id, p_order_item_id, 'credit', p_amount, v_new_balance, p_description, jsonb_build_object( 'credited_at', NOW(), 'order_item_id', p_order_item_id ) ) RETURNING id INTO v_transaction_id; -- Update order_item with transaction reference UPDATE order_items SET wallet_transaction_id = v_transaction_id WHERE id = p_order_item_id; RETURN v_transaction_id; END; $$ LANGUAGE plpgsql SECURITY DEFINER; COMMENT ON FUNCTION credit_collaborator_wallet IS 'Credit collaborator wallet when order is paid. Returns transaction ID.'; -- Function to get wallet balance CREATE OR REPLACE FUNCTION get_collaborator_wallet(p_user_id UUID) RETURNS TABLE( current_balance DECIMAL(12,2), total_earned DECIMAL(12,2), total_withdrawn DECIMAL(12,2), pending_balance DECIMAL(12,2) ) AS $$ BEGIN RETURN QUERY SELECT COALESCE(w.current_balance, 0) as current_balance, COALESCE(w.total_earned, 0) as total_earned, COALESCE(w.total_withdrawn, 0) as total_withdrawn, COALESCE(w.pending_balance, 0) as pending_balance FROM collaborator_wallets w WHERE w.user_id = p_user_id; END; $$ LANGUAGE plpgsql SECURITY DEFINER; COMMENT ON FUNCTION get_collaborator_wallet IS 'Get collaborator wallet balance (returns 0 if no wallet exists)'; -- Function to get collaboration settings CREATE OR REPLACE FUNCTION get_collaboration_settings() RETURNS TABLE( collaboration_enabled BOOLEAN, min_withdrawal_amount INTEGER, default_profit_share INTEGER, max_pending_withdrawals INTEGER, withdrawal_processing_days INTEGER ) AS $$ BEGIN RETURN QUERY SELECT COALESCE((SELECT ps.collaboration_enabled FROM platform_settings ps LIMIT 1), true) as collaboration_enabled, COALESCE((SELECT ps.min_withdrawal_amount FROM platform_settings ps LIMIT 1), 100000) as min_withdrawal_amount, COALESCE((SELECT ps.default_profit_share FROM platform_settings ps LIMIT 1), 50) as default_profit_share, COALESCE((SELECT ps.max_pending_withdrawals FROM platform_settings ps LIMIT 1), 1) as max_pending_withdrawals, COALESCE((SELECT ps.withdrawal_processing_days FROM platform_settings ps LIMIT 1), 3) as withdrawal_processing_days; END; $$ LANGUAGE plpgsql SECURITY DEFINER; COMMENT ON FUNCTION get_collaboration_settings IS 'Get all collaboration-related settings'; -- Function to hold withdrawal amount CREATE OR REPLACE FUNCTION hold_withdrawal_amount( p_user_id UUID, p_withdrawal_id UUID, p_amount DECIMAL(12,2) ) RETURNS UUID AS $$ DECLARE v_transaction_id UUID; v_new_balance DECIMAL(12,2); BEGIN -- Lock wallet row LOCK TABLE collaborator_wallets IN EXCLUSIVE MODE; -- Check sufficient balance SELECT current_balance INTO v_new_balance FROM collaborator_wallets WHERE user_id = p_user_id FOR UPDATE; IF v_new_balance < p_amount THEN RAISE EXCEPTION 'Insufficient balance'; END IF; -- Update wallet (deduct from current, add to pending) UPDATE collaborator_wallets SET current_balance = current_balance - p_amount, pending_balance = pending_balance + p_amount, updated_at = NOW() WHERE user_id = p_user_id RETURNING current_balance INTO v_new_balance; -- Create transaction record INSERT INTO wallet_transactions ( user_id, withdrawal_id, transaction_type, amount, balance_after, description, status, metadata ) VALUES ( p_user_id, p_withdrawal_id, 'withdrawal', p_amount, v_new_balance, 'Withdrawal request - amount held pending approval', 'pending', jsonb_build_object( 'withdrawal_id', p_withdrawal_id, 'held_at', NOW() ) ) RETURNING id INTO v_transaction_id; RETURN v_transaction_id; END; $$ LANGUAGE plpgsql SECURITY DEFINER; COMMENT ON FUNCTION hold_withdrawal_amount IS 'Hold withdrawal amount in pending balance. Raises exception if insufficient funds.'; -- Function to complete withdrawal CREATE OR REPLACE FUNCTION complete_withdrawal( p_user_id UUID, p_withdrawal_id UUID, p_amount DECIMAL(12,2), p_payment_reference TEXT ) RETURNS VOID AS $$ DECLARE v_new_balance DECIMAL(12,2); BEGIN -- Lock wallet row LOCK TABLE collaborator_wallets IN EXCLUSIVE MODE; -- Update wallet (deduct from pending, add to withdrawn) UPDATE collaborator_wallets SET pending_balance = pending_balance - p_amount, total_withdrawn = total_withdrawn + p_amount, updated_at = NOW() WHERE user_id = p_user_id RETURNING current_balance INTO v_new_balance; -- Update transaction to completed UPDATE wallet_transactions SET status = 'completed', description = 'Withdrawal completed - Ref: ' || p_payment_reference, updated_at = NOW(), metadata = jsonb_set( metadata, '{completed_at}', to_jsonb(NOW()) ) WHERE withdrawal_id = p_withdrawal_id AND transaction_type = 'withdrawal' AND status = 'pending'; END; $$ LANGUAGE plpgsql SECURITY DEFINER; COMMENT ON FUNCTION complete_withdrawal IS 'Complete withdrawal: move amount from pending to withdrawn'; -- Function to reject withdrawal (return funds) CREATE OR REPLACE FUNCTION reject_withdrawal( p_user_id UUID, p_withdrawal_id UUID, p_amount DECIMAL(12,2), p_reason TEXT ) RETURNS VOID AS $$ BEGIN -- Lock wallet row LOCK TABLE collaborator_wallets IN EXCLUSIVE MODE; -- Return funds from pending to current UPDATE collaborator_wallets SET current_balance = current_balance + p_amount, pending_balance = pending_balance - p_amount, updated_at = NOW() WHERE user_id = p_user_id; -- Update transaction to reversed UPDATE wallet_transactions SET status = 'reversed', description = 'Withdrawal rejected: ' || p_reason, updated_at = NOW(), metadata = jsonb_set( metadata, '{rejected_at}', to_jsonb(NOW()) ) WHERE withdrawal_id = p_withdrawal_id AND transaction_type = 'withdrawal' AND status = 'pending'; END; $$ LANGUAGE plpgsql SECURITY DEFINER; COMMENT ON FUNCTION reject_withdrawal IS 'Reject withdrawal: return funds from pending to available balance'; ``` **Execute:** Copy-paste into Supabase SQL Editor → Run --- ## Migration 7: Add Profit Fields to Order Items **Why seventh:** References `wallet_transactions(id)` which now exists (created in Migration 5) ```sql -- Add profit split fields to order_items table (not orders) ALTER TABLE order_items ADD COLUMN IF NOT EXISTS host_share DECIMAL(12,2) DEFAULT 0, ADD COLUMN IF NOT EXISTS collaborator_share DECIMAL(12,2) DEFAULT 0, ADD COLUMN IF NOT EXISTS wallet_transaction_id UUID REFERENCES wallet_transactions(id); -- Add index for wallet transaction lookups CREATE INDEX IF NOT EXISTS idx_order_items_wallet ON order_items(wallet_transaction_id) WHERE wallet_transaction_id IS NOT NULL; COMMENT ON COLUMN order_items.host_share IS 'Host profit amount from this order item'; COMMENT ON COLUMN order_items.collaborator_share IS 'Collaborator profit amount from this order item'; COMMENT ON COLUMN order_items.wallet_transaction_id IS 'Reference to wallet transaction that credited this profit'; ``` **Execute:** Copy-paste into Supabase SQL Editor → Run --- ## Migration 8: Create Withdrawals Table **Why eighth:** References `wallet_transactions(id)` and then adds back FK from `wallet_transactions.withdrawal_id` after `withdrawals` exists ```sql -- Create withdrawals table CREATE TABLE IF NOT EXISTS withdrawals ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, amount DECIMAL(12,2) NOT NULL CHECK (amount > 0), status VARCHAR(20) NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'processing', 'completed', 'rejected', 'failed')), requested_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), processed_at TIMESTAMPTZ, payment_method VARCHAR(100) DEFAULT 'bank_transfer', payment_reference TEXT, notes TEXT, admin_notes TEXT, wallet_transaction_id UUID REFERENCES wallet_transactions(id), created_by UUID REFERENCES auth.users(id), updated_at TIMESTAMPTZ DEFAULT NOW(), updated_by UUID REFERENCES auth.users(id) ); -- Add FK from wallet_transactions -> withdrawals (safe if rerun) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM pg_constraint WHERE conname = 'wallet_transactions_withdrawal_id_fkey' ) THEN ALTER TABLE wallet_transactions ADD CONSTRAINT wallet_transactions_withdrawal_id_fkey FOREIGN KEY (withdrawal_id) REFERENCES withdrawals(id) ON DELETE SET NULL; END IF; END $$; -- Create indexes CREATE INDEX IF NOT EXISTS idx_withdrawals_user_status ON withdrawals(user_id, status); CREATE INDEX IF NOT EXISTS idx_withdrawals_status_created ON withdrawals(status, requested_at DESC); CREATE INDEX IF NOT EXISTS idx_withdrawals_wallet ON withdrawals(wallet_transaction_id) WHERE wallet_transaction_id IS NOT NULL; -- Enable RLS ALTER TABLE withdrawals ENABLE ROW LEVEL SECURITY; -- Drop existing policies if any DROP POLICY IF EXISTS "Collaborators can view own withdrawals" ON withdrawals; DROP POLICY IF EXISTS "Admins can view all withdrawals" ON withdrawals; DROP POLICY IF EXISTS "Collaborators can create own withdrawals" ON withdrawals; DROP POLICY IF EXISTS "Admins can update all withdrawals" ON withdrawals; -- Create RLS policies CREATE POLICY "Collaborators can view own withdrawals" ON withdrawals FOR SELECT USING (auth.uid() = user_id); CREATE POLICY "Admins can view all withdrawals" ON withdrawals FOR SELECT USING ( EXISTS ( SELECT 1 FROM user_roles WHERE user_id = auth.uid() AND role = 'admin' ) ); CREATE POLICY "Collaborators can create own withdrawals" ON withdrawals FOR INSERT WITH CHECK (auth.uid() = user_id); CREATE POLICY "Admins can update all withdrawals" ON withdrawals FOR ALL USING ( EXISTS ( SELECT 1 FROM user_roles WHERE user_id = auth.uid() AND role = 'admin' ) ); COMMENT ON TABLE withdrawals IS 'Collaborator withdrawal requests'; COMMENT ON COLUMN withdrawals.wallet_transaction_id IS 'Reference to wallet transaction that debited this amount'; ``` **Execute:** Copy-paste into Supabase SQL Editor → Run --- ## Migration 9: Create Collaborator Profits View **Why ninth:** References `wallet_transactions` which now exists (created in Migration 5) ```sql -- Create or replace view for collaborator profits (privacy-protected) CREATE OR REPLACE VIEW collaborator_profits AS SELECT oi.id as order_item_id, o.id as order_id, o.created_at, p.id as product_id, p.title as product_title, p.collaborator_user_id, p.profit_share_percentage, oi.collaborator_share as profit_amount, wt.transaction_type as profit_status, wt.id as wallet_transaction_id FROM order_items oi INNER JOIN orders o ON oi.order_id = o.id INNER JOIN products p ON oi.product_id = p.id LEFT JOIN wallet_transactions wt ON oi.wallet_transaction_id = wt.id WHERE p.collaborator_user_id IS NOT NULL AND o.payment_status = 'paid' AND oi.collaborator_share > 0; -- Set security barrier for additional privacy ALTER VIEW collaborator_profits SET (security_barrier = true); COMMENT ON VIEW collaborator_profits IS 'Collaborator profit view - excludes buyer info for privacy'; ``` **Execute:** Copy-paste into Supabase SQL Editor → Run --- ## Migration 10: Create Triggers for Auto Wallet Creation **Why tenth:** Needs `products` table (Migration 4) and `wallet` tables (Migration 5) ```sql -- Auto-create wallet when collaborator is added to product CREATE OR REPLACE FUNCTION ensure_collaborator_wallet() RETURNS TRIGGER AS $$ BEGIN -- When a product is updated/inserted with collaborator IF NEW.collaborator_user_id IS NOT NULL THEN INSERT INTO collaborator_wallets (user_id, current_balance, total_earned) VALUES (NEW.collaborator_user_id, 0, 0) ON CONFLICT (user_id) DO NOTHING; END IF; RETURN NEW; END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- Create trigger DROP TRIGGER IF EXISTS trigger_ensure_collaborator_wallet ON products; CREATE TRIGGER trigger_ensure_collaborator_wallet AFTER INSERT OR UPDATE OF collaborator_user_id ON products FOR EACH ROW EXECUTE FUNCTION ensure_collaborator_wallet(); COMMENT ON FUNCTION ensure_collaborator_wallet IS 'Auto-create wallet when user becomes collaborator'; ``` **Execute:** Copy-paste into Supabase SQL Editor → Run --- # Phase 2: Edge Functions ## Edge Function 1: Get Owner Identity **Folder:** `supabase/functions/get-owner-identity` **Command:** ```bash mkdir -p supabase/functions/get-owner-identity ``` **File:** `supabase/functions/get-owner-identity/index.ts` ```typescript import { serve } from 'https://deno.land/std@0.168.0/http/server.ts'; import { createClient } from 'https://esm.sh/@supabase/supabase-js@2'; serve(async (req) => { try { const supabase = createClient( Deno.env.get('SUPABASE_URL')!, Deno.env.get('SUPABASE_SERVICE_ROLE_KEY')! ); // Get owner identity from platform_settings const { data: platformSettings } = await supabase .from('platform_settings') .select('owner_name, owner_avatar_url') .limit(1) .maybeSingle(); return new Response(JSON.stringify({ owner_name: platformSettings?.owner_name || 'Dwindi', owner_avatar_url: platformSettings?.owner_avatar_url || '' }), { status: 200, headers: { 'Content-Type': 'application/json' } }); } catch (error) { return new Response(JSON.stringify({ error: error.message }), { status: 500, headers: { 'Content-Type': 'application/json' } }); } }); ``` **Deploy:** ```bash supabase functions deploy get-owner-identity ``` --- ## Edge Function 2: Send Collaboration Notification **Folder:** `supabase/functions/send-collaboration-notification` **Command:** ```bash mkdir -p supabase/functions/send-collaboration-notification ``` **File:** `supabase/functions/send-collaboration-notification/index.ts` ```typescript import { serve } from 'https://deno.land/std@0.168.0/http/server.ts'; import { createClient } from 'https://esm.sh/@supabase/supabase-js@2'; serve(async (req) => { try { const supabase = createClient( Deno.env.get('SUPABASE_URL')!, Deno.env.get('SUPABASE_SERVICE_ROLE_KEY')! ); const { type, ...data } = await req.json(); let recipientEmail = ''; let subject = ''; let htmlContent = ''; switch (type) { case 'new_sale': const { data: collaborator } = await supabase .from('profiles') .select('email, name, full_name') .eq('id', data.collaboratorUserId) .single(); recipientEmail = collaborator?.email || ''; subject = `🎉 You earned Rp ${data.profitAmount.toLocaleString()} from ${data.productTitle}!`; htmlContent = `

Great news, ${collaborator?.full_name || collaborator?.name || 'Partner'}!

Your collaborative webinar ${data.productTitle} just made a sale.

Sale Details:

Your wallet has been credited. Log in to your dashboard to view your earnings.

Keep up the great work!

Best regards,
WithDwindi Team

`; break; case 'withdrawal_requested': const { data: adminRole } = await supabase .from('user_roles') .select('user_id') .eq('role', 'admin') .limit(1) .maybeSingle(); const { data: admin } = await supabase .from('profiles') .select('email') .eq('id', adminRole?.user_id || '') .maybeSingle(); recipientEmail = admin?.email || ''; subject = `💸 New Withdrawal Request`; htmlContent = `

New Withdrawal Request

A collaborator has requested a withdrawal:

Please review and process in admin dashboard.

`; break; case 'withdrawal_completed': const { data: user } = await supabase .from('profiles') .select('email, name, full_name') .eq('id', data.userId) .single(); recipientEmail = user?.email || ''; subject = `✅ Withdrawal Completed: Rp ${data.amount.toLocaleString()}`; htmlContent = `

Withdrawal Completed, ${user?.full_name || user?.name || 'Partner'}!

Your withdrawal request has been processed.

The funds have been transferred to your bank account.

Thank you for your collaboration!

`; break; case 'withdrawal_rejected': const { data: rejectedUser } = await supabase .from('profiles') .select('email, name, full_name') .eq('id', data.userId) .single(); recipientEmail = rejectedUser?.email || ''; subject = `❌ Withdrawal Request Returned`; htmlContent = `

Withdrawal Request Returned

Hi ${rejectedUser?.full_name || rejectedUser?.name || 'Partner'},

Your withdrawal request of Rp ${data.amount.toLocaleString()} has been returned to your wallet.

Reason: ${data.reason || 'Contact admin for details'}

You can request a new withdrawal anytime.

`; break; default: return new Response(JSON.stringify({ error: 'Unknown notification type' }), { status: 400, headers: { 'Content-Type': 'application/json' } }); } if (!recipientEmail) { return new Response(JSON.stringify({ error: 'Recipient email not found' }), { status: 400, headers: { 'Content-Type': 'application/json' } }); } // Send email using existing direct email function await supabase.functions.invoke('send-email-v2', { body: { recipient: recipientEmail, subject, content: htmlContent } }); return new Response(JSON.stringify({ success: true }), { status: 200, headers: { 'Content-Type': 'application/json' } }); } catch (error) { console.error('Notification error:', error); return new Response(JSON.stringify({ error: error.message }), { status: 500, headers: { 'Content-Type': 'application/json' } }); } }); ``` **Deploy:** ```bash supabase functions deploy send-collaboration-notification ``` --- ## Edge Function 3: Create Withdrawal Request **Folder:** `supabase/functions/create-withdrawal` **Command:** ```bash mkdir -p supabase/functions/create-withdrawal ``` **File:** `supabase/functions/create-withdrawal/index.ts` ```typescript import { serve } from 'https://deno.land/std@0.168.0/http/server.ts'; import { createClient } from 'https://esm.sh/@supabase/supabase-js@2'; serve(async (req) => { try { const supabase = createClient( Deno.env.get('SUPABASE_URL')!, Deno.env.get('SUPABASE_SERVICE_ROLE_KEY')! ); const { amount, notes } = await req.json(); const authHeader = req.headers.get('Authorization'); if (!authHeader) { return new Response(JSON.stringify({ error: 'Unauthorized' }), { status: 401, headers: { 'Content-Type': 'application/json' } }); } const { data: { user } } = await supabase.auth.getUser(authHeader.replace('Bearer ', '')); if (!user) { return new Response(JSON.stringify({ error: 'Unauthorized' }), { status: 401, headers: { 'Content-Type': 'application/json' } }); } // Get wallet balance const { data: wallet } = await supabase .rpc('get_collaborator_wallet', { p_user_id: user.id }); const currentBalance = wallet[0]?.current_balance || 0; const pendingBalance = wallet[0]?.pending_balance || 0; // Get collaboration settings const { data: settings } = await supabase .rpc('get_collaboration_settings'); const minWithdrawal = settings[0]?.min_withdrawal_amount || 100000; const maxPendingWithdrawals = settings[0]?.max_pending_withdrawals || 1; // Validations if (currentBalance < minWithdrawal) { return new Response( JSON.stringify({ error: `Minimum withdrawal is Rp ${minWithdrawal.toLocaleString()}` }), { status: 400, headers: { 'Content-Type': 'application/json' } } ); } if (amount > currentBalance) { return new Response( JSON.stringify({ error: 'Insufficient available balance', available: currentBalance }), { status: 400, headers: { 'Content-Type': 'application/json' } } ); } // Check for existing pending withdrawals const { data: existingWithdrawals } = await supabase .from('withdrawals') .select('id') .eq('user_id', user.id) .eq('status', 'pending'); if (existingWithdrawals && existingWithdrawals.length >= maxPendingWithdrawals) { return new Response( JSON.stringify({ error: `Maximum ${maxPendingWithdrawals} pending withdrawal(s) allowed` }), { status: 400, headers: { 'Content-Type': 'application/json' } } ); } // Get collaborator bank info const { data: profile } = await supabase .from('profiles') .select('bank_account_name, bank_account_number, bank_name') .eq('id', user.id) .single(); if (!profile?.bank_account_number || !profile?.bank_account_name || !profile?.bank_name) { return new Response( JSON.stringify({ error: 'Please complete your bank account information in profile settings' }), { status: 400, headers: { 'Content-Type': 'application/json' } } ); } // Create withdrawal record first const { data: withdrawal, error: withdrawalError } = await supabase .from('withdrawals') .insert({ user_id: user.id, amount, status: 'pending', payment_method: 'bank_transfer', payment_reference: `${profile.bank_name} - ${profile.bank_account_number} (${profile.bank_account_name})`, notes, created_by: user.id }) .select() .single(); if (withdrawalError) throw withdrawalError; // Hold amount in wallet const { data: holdResult, error: holdError } = await supabase .rpc('hold_withdrawal_amount', { p_user_id: user.id, p_withdrawal_id: withdrawal.id, p_amount: amount }); if (holdError) { // Rollback withdrawal creation await supabase.from('withdrawals').delete().eq('id', withdrawal.id); throw holdError; } // Update withdrawal with wallet transaction reference await supabase .from('withdrawals') .update({ wallet_transaction_id: holdResult }) .eq('id', withdrawal.id); // Send notifications await supabase.functions.invoke('send-collaboration-notification', { body: { type: 'withdrawal_requested', withdrawalId: withdrawal.id, userId: user.id, amount, bankInfo: { bankName: profile.bank_name, accountNumber: profile.bank_account_number, accountName: profile.bank_account_name } } }); return new Response(JSON.stringify({ success: true, withdrawal: { ...withdrawal, wallet_transaction_id: holdResult } }), { status: 201, headers: { 'Content-Type': 'application/json' } }); } catch (error) { return new Response(JSON.stringify({ error: error.message }), { status: 500, headers: { 'Content-Type': 'application/json' } }); } }); ``` **Deploy:** ```bash supabase functions deploy create-withdrawal ``` --- ## Edge Function 4: Process Withdrawal **Folder:** `supabase/functions/process-withdrawal` **Command:** ```bash mkdir -p supabase/functions/process-withdrawal ``` **File:** `supabase/functions/process-withdrawal/index.ts` ```typescript import { serve } from 'https://deno.land/std@0.168.0/http/server.ts'; import { createClient } from 'https://esm.sh/@supabase/supabase-js@2'; serve(async (req) => { try { const supabase = createClient( Deno.env.get('SUPABASE_URL')!, Deno.env.get('SUPABASE_SERVICE_ROLE_KEY')! ); const { withdrawalId, status, payment_reference, admin_notes, reason } = await req.json(); const authHeader = req.headers.get('Authorization'); if (!authHeader) { return new Response(JSON.stringify({ error: 'Unauthorized' }), { status: 401, headers: { 'Content-Type': 'application/json' } }); } const { data: { user } } = await supabase.auth.getUser(authHeader.replace('Bearer ', '')); if (!user) { return new Response(JSON.stringify({ error: 'Unauthorized' }), { status: 401, headers: { 'Content-Type': 'application/json' } }); } // Verify admin role const { data: isAdmin } = await supabase .from('user_roles') .select('role') .eq('user_id', user.id) .eq('role', 'admin') .single(); if (!isAdmin) { return new Response(JSON.stringify({ error: 'Forbidden - Admin only' }), { status: 403, headers: { 'Content-Type': 'application/json' } }); } // Get withdrawal details const { data: withdrawal } = await supabase .from('withdrawals') .select('*, user:profiles(full_name, email)') .eq('id', withdrawalId) .single(); if (!withdrawal) { return new Response(JSON.stringify({ error: 'Withdrawal not found' }), { status: 404, headers: { 'Content-Type': 'application/json' } }); } if (withdrawal.status !== 'pending') { return new Response(JSON.stringify({ error: 'Withdrawal already processed' }), { status: 400, headers: { 'Content-Type': 'application/json' } }); } if (!['completed', 'rejected'].includes(status)) { return new Response(JSON.stringify({ error: 'Invalid status. Use completed or rejected.' }), { status: 400, headers: { 'Content-Type': 'application/json' } }); } if (status === 'completed') { // Complete withdrawal await supabase.rpc('complete_withdrawal', { p_user_id: withdrawal.user_id, p_withdrawal_id: withdrawalId, p_amount: withdrawal.amount, p_payment_reference: payment_reference }); // Update withdrawal record await supabase .from('withdrawals') .update({ status: 'completed', processed_at: new Date().toISOString(), payment_reference, admin_notes, updated_by: user.id, updated_at: new Date().toISOString() }) .eq('id', withdrawalId); // Send completion notification await supabase.functions.invoke('send-collaboration-notification', { body: { type: 'withdrawal_completed', userId: withdrawal.user_id, amount: withdrawal.amount, paymentReference: payment_reference } }); } else if (status === 'rejected') { // Reject withdrawal - return funds await supabase.rpc('reject_withdrawal', { p_user_id: withdrawal.user_id, p_withdrawal_id: withdrawalId, p_amount: withdrawal.amount, p_reason: reason || 'Withdrawal rejected by admin' }); // Update withdrawal record await supabase .from('withdrawals') .update({ status: 'rejected', processed_at: new Date().toISOString(), admin_notes, updated_by: user.id, updated_at: new Date().toISOString() }) .eq('id', withdrawalId); // Send rejection notification await supabase.functions.invoke('send-collaboration-notification', { body: { type: 'withdrawal_rejected', userId: withdrawal.user_id, amount: withdrawal.amount, reason: admin_notes || reason || 'Withdrawal rejected' } }); } return new Response(JSON.stringify({ success: true }), { status: 200, headers: { 'Content-Type': 'application/json' } }); } catch (error) { return new Response(JSON.stringify({ error: error.message }), { status: 500, headers: { 'Content-Type': 'application/json' } }); } }); ``` **Deploy:** ```bash supabase functions deploy process-withdrawal ``` --- ## Edge Function 5: Modify Handle Order Paid **Folder:** `supabase/functions/handle-order-paid` (EXISTS) **Add this after access granting section:** > Make sure `order_items` selected in `handle-order-paid` includes at least: `id`, `product_id`, `unit_price`. ```typescript // ============================================ // COLLABORATION: Credit collaborator wallets // ============================================ // Check if any order items have collaborator products for (const item of orderItems) { // Fetch product with collaboration details const { data: product } = await supabase .from('products') .select('collaborator_user_id, profit_share_percentage, auto_grant_access, title') .eq('id', item.product_id) .single(); if (!product?.collaborator_user_id) continue; // Calculate profit splits const itemPrice = item.unit_price || 0; const hostShare = itemPrice * ((100 - product.profit_share_percentage) / 100); const collaboratorShare = itemPrice * (product.profit_share_percentage / 100); // Update order_item with calculated shares await supabase .from('order_items') .update({ host_share: hostShare, collaborator_share: collaboratorShare }) .eq('id', item.id); // Credit collaborator wallet const { data: transactionId } = await supabase .rpc('credit_collaborator_wallet', { p_user_id: product.collaborator_user_id, p_order_item_id: item.id, p_amount: collaboratorShare, p_description: `Profit from sale: ${product.title}` }); console.log(`Credited wallet: ${product.collaborator_user_id} + Rp ${collaboratorShare}, Transaction: ${transactionId}`); // Grant access to collaborator if auto_grant_access is true if (product.auto_grant_access) { await supabase .from('user_access') .upsert({ user_id: product.collaborator_user_id, product_id: item.product_id, access_type: 'collaborator', granted_by: order.user_id }, { onConflict: 'user_id,product_id' }); } // Send notification to collaborator await supabase.functions.invoke('send-collaboration-notification', { body: { type: 'new_sale', collaboratorUserId: product.collaborator_user_id, productTitle: product.title, profitAmount: collaboratorShare, profitSharePercentage: product.profit_share_percentage, saleDate: order.created_at } }); } ``` **Deploy:** ```bash supabase functions deploy handle-order-paid ``` --- # Phase 3: Verification Tests ## Test 1: Verify Wallet Tables ```sql -- Check if tables exist SELECT table_name FROM information_schema.tables WHERE table_schema = 'public' AND table_name IN ('collaborator_wallets', 'wallet_transactions') ORDER BY table_name; -- Should return both tables ``` ## Test 2: Verify Wallet Functions ```sql -- Test collaboration settings retrieval (reads from platform_settings) SELECT * FROM get_collaboration_settings(); -- Should return all 5 collaboration settings with correct types ``` ## Test 3: Test Wallet Creation Trigger ```sql -- This should auto-create a wallet for the collaborator INSERT INTO products (title, slug, type, description, price, collaborator_user_id, profit_share_percentage) VALUES ('Test Collab', 'test-collab', 'webinar', 'Test', 100000, 'YOUR_USER_ID', 50); -- Check if wallet was created SELECT * FROM collaborator_wallets WHERE user_id = 'YOUR_USER_ID'; -- Should return: user_id with 0 balances ``` ## Test 4: Test Credit Function ```sql -- You'll need a real order_item_id for this SELECT credit_collaborator_wallet( 'YOUR_USER_ID', -- p_user_id 'YOUR_ORDER_ITEM_ID', -- p_order_item_id 50000, -- p_amount 'Test profit credit' -- p_description ); -- Check wallet balance SELECT * FROM get_collaborator_wallet('YOUR_USER_ID'); -- Check transaction history SELECT * FROM wallet_transactions WHERE user_id = 'YOUR_USER_ID' ORDER BY created_at DESC; ``` ## Test 5: Test Owner Identity Function ```bash # Via curl curl https://YOUR_PROJECT_REF.supabase.co/functions/v1/get-owner-identity # Should return: # {"owner_name":"Dwindi","owner_avatar_url":""} ``` --- # Quick Deploy Commands ```bash # Create all folders mkdir -p supabase/functions/get-owner-identity mkdir -p supabase/functions/send-collaboration-notification mkdir -p supabase/functions/create-withdrawal mkdir -p supabase/functions/process-withdrawal # Deploy all functions supabase functions deploy get-owner-identity supabase functions deploy send-collaboration-notification supabase functions deploy create-withdrawal supabase functions deploy process-withdrawal supabase functions deploy handle-order-paid ``` --- # Completion Checklist **Database Migrations (IN ORDER!):** - [x] Migration 1: Platform settings extension (owner + collaboration) - [x] Migration 2: Profile bank fields - [x] Migration 3: User access enhancement - [x] Migration 4: Products collaboration fields - [x] Migration 5: **Wallet tables** (DO THIS FIRST!) - [ ] Migration 6: Wallet functions - [ ] Migration 7: Order items profit fields - [ ] Migration 8: Withdrawals table - [ ] Migration 9: Collaborator profits view - [ ] Migration 10: Auto wallet triggers **Edge Functions:** - [ ] Get Owner Identity - [ ] Send Collaboration Notification - [ ] Create Withdrawal - [ ] Process Withdrawal - [ ] Modify Handle Order Paid **Verification:** - [ ] Test wallet tables exist - [ ] Test wallet functions - [ ] Test wallet creation trigger - [ ] Test credit function - [ ] Test collaboration settings retrieval - [ ] Test owner identity endpoint - [ ] Test profits view --- ## Dependency Flow ``` Migration 5: Wallet Tables (creates collaborator_wallets, wallet_transactions) ↓ Migration 6: Wallet Functions (uses wallet tables) ↓ Migration 7: Order Items (references wallet_transactions) ↓ Migration 8: Withdrawals (references wallet_transactions) ↓ Migration 9: Profits View (references wallet_transactions) ↓ Migration 10: Triggers (uses products + wallet tables) ``` --- **Next:** Once all migrations and edge functions are complete, we'll implement the frontend components! 🚀