Skip to content

Commit

Permalink
Merge pull request #136 from kinotio/develop
Browse files Browse the repository at this point in the history
feat: create query sql
  • Loading branch information
andostronaut committed Sep 11, 2024
2 parents 1c213c8 + 0cb747f commit 0b3c98f
Showing 1 changed file with 273 additions and 0 deletions.
273 changes: 273 additions & 0 deletions query.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,273 @@
-- Drop tables if exists
drop table if exists public.users cascade;
drop table if exists public.user_roles cascade;

drop table if exists public.reports cascade;

drop table if exists public.ai_configurations cascade;
drop table if exists public.ai_tokens cascade;

drop table if exists public.role_permissions cascade;

drop table if exists public.inboxes cascade;
drop table if exists public.inboxes_preferences cascade;

drop table if exists public.activities cascade;

-- Drop types if already exists
drop type if exists public.app_permission cascade;
drop type if exists public.app_role cascade;
drop type if exists public.user_status cascade;
drop type if exists public.user_inboxes_preferences cascade;
drop type if exists public.app_activities cascade;
drop type if exists public.app_activities_device cascade;

-- Drop functions if already exists
drop function if exists public.handle_new_user() cascade;
drop function if exists public.authorize() cascade;

----------------------------------------------------------------------------------------------
-- TYPES --
----------------------------------------------------------------------------------------------
create type public.app_permission as enum ('reports.delete', 'inboxes.delete');
create type public.app_role as enum ('client');
create type public.user_inboxes_preferences as enum ('everything', 'ignoring');
create type public.app_activities as enum ('unknown', 'login', 'account_created', 'password_change','report_added', 'inboxes_preferences_change', 'profile_information_change', 'logout');
create type public.app_activities_device as enum ('desktop', 'mobile');
----------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------------
-- USERS TABLES --
----------------------------------------------------------------------------------------------
create table public.users (
id uuid not null primary key, -- UUID from auth.users
email text not null unique,
name text not null,
created_at timestamp with time zone default timezone('utc'::text, now()) not null
);

create table public.user_roles (
id bigint generated by default as identity primary key,
user_id uuid references public.users on delete cascade not null,
role app_role not null,
unique (user_id, role)
);
----------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------------
-- ROLE PERMISSIONS --
----------------------------------------------------------------------------------------------
create table public.role_permissions (
id bigint generated by default as identity primary key,
role app_role not null,
permission app_permission not null,
unique (role, permission)
);
----------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------------
-- REPORTS TABLES --
----------------------------------------------------------------------------------------------
create table public.reports (
id bigint generated by default as identity primary key,
name text not null,
metadata jsonb not null,
user_id uuid references public.users not null,
created_at timestamp with time zone default timezone('utc'::text, now()) not null,
);
----------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------------
-- AI CONFIGURATIONS AND TOKENS TABLES --
----------------------------------------------------------------------------------------------
create table public.ai_configurations (
id bigint generated by default as identity primary key,
provider text not null,
model text not null,
ai_token_id text not null,
temperature integer,
max_tokens text,
is_global boolean,
user_id uuid references public.users not null,
created_at timestamp with time zone default timezone('utc'::text, now()) not null,
updated_at timestamp with time zone
);

create table public.ai_tokens (
id bigint generated by default as identity primary key,
hashed_key text not null,
created_at timestamp with time zone default timezone('utc'::text, now()) not null,
updated_at timestamp with time zone
);
----------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------------
-- INBOXES TABLES --
----------------------------------------------------------------------------------------------
create table public.inboxes (
id bigint generated by default as identity primary key,
message text not null unique,
user_id uuid references public.users not null,
created_at timestamp with time zone default timezone('utc'::text, now()) not null
);
----------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------------
-- INBOXES PREFERENCES TABLES --
----------------------------------------------------------------------------------------------
create table public.inboxes_preferences (
id bigint generated by default as identity primary key,
preference user_inboxes_preferences default 'everything'::public.user_inboxes_preferences,
user_id uuid references public.users not null,
created_at timestamp with time zone default timezone('utc'::text, now()) not null
);
----------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------------
-- ACTIVITIES TABLES --
----------------------------------------------------------------------------------------------
create table public.activities (
id bigint generated by default as identity primary key,
type app_activities default 'unknown'::public.app_activities,
description text not null,
user_id uuid references public.users not null,
device app_activities_device not null,
timestamp timestamp with time zone default timezone('utc'::text, now()) not null
);
----------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------------
-- AUTHORIZE WITH RBAC --
----------------------------------------------------------------------------------------------
-- authorize with role-based access control (RBAC)
create function public.authorize(
requested_permission app_permission,
user_id uuid
)
returns boolean as $$
declare
bind_permissions int;
begin
select count(*)
from public.role_permissions
inner join public.user_roles on role_permissions.role = user_roles.role
where role_permissions.permission = authorize.requested_permission
and user_roles.user_id = authorize.user_id
into bind_permissions;

return bind_permissions > 0;
end;
$$ language plpgsql security definer;
----------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------------
-- ENABLE ROW LEVEL SECURITY --
----------------------------------------------------------------------------------------------
alter table public.users enable row level security;
alter table public.user_roles enable row level security;
alter table public.role_permissions enable row level security;
alter table public.reports enable row level security;
alter table public.ai_configurations enable row level security;
alter table public.ai_tokens enable row level security;
alter table public.inboxes enable row level security;
alter table public.inboxes_preferences enable row level security;
alter table public.activities enable row level security;
----------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------------
-- CREATE POLICIES --
----------------------------------------------------------------------------------------------
create policy "Allow logged-in read access" on public.users for select using (auth.role() = 'authenticated');
create policy "Allow individual insert access" on public.users for insert with check (auth.uid() = id);
create policy "Allow individual update access" on public.users for update using (auth.uid() = id);

create policy "Allow individual read access" on public.user_roles for select using (auth.uid() = user_id);

create policy "Allow logged-in read access" on public.reports for select using (auth.role() = 'authenticated');
create policy "Allow individual insert access" on public.reports for insert with check (auth.uid() = user_id);
create policy "Allow individual delete access" on public.reports for delete using (auth.uid() = user_id);

create policy "Allow logged-in read access" on public.ai_configurations for select using (auth.role() = 'authenticated');
create policy "Allow individual insert access" on public.ai_configurations for insert with check (auth.uid() = user_id);
create policy "Allow individual delete access" on public.ai_configurations for delete using (auth.uid() = user_id);

create policy "Allow logged-in read access" on public.ai_tokens for select using (auth.role() = 'authenticated');

create policy "Allow logged-in read access" on public.inboxes for select using (auth.role() = 'authenticated');
create policy "Allow individual insert access" on public.inboxes for insert with check (auth.uid() = user_id);
create policy "Allow individual delete access" on public.inboxes for delete using (auth.uid() = user_id);
create policy "Allow authorized delete access" on public.inboxes for delete using (authorize('inboxes.delete', auth.uid()));

create policy "Allow logged-in read access" on public.inboxes_preferences for select using (auth.role() = 'authenticated');
create policy "Allow individual insert access" on public.inboxes_preferences for insert with check (auth.uid() = user_id);
create policy "Allow individual update access" on public.inboxes_preferences for update using (auth.uid() = user_id);

create policy "Allow logged-in read access" on public.activities for select using (auth.role() = 'authenticated');
create policy "Allow individual insert access" on public.activities for insert with check (auth.uid() = user_id);
create policy "Allow individual update access" on public.activities for update using (auth.uid() = user_id);
----------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------------
-- REPLICA IDENTITY --
----------------------------------------------------------------------------------------------
alter table public.users replica identity full;
alter table public.reports replica identity full;
alter table public.ai_configurations replica identity full;
alter table public.ai_tokens replica identity full;
alter table public.inboxes replica identity full;
alter table public.inboxes_preferences replica identity full;
alter table public.activities replica identity full;
----------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------------
-- HANDLE NEW USER --
----------------------------------------------------------------------------------------------
-- inserts a row into public.users and assigns roles
create function public.handle_new_user()
returns trigger as $$
begin
insert into public.users (id, email, name)
values (new.id, new.email, new.raw_user_meta_data ->> 'name');

insert into public.inboxes_preferences (user_id) values (new.id);
insert into public.user_roles (user_id, role) values (new.id, 'client');

return new;
end;
$$ language plpgsql security definer;
----------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------------
-- TRIGGERS --
----------------------------------------------------------------------------------------------
-- trigger the function every time a user is created
create trigger on_auth_user_created
after insert on auth.users
for each row execute procedure public.handle_new_user();
----------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------------
-- SUPABASE REALTIME --
----------------------------------------------------------------------------------------------
begin;
-- remove the realtime publication
drop publication if exists supabase_realtime;
-- re-create the publication but don't enable it for any tables
create publication supabase_realtime;
commit;


alter publication supabase_realtime add table public.users;
alter publication supabase_realtime add table public.reports;
alter publication supabase_realtime add table public.inboxes;
alter publication supabase_realtime add table public.inboxes_preferences;
alter publication supabase_realtime add table public.activities;
----------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------------
-- SEEDS --
----------------------------------------------------------------------------------------------
insert into public.role_permissions (role, permission)
values
('client', 'reports.delete');
----------------------------------------------------------------------------------------------

0 comments on commit 0b3c98f

Please sign in to comment.