AW: theCure
This commit is contained in:
163
db/migrations/0001_core_schema.sql
Normal file
163
db/migrations/0001_core_schema.sql
Normal file
@@ -0,0 +1,163 @@
|
||||
-- 0001_core_schema.sql
|
||||
-- Portable Postgres core schema (no Supabase-specific RLS).
|
||||
|
||||
create extension if not exists pgcrypto; -- for gen_random_uuid()
|
||||
|
||||
-- =======================================
|
||||
-- APPLICATIONS
|
||||
-- =======================================
|
||||
create table if not exists public.applications (
|
||||
id uuid primary key default gen_random_uuid(),
|
||||
name text not null unique,
|
||||
description text,
|
||||
owner_user_id uuid,
|
||||
created_at timestamptz default now(),
|
||||
updated_at timestamptz default now()
|
||||
);
|
||||
|
||||
-- =======================================
|
||||
-- ENTITIES
|
||||
-- =======================================
|
||||
create table if not exists public.entities (
|
||||
id uuid primary key default gen_random_uuid(),
|
||||
application_id uuid not null references public.applications(id) on delete cascade,
|
||||
name text not null,
|
||||
label text,
|
||||
description text,
|
||||
created_at timestamptz default now(),
|
||||
updated_at timestamptz default now(),
|
||||
unique (application_id, name)
|
||||
);
|
||||
|
||||
-- =======================================
|
||||
-- FIELDS
|
||||
-- =======================================
|
||||
create table if not exists public.fields (
|
||||
id uuid primary key default gen_random_uuid(),
|
||||
entity_id uuid not null references public.entities(id) on delete cascade,
|
||||
name text not null,
|
||||
label text,
|
||||
field_type text not null, -- string, number, boolean, date, relation, etc.
|
||||
required boolean default false,
|
||||
default_value text,
|
||||
relation_entity uuid references public.entities(id),
|
||||
created_at timestamptz default now(),
|
||||
updated_at timestamptz default now(),
|
||||
unique (entity_id, name)
|
||||
);
|
||||
|
||||
-- =======================================
|
||||
-- FORMS
|
||||
-- =======================================
|
||||
create table if not exists public.forms (
|
||||
id uuid primary key default gen_random_uuid(),
|
||||
application_id uuid not null references public.applications(id) on delete cascade,
|
||||
entity_id uuid not null references public.entities(id) on delete cascade,
|
||||
name text not null,
|
||||
label text,
|
||||
form_type text not null, -- create, edit, view, list
|
||||
layout_json jsonb not null, -- UI layout structure
|
||||
created_at timestamptz default now(),
|
||||
updated_at timestamptz default now(),
|
||||
unique (entity_id, name)
|
||||
);
|
||||
|
||||
-- =======================================
|
||||
-- WORKFLOWS
|
||||
-- =======================================
|
||||
create table if not exists public.workflows (
|
||||
id uuid primary key default gen_random_uuid(),
|
||||
application_id uuid not null references public.applications(id) on delete cascade,
|
||||
entity_id uuid not null references public.entities(id) on delete cascade,
|
||||
name text not null,
|
||||
description text,
|
||||
trigger_event text not null, -- on_create, on_update, on_delete
|
||||
condition_json jsonb,
|
||||
action_json jsonb,
|
||||
created_at timestamptz default now(),
|
||||
updated_at timestamptz default now(),
|
||||
unique (entity_id, name)
|
||||
);
|
||||
|
||||
-- =======================================
|
||||
-- SECURITY: ROLES / USERS / PERMISSIONS
|
||||
-- =======================================
|
||||
create table if not exists public.roles (
|
||||
id uuid primary key default gen_random_uuid(),
|
||||
name text not null unique,
|
||||
description text,
|
||||
parent_role_id uuid references public.roles(id) on delete set null,
|
||||
created_at timestamptz default now(),
|
||||
updated_at timestamptz default now()
|
||||
);
|
||||
|
||||
create table if not exists public.users (
|
||||
id uuid primary key default gen_random_uuid(),
|
||||
email text unique,
|
||||
display_name text,
|
||||
created_at timestamptz default now(),
|
||||
updated_at timestamptz default now()
|
||||
);
|
||||
|
||||
create table if not exists public.user_roles (
|
||||
id uuid primary key default gen_random_uuid(),
|
||||
user_id uuid not null references public.users(id) on delete cascade,
|
||||
role_id uuid not null references public.roles(id) on delete cascade,
|
||||
created_at timestamptz default now(),
|
||||
unique (user_id, role_id)
|
||||
);
|
||||
|
||||
create table if not exists public.entity_permissions (
|
||||
id uuid primary key default gen_random_uuid(),
|
||||
role_id uuid not null references public.roles(id) on delete cascade,
|
||||
entity_id uuid not null references public.entities(id) on delete cascade,
|
||||
can_create boolean default false,
|
||||
can_read boolean default false,
|
||||
can_update boolean default false,
|
||||
can_delete boolean default false,
|
||||
row_filter_json jsonb, -- e.g. {"field":"owner_id","op":"=","value":"auth.uid()"}
|
||||
created_at timestamptz default now(),
|
||||
updated_at timestamptz default now(),
|
||||
unique (role_id, entity_id)
|
||||
);
|
||||
|
||||
create table if not exists public.field_permissions (
|
||||
id uuid primary key default gen_random_uuid(),
|
||||
role_id uuid not null references public.roles(id) on delete cascade,
|
||||
field_id uuid not null references public.fields(id) on delete cascade,
|
||||
can_read boolean default false,
|
||||
can_update boolean default false,
|
||||
created_at timestamptz default now(),
|
||||
updated_at timestamptz default now(),
|
||||
unique (role_id, field_id)
|
||||
);
|
||||
|
||||
-- =======================================
|
||||
-- TIMESTAMP TRIGGER
|
||||
-- =======================================
|
||||
create or replace function public.set_updated_at()
|
||||
returns trigger as $$
|
||||
begin
|
||||
new.updated_at = now();
|
||||
return new;
|
||||
end;
|
||||
$$ language plpgsql;
|
||||
|
||||
create trigger trg_updated_at_applications before update on public.applications
|
||||
for each row execute procedure public.set_updated_at();
|
||||
create trigger trg_updated_at_entities before update on public.entities
|
||||
for each row execute procedure public.set_updated_at();
|
||||
create trigger trg_updated_at_fields before update on public.fields
|
||||
for each row execute procedure public.set_updated_at();
|
||||
create trigger trg_updated_at_forms before update on public.forms
|
||||
for each row execute procedure public.set_updated_at();
|
||||
create trigger trg_updated_at_workflows before update on public.workflows
|
||||
for each row execute procedure public.set_updated_at();
|
||||
create trigger trg_updated_at_roles before update on public.roles
|
||||
for each row execute procedure public.set_updated_at();
|
||||
create trigger trg_updated_at_users before update on public.users
|
||||
for each row execute procedure public.set_updated_at();
|
||||
create trigger trg_updated_at_entity_permissions before update on public.entity_permissions
|
||||
for each row execute procedure public.set_updated_at();
|
||||
create trigger trg_updated_at_field_permissions before update on public.field_permissions
|
||||
for each row execute procedure public.set_updated_at();
|
||||
103
db/migrations/0002_supabase_objects.sql
Normal file
103
db/migrations/0002_supabase_objects.sql
Normal file
@@ -0,0 +1,103 @@
|
||||
-- 0002_supabase_objects.sql
|
||||
-- Supabase wiring: auth sync, RLS-enabled permission views and stubs.
|
||||
|
||||
create extension if not exists pgcrypto;
|
||||
|
||||
-- Link auth.users to public.users
|
||||
alter table public.users
|
||||
add column if not exists supabase_uid uuid unique;
|
||||
|
||||
create or replace function public.handle_new_supabase_user()
|
||||
returns trigger as $$
|
||||
begin
|
||||
insert into public.users (id, supabase_uid, email, display_name)
|
||||
values (gen_random_uuid(), new.id, new.email, coalesce(new.raw_user_meta_data->>'full_name', new.email))
|
||||
on conflict (supabase_uid) do nothing;
|
||||
return new;
|
||||
end;
|
||||
$$ language plpgsql security definer;
|
||||
|
||||
drop trigger if exists on_auth_user_created on auth.users;
|
||||
create trigger on_auth_user_created
|
||||
after insert on auth.users
|
||||
for each row execute function public.handle_new_supabase_user();
|
||||
|
||||
-- Expanded roles for CURRENT user (via auth.uid())
|
||||
create or replace view public.current_user_roles as
|
||||
with recursive role_hierarchy as (
|
||||
select ur.user_id, r.id as role_id, r.parent_role_id
|
||||
from public.user_roles ur
|
||||
join public.users u on ur.user_id = u.id
|
||||
join public.roles r on ur.role_id = r.id
|
||||
where u.supabase_uid = auth.uid()
|
||||
union
|
||||
select rh.user_id, pr.id as role_id, pr.parent_role_id
|
||||
from role_hierarchy rh
|
||||
join public.roles pr on rh.parent_role_id = pr.id
|
||||
)
|
||||
select distinct user_id, role_id from role_hierarchy;
|
||||
|
||||
-- Effective entity permissions for CURRENT user
|
||||
create or replace view public.current_user_entity_permissions as
|
||||
select
|
||||
ure.user_id,
|
||||
e.id as entity_id,
|
||||
e.name as entity_name,
|
||||
bool_or(ep.can_create) as can_create,
|
||||
bool_or(ep.can_read) as can_read,
|
||||
bool_or(ep.can_update) as can_update,
|
||||
bool_or(ep.can_delete) as can_delete,
|
||||
array_remove(array_agg(ep.row_filter_json), null)::jsonb[] as row_filters
|
||||
from public.current_user_roles ure
|
||||
join public.entity_permissions ep on ure.role_id = ep.role_id
|
||||
join public.entities e on ep.entity_id = e.id
|
||||
group by ure.user_id, e.id, e.name;
|
||||
|
||||
-- Effective field permissions for CURRENT user
|
||||
create or replace view public.current_user_field_permissions as
|
||||
select
|
||||
ure.user_id,
|
||||
f.id as field_id,
|
||||
f.name as field_name,
|
||||
e.id as entity_id,
|
||||
e.name as entity_name,
|
||||
bool_or(fp.can_read) as can_read,
|
||||
bool_or(fp.can_update) as can_update
|
||||
from public.current_user_roles ure
|
||||
join public.field_permissions fp on ure.role_id = fp.role_id
|
||||
join public.fields f on fp.field_id = f.id
|
||||
join public.entities e on f.entity_id = e.id
|
||||
group by ure.user_id, f.id, f.name, e.id, e.name;
|
||||
|
||||
-- Enable RLS on core security tables
|
||||
alter table public.roles enable row level security;
|
||||
alter table public.user_roles enable row level security;
|
||||
alter table public.entity_permissions enable row level security;
|
||||
alter table public.field_permissions enable row level security;
|
||||
|
||||
-- Basic policies
|
||||
drop policy if exists "users see their user_roles" on public.user_roles;
|
||||
create policy "users see their user_roles"
|
||||
on public.user_roles
|
||||
for select
|
||||
using (
|
||||
exists (
|
||||
select 1 from public.users u
|
||||
where u.id = public.user_roles.user_id
|
||||
and u.supabase_uid = auth.uid()
|
||||
)
|
||||
);
|
||||
|
||||
-- Example admin policy (adjust as needed)
|
||||
drop policy if exists "admins manage roles" on public.roles;
|
||||
create policy "admins manage roles"
|
||||
on public.roles
|
||||
for all
|
||||
using (
|
||||
exists (
|
||||
select 1
|
||||
from public.current_user_roles cur
|
||||
join public.roles r on cur.role_id = r.id
|
||||
where r.name = 'Admin'
|
||||
)
|
||||
);
|
||||
133
db/migrations/0003_row_filters.sql
Normal file
133
db/migrations/0003_row_filters.sql
Normal file
@@ -0,0 +1,133 @@
|
||||
-- 0003_row_filters.sql
|
||||
-- Row filter evaluator + demo policies.
|
||||
|
||||
-- Evaluate array of JSONB filter objects against a row (as jsonb).
|
||||
-- Supported:
|
||||
-- ops: =, !=, in, not_in, >, <, between
|
||||
-- logic: and/or with structure: {"and":[...]} or {"or":[...]}
|
||||
|
||||
create or replace function public.check_row_filter(row_data jsonb, filters jsonb[])
|
||||
returns boolean as $$
|
||||
declare
|
||||
f jsonb;
|
||||
ok boolean := true;
|
||||
val text;
|
||||
lhs text;
|
||||
op text;
|
||||
begin
|
||||
if filters is null then
|
||||
return true;
|
||||
end if;
|
||||
|
||||
foreach f in array filters loop
|
||||
-- Composite logic
|
||||
if f ? 'and' then
|
||||
if not public.check_row_filter(row_data, array(select jsonb_array_elements(f->'and'))) then
|
||||
return false;
|
||||
end if;
|
||||
continue;
|
||||
elsif f ? 'or' then
|
||||
-- at least one must pass
|
||||
ok := false;
|
||||
for f in select jsonb_array_elements(f->'or') loop
|
||||
if public.check_row_filter(row_data, array[f]) then
|
||||
ok := true; exit;
|
||||
end if;
|
||||
end loop;
|
||||
if not ok then return false; end if;
|
||||
continue;
|
||||
end if;
|
||||
|
||||
lhs := row_data->>(f->>'field');
|
||||
op := f->>'op';
|
||||
|
||||
if f->>'value' = 'auth.uid()' then
|
||||
val := auth.uid()::text;
|
||||
else
|
||||
val := f->>'value';
|
||||
end if;
|
||||
|
||||
if op = '=' then
|
||||
if lhs is null or lhs <> val then return false; end if;
|
||||
elsif op = '!=' then
|
||||
if lhs = val then return false; end if;
|
||||
elsif op = 'in' then
|
||||
if not (lhs = any (select jsonb_array_elements_text(f->'values'))) then return false; end if;
|
||||
elsif op = 'not_in' then
|
||||
if (lhs = any (select jsonb_array_elements_text(f->'values'))) then return false; end if;
|
||||
elsif op = '>' then
|
||||
if lhs is null or lhs <= val then return false; end if;
|
||||
elsif op = '<' then
|
||||
if lhs is null or lhs >= val then return false; end if;
|
||||
elsif op = 'between' then
|
||||
if lhs is null or not (lhs >= (f->>'min') and lhs <= (f->>'max')) then return false; end if;
|
||||
else
|
||||
-- unknown op -> deny
|
||||
return false;
|
||||
end if;
|
||||
end loop;
|
||||
|
||||
return true;
|
||||
end;
|
||||
$$ language plpgsql stable;
|
||||
|
||||
-- Demo runtime table: tickets
|
||||
create table if not exists public.tickets (
|
||||
id uuid primary key default gen_random_uuid(),
|
||||
title text not null,
|
||||
description text,
|
||||
status text default 'open',
|
||||
created_by uuid not null, -- should match users.supabase_uid for auth.uid() checks
|
||||
created_at timestamptz default now()
|
||||
);
|
||||
|
||||
alter table public.tickets enable row level security;
|
||||
|
||||
-- Example policies using current_user_entity_permissions + check_row_filter
|
||||
-- For demo we key by entity_name = 'tickets' (in your production, key by entity_id).
|
||||
drop policy if exists "tickets_select_policy" on public.tickets;
|
||||
create policy "tickets_select_policy" on public.tickets
|
||||
for select using (
|
||||
exists (
|
||||
select 1
|
||||
from public.current_user_entity_permissions cuep
|
||||
where cuep.entity_name = 'tickets'
|
||||
and cuep.can_read = true
|
||||
and public.check_row_filter(to_jsonb(public.tickets), cuep.row_filters)
|
||||
)
|
||||
);
|
||||
|
||||
drop policy if exists "tickets_insert_policy" on public.tickets;
|
||||
create policy "tickets_insert_policy" on public.tickets
|
||||
for insert with check (
|
||||
exists (
|
||||
select 1
|
||||
from public.current_user_entity_permissions cuep
|
||||
where cuep.entity_name = 'tickets'
|
||||
and cuep.can_create = true
|
||||
)
|
||||
);
|
||||
|
||||
drop policy if exists "tickets_update_policy" on public.tickets;
|
||||
create policy "tickets_update_policy" on public.tickets
|
||||
for update using (
|
||||
exists (
|
||||
select 1
|
||||
from public.current_user_entity_permissions cuep
|
||||
where cuep.entity_name = 'tickets'
|
||||
and cuep.can_update = true
|
||||
and public.check_row_filter(to_jsonb(public.tickets), cuep.row_filters)
|
||||
)
|
||||
);
|
||||
|
||||
drop policy if exists "tickets_delete_policy" on public.tickets;
|
||||
create policy "tickets_delete_policy" on public.tickets
|
||||
for delete using (
|
||||
exists (
|
||||
select 1
|
||||
from public.current_user_entity_permissions cuep
|
||||
where cuep.entity_name = 'tickets'
|
||||
and cuep.can_delete = true
|
||||
and public.check_row_filter(to_jsonb(public.tickets), cuep.row_filters)
|
||||
)
|
||||
);
|
||||
82
db/migrations/0004_seed_demo.sql
Normal file
82
db/migrations/0004_seed_demo.sql
Normal file
@@ -0,0 +1,82 @@
|
||||
-- 0004_seed_demo.sql
|
||||
-- Seed demo roles, user, entity, fields, form, workflow.
|
||||
|
||||
-- Roles
|
||||
insert into public.roles (id, name, description)
|
||||
values (gen_random_uuid(), 'Admin', 'Full access admin role')
|
||||
on conflict do nothing;
|
||||
|
||||
insert into public.roles (id, name, description)
|
||||
values (gen_random_uuid(), 'Manager', 'Manager role')
|
||||
on conflict do nothing;
|
||||
|
||||
insert into public.roles (id, name, description)
|
||||
values (gen_random_uuid(), 'Agent', 'Agent role')
|
||||
on conflict do nothing;
|
||||
|
||||
-- Demo user (dummy UUID, replace with actual Supabase user id later if desired)
|
||||
insert into public.users (id, email, display_name)
|
||||
values (gen_random_uuid(), 'demo@example.com', 'Demo User')
|
||||
on conflict do nothing;
|
||||
|
||||
-- Link demo user to Agent role
|
||||
insert into public.user_roles (user_id, role_id)
|
||||
select u.id, r.id from public.users u, public.roles r
|
||||
where u.email = 'demo@example.com' and r.name = 'Agent'
|
||||
on conflict do nothing;
|
||||
|
||||
-- Demo application
|
||||
insert into public.applications (id, name, description)
|
||||
values (gen_random_uuid(), 'Helpdesk', 'Demo helpdesk app with tickets')
|
||||
on conflict do nothing;
|
||||
|
||||
-- Demo entity: tickets
|
||||
insert into public.entities (id, application_id, name, label, description)
|
||||
select gen_random_uuid(), a.id, 'tickets', 'Tickets', 'Support tickets'
|
||||
from public.applications a
|
||||
where a.name = 'Helpdesk'
|
||||
on conflict do nothing;
|
||||
|
||||
-- Demo fields for tickets
|
||||
insert into public.fields (id, entity_id, name, label, field_type, required)
|
||||
select gen_random_uuid(), e.id, 'title', 'Title', 'string', true
|
||||
from public.entities e where e.name = 'tickets'
|
||||
on conflict do nothing;
|
||||
|
||||
insert into public.fields (id, entity_id, name, label, field_type)
|
||||
select gen_random_uuid(), e.id, 'description', 'Description', 'textarea'
|
||||
from public.entities e where e.name = 'tickets'
|
||||
on conflict do nothing;
|
||||
|
||||
insert into public.fields (id, entity_id, name, label, field_type)
|
||||
select gen_random_uuid(), e.id, 'status', 'Status', 'string'
|
||||
from public.entities e where e.name = 'tickets'
|
||||
on conflict do nothing;
|
||||
|
||||
insert into public.fields (id, entity_id, name, label, field_type)
|
||||
select gen_random_uuid(), e.id, 'created_by', 'Created By', 'uuid'
|
||||
from public.entities e where e.name = 'tickets'
|
||||
on conflict do nothing;
|
||||
|
||||
-- Demo form layout
|
||||
insert into public.forms (id, application_id, entity_id, name, label, form_type, layout_json)
|
||||
select gen_random_uuid(), a.id, e.id, 'ticket_form', 'Ticket Form', 'create',
|
||||
'{
|
||||
"sections":[
|
||||
{"title":"Ticket Info","fields":["title","description","status"]}
|
||||
]
|
||||
}'::jsonb
|
||||
from public.applications a
|
||||
join public.entities e on e.application_id = a.id
|
||||
where a.name = 'Helpdesk' and e.name = 'tickets'
|
||||
on conflict do nothing;
|
||||
|
||||
-- Demo workflow (on_create -> set status open)
|
||||
insert into public.workflows (id, application_id, entity_id, name, description, trigger_event, condition_json, action_json)
|
||||
select gen_random_uuid(), a.id, e.id, 'ticket_on_create', 'Set ticket status to open on create', 'on_create',
|
||||
null,
|
||||
'[{"action":"set_field","field":"status","value":"open"}]'::jsonb
|
||||
from public.applications a
|
||||
join public.entities e on e.application_id = a.id
|
||||
where a.name = 'Helpdesk' and e.name = 'tickets'
|
||||
on conflict do nothing;
|
||||
Reference in New Issue
Block a user