You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 
 
 

177 lines
7.1 KiB

-- Custom Roles and Invite System
-- Permission types (similar to Google Drive)
-- viewer: Can view content
-- commenter: Can view and comment
-- editor: Can view, comment, and edit content
-- admin: Can manage members and settings
-- owner: Full control
-- Custom roles table (allows vanity roles with custom permissions)
CREATE TABLE IF NOT EXISTS org_roles (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
org_id UUID REFERENCES organizations(id) ON DELETE CASCADE,
name TEXT NOT NULL,
color TEXT DEFAULT '#6366f1', -- For vanity display
permissions JSONB NOT NULL DEFAULT '[]'::jsonb,
is_default BOOLEAN DEFAULT false, -- If this is a default role for new members
is_system BOOLEAN DEFAULT false, -- System roles can't be deleted
position INTEGER DEFAULT 0, -- For ordering
created_at TIMESTAMPTZ DEFAULT now(),
updated_at TIMESTAMPTZ DEFAULT now(),
UNIQUE(org_id, name)
);
-- Available permissions
COMMENT ON COLUMN org_roles.permissions IS 'Array of permission strings:
documents.view, documents.create, documents.edit, documents.delete,
kanban.view, kanban.create, kanban.edit, kanban.delete,
calendar.view, calendar.create, calendar.edit, calendar.delete,
members.view, members.invite, members.manage, members.remove,
roles.view, roles.create, roles.edit, roles.delete,
settings.view, settings.edit,
org.delete';
-- Update org_members to reference custom roles
ALTER TABLE org_members ADD COLUMN IF NOT EXISTS role_id UUID REFERENCES org_roles(id);
-- Organization invites
CREATE TABLE IF NOT EXISTS org_invites (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
org_id UUID REFERENCES organizations(id) ON DELETE CASCADE,
email TEXT NOT NULL,
role_id UUID REFERENCES org_roles(id),
role TEXT DEFAULT 'viewer', -- Fallback if no custom role
invited_by UUID REFERENCES auth.users(id),
token TEXT UNIQUE NOT NULL DEFAULT encode(gen_random_bytes(32), 'hex'),
expires_at TIMESTAMPTZ DEFAULT (now() + interval '7 days'),
accepted_at TIMESTAMPTZ,
created_at TIMESTAMPTZ DEFAULT now(),
UNIQUE(org_id, email)
);
-- Indexes
CREATE INDEX IF NOT EXISTS idx_org_roles_org ON org_roles(org_id);
CREATE INDEX IF NOT EXISTS idx_org_invites_org ON org_invites(org_id);
CREATE INDEX IF NOT EXISTS idx_org_invites_token ON org_invites(token);
CREATE INDEX IF NOT EXISTS idx_org_invites_email ON org_invites(email);
-- RLS for org_roles
ALTER TABLE org_roles ENABLE ROW LEVEL SECURITY;
CREATE POLICY "Org members can view roles" ON org_roles FOR SELECT
USING (EXISTS (
SELECT 1 FROM org_members om
WHERE om.org_id = org_roles.org_id AND om.user_id = auth.uid()
));
CREATE POLICY "Admins can manage roles" ON org_roles FOR ALL
USING (EXISTS (
SELECT 1 FROM org_members om
WHERE om.org_id = org_roles.org_id
AND om.user_id = auth.uid()
AND om.role IN ('owner', 'admin')
));
-- RLS for org_invites
ALTER TABLE org_invites ENABLE ROW LEVEL SECURITY;
CREATE POLICY "Org members can view invites" ON org_invites FOR SELECT
USING (EXISTS (
SELECT 1 FROM org_members om
WHERE om.org_id = org_invites.org_id AND om.user_id = auth.uid()
));
CREATE POLICY "Admins can manage invites" ON org_invites FOR ALL
USING (EXISTS (
SELECT 1 FROM org_members om
WHERE om.org_id = org_invites.org_id
AND om.user_id = auth.uid()
AND om.role IN ('owner', 'admin')
));
-- Anyone can view invite by token (for accepting)
CREATE POLICY "Anyone can view invite by token" ON org_invites FOR SELECT
USING (true);
-- Function to create default roles for new org
CREATE OR REPLACE FUNCTION create_default_org_roles()
RETURNS TRIGGER AS $$
BEGIN
-- Owner role (full permissions)
INSERT INTO org_roles (org_id, name, color, permissions, is_system, position) VALUES
(NEW.id, 'Owner', '#ef4444', '["*"]'::jsonb, true, 0);
-- Admin role
INSERT INTO org_roles (org_id, name, color, permissions, is_system, position) VALUES
(NEW.id, 'Admin', '#f59e0b', '[
"documents.view", "documents.create", "documents.edit", "documents.delete",
"kanban.view", "kanban.create", "kanban.edit", "kanban.delete",
"calendar.view", "calendar.create", "calendar.edit", "calendar.delete",
"members.view", "members.invite", "members.manage",
"roles.view", "settings.view", "settings.edit"
]'::jsonb, true, 1);
-- Editor role
INSERT INTO org_roles (org_id, name, color, permissions, is_system, is_default, position) VALUES
(NEW.id, 'Editor', '#10b981', '[
"documents.view", "documents.create", "documents.edit",
"kanban.view", "kanban.create", "kanban.edit",
"calendar.view", "calendar.create", "calendar.edit",
"members.view"
]'::jsonb, true, true, 2);
-- Commenter role
INSERT INTO org_roles (org_id, name, color, permissions, is_system, position) VALUES
(NEW.id, 'Commenter', '#6366f1', '[
"documents.view",
"kanban.view",
"calendar.view",
"members.view"
]'::jsonb, true, 3);
-- Viewer role
INSERT INTO org_roles (org_id, name, color, permissions, is_system, position) VALUES
(NEW.id, 'Viewer', '#8b5cf6', '[
"documents.view",
"kanban.view",
"calendar.view",
"members.view"
]'::jsonb, true, 4);
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Trigger to create default roles
DROP TRIGGER IF EXISTS on_org_created_create_roles ON organizations;
CREATE TRIGGER on_org_created_create_roles
AFTER INSERT ON organizations
FOR EACH ROW EXECUTE FUNCTION create_default_org_roles();
-- Insert default roles for existing organizations
DO $$
DECLARE
org RECORD;
BEGIN
FOR org IN SELECT id FROM organizations LOOP
-- Only insert if no roles exist
IF NOT EXISTS (SELECT 1 FROM org_roles WHERE org_id = org.id) THEN
-- Owner role
INSERT INTO org_roles (org_id, name, color, permissions, is_system, position) VALUES
(org.id, 'Owner', '#ef4444', '["*"]'::jsonb, true, 0);
-- Admin role
INSERT INTO org_roles (org_id, name, color, permissions, is_system, position) VALUES
(org.id, 'Admin', '#f59e0b', '["documents.view", "documents.create", "documents.edit", "documents.delete", "kanban.view", "kanban.create", "kanban.edit", "kanban.delete", "calendar.view", "calendar.create", "calendar.edit", "calendar.delete", "members.view", "members.invite", "members.manage", "roles.view", "settings.view", "settings.edit"]'::jsonb, true, 1);
-- Editor role
INSERT INTO org_roles (org_id, name, color, permissions, is_system, is_default, position) VALUES
(org.id, 'Editor', '#10b981', '["documents.view", "documents.create", "documents.edit", "kanban.view", "kanban.create", "kanban.edit", "calendar.view", "calendar.create", "calendar.edit", "members.view"]'::jsonb, true, true, 2);
-- Commenter role
INSERT INTO org_roles (org_id, name, color, permissions, is_system, position) VALUES
(org.id, 'Commenter', '#6366f1', '["documents.view", "kanban.view", "calendar.view", "members.view"]'::jsonb, true, 3);
-- Viewer role
INSERT INTO org_roles (org_id, name, color, permissions, is_system, position) VALUES
(org.id, 'Viewer', '#8b5cf6', '["documents.view", "kanban.view", "calendar.view", "members.view"]'::jsonb, true, 4);
END IF;
END LOOP;
END $$;