59 lines
2.0 KiB
PL/PgSQL
59 lines
2.0 KiB
PL/PgSQL
-- Create invite_codes table
|
|
CREATE TABLE invite_codes (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
code VARCHAR(20) NOT NULL UNIQUE,
|
|
created_by UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
used_by UUID REFERENCES users(id) ON DELETE SET NULL,
|
|
is_used BOOLEAN NOT NULL DEFAULT FALSE,
|
|
expires_at TIMESTAMPTZ,
|
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
|
used_at TIMESTAMPTZ
|
|
);
|
|
|
|
-- Create indexes for better performance
|
|
CREATE INDEX idx_invite_codes_code ON invite_codes(code);
|
|
CREATE INDEX idx_invite_codes_created_by ON invite_codes(created_by);
|
|
CREATE INDEX idx_invite_codes_used_by ON invite_codes(used_by);
|
|
CREATE INDEX idx_invite_codes_is_used ON invite_codes(is_used);
|
|
CREATE INDEX idx_invite_codes_expires_at ON invite_codes(expires_at);
|
|
|
|
-- Add invite_code_id column to users table
|
|
ALTER TABLE users ADD COLUMN invite_code_id UUID REFERENCES invite_codes(id) ON DELETE SET NULL;
|
|
|
|
-- Create index on the new column
|
|
CREATE INDEX idx_users_invite_code_id ON users(invite_code_id);
|
|
|
|
-- Create function to generate random invite codes
|
|
CREATE OR REPLACE FUNCTION generate_invite_code()
|
|
RETURNS VARCHAR(20) AS $$
|
|
DECLARE
|
|
chars TEXT := 'ABCDEFGHIJKLMNOPQRSTUVWXYZ0123456789';
|
|
result VARCHAR(20) := '';
|
|
i INTEGER;
|
|
BEGIN
|
|
FOR i IN 1..8 LOOP
|
|
result := result || substr(chars, floor(random() * length(chars))::integer + 1, 1);
|
|
END LOOP;
|
|
RETURN result;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Create function to create a new invite code
|
|
CREATE OR REPLACE FUNCTION create_invite_code(creator_id UUID, expires_in_days INTEGER DEFAULT 30)
|
|
RETURNS VARCHAR(20) AS $$
|
|
DECLARE
|
|
new_code VARCHAR(20);
|
|
code_exists BOOLEAN;
|
|
BEGIN
|
|
LOOP
|
|
new_code := generate_invite_code();
|
|
SELECT EXISTS(SELECT 1 FROM invite_codes WHERE code = new_code) INTO code_exists;
|
|
EXIT WHEN NOT code_exists;
|
|
END LOOP;
|
|
|
|
INSERT INTO invite_codes (code, created_by, expires_at)
|
|
VALUES (new_code, creator_id, NOW() + (expires_in_days || ' days')::INTERVAL);
|
|
|
|
RETURN new_code;
|
|
END;
|
|
$$ LANGUAGE plpgsql; |