sojorn/_legacy/supabase/apply_e2ee_migration.sql
2026-02-15 00:33:24 -06:00

104 lines
4 KiB
PL/PgSQL

-- ============================================================================
-- APPLY E2EE CHAT MIGRATION MANUALLY
-- ============================================================================
-- Run this script in your Supabase SQL Editor to apply the E2EE chat migration
-- ============================================================================
-- ============================================================================
-- 1. Update profiles table to store identity key and registration ID
-- ============================================================================
-- Add Signal Protocol identity key and registration ID to profiles
ALTER TABLE profiles
ADD COLUMN IF NOT EXISTS identity_key TEXT,
ADD COLUMN IF NOT EXISTS registration_id INTEGER;
-- ============================================================================
-- 2. Create separate one_time_prekeys table
-- ============================================================================
-- Separate table for one-time pre-keys (consumed on use)
CREATE TABLE IF NOT EXISTS one_time_prekeys (
id SERIAL PRIMARY KEY,
user_id UUID NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
key_id INTEGER NOT NULL,
public_key TEXT NOT NULL,
created_at TIMESTAMPTZ DEFAULT NOW(),
-- Ensure unique key_id per user
UNIQUE(user_id, key_id)
);
-- Index for efficient key consumption
CREATE INDEX IF NOT EXISTS idx_one_time_prekeys_user_id ON one_time_prekeys(user_id);
-- ============================================================================
-- 3. Update signal_keys table structure
-- ============================================================================
-- Remove one_time_prekeys from signal_keys (now separate table)
ALTER TABLE signal_keys
DROP COLUMN IF EXISTS one_time_prekeys;
-- Add registration_id to signal_keys if not already present
ALTER TABLE signal_keys
ADD COLUMN IF NOT EXISTS registration_id INTEGER;
-- ============================================================================
-- 4. Update consume_one_time_prekey function
-- ============================================================================
-- Drop existing function if it exists (different return type)
DROP FUNCTION IF EXISTS consume_one_time_prekey(UUID);
-- Create the new function to work with the separate table
CREATE FUNCTION consume_one_time_prekey(target_user_id UUID)
RETURNS TABLE(key_id INTEGER, public_key TEXT) AS $$
DECLARE
selected_key_id INTEGER;
selected_public_key TEXT;
BEGIN
-- First, find the oldest key
SELECT otpk.key_id, otpk.public_key
INTO selected_key_id, selected_public_key
FROM one_time_prekeys otpk
WHERE otpk.user_id = target_user_id
ORDER BY otpk.created_at ASC
LIMIT 1;
-- If we found a key, delete it and return it
IF selected_key_id IS NOT NULL THEN
DELETE FROM one_time_prekeys
WHERE user_id = target_user_id AND key_id = selected_key_id;
RETURN QUERY SELECT selected_key_id, selected_public_key;
END IF;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- ============================================================================
-- 5. Update RLS policies for one_time_prekeys
-- ============================================================================
-- Enable RLS
ALTER TABLE one_time_prekeys ENABLE ROW LEVEL SECURITY;
-- Users can read their own pre-keys (for management)
CREATE POLICY one_time_prekeys_select_own ON one_time_prekeys
FOR SELECT USING (auth.uid() = user_id);
-- Users can insert their own pre-keys
CREATE POLICY one_time_prekeys_insert_own ON one_time_prekeys
FOR INSERT WITH CHECK (auth.uid() = user_id);
-- Users can delete their own pre-keys (when consumed)
CREATE POLICY one_time_prekeys_delete_own ON one_time_prekeys
FOR DELETE USING (auth.uid() = user_id);
-- ============================================================================
-- SUCCESS MESSAGE
-- ============================================================================
-- If you see this message, the migration completed successfully!
SELECT 'E2EE Chat Migration Applied Successfully!' as status;