Skip to content

Commit

Permalink
Merge pull request #224 from duncanhealy/feature/todo-sql-policy
Browse files Browse the repository at this point in the history
feature/todo sql policy
  • Loading branch information
kiwicopple committed Oct 7, 2020
2 parents 4a53c94 + 3955cf5 commit e3c10ff
Show file tree
Hide file tree
Showing 2 changed files with 126 additions and 13 deletions.
82 changes: 82 additions & 0 deletions examples/todo/db/collab_task_list_schema.sql
@@ -0,0 +1,82 @@
-- users table exists but not able to reference
-- USER PROFILES
CREATE TYPE public.user_status AS ENUM ('ONLINE', 'OFFLINE');
CREATE TABLE public.users (
id uuid NOT NULL PRIMARY KEY,
-- UUID from auth.users (Supabase)
username text,
list_id uuid NULL,
-- can be selected by user - current list and updated
status user_status DEFAULT 'OFFLINE'::public.user_status
);
ALTER TABLE public.users ENABLE ROW LEVEL SECURITY;
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);
-- change to uuid primary key
CREATE TABLE lists (
lists_id uuid PRIMARY KEY,
list_name text NOT NULL,
inserted_at timestamp without time zone DEFAULT timezone('utc'::text, now()) NOT NULL,
updated_at timestamp without time zone DEFAULT timezone('utc'::text, now()) NOT NULL
);
CREATE TABLE userlists (
users_id uuid REFERENCES public.users NOT NULL,
lists_id uuid REFERENCES lists NOT NULL
);
ALTER TABLE userlists ENABLE ROW LEVEL SECURITY;
ALTER TABLE lists ENABLE ROW LEVEL SECURITY;
CREATE TABLE tasks (
task_text text NOT NULL,
complete boolean DEFAULT false,
id bigserial PRIMARY KEY,
user_id uuid REFERENCES public.users NOT NULL,
list_id uuid REFERENCES lists NOT NULL,
inserted_at timestamp without time zone DEFAULT timezone('utc'::text, now()) NOT NULL,
updated_at timestamp without time zone DEFAULT timezone('utc'::text, now()) NOT NULL
);
ALTER TABLE tasks ENABLE ROW LEVEL SECURITY;
CREATE POLICY "Allow individual select access" on userlists FOR
SELECT USING (auth.uid() = users_id);
CREATE POLICY "Allow individual insert access" on userlists FOR
INSERT WITH CHECK (auth.uid() = users_id);
CREATE POLICY "Allow individual update access" on userlists FOR
UPDATE USING (auth.uid() = users_id);
CREATE POLICY "Allow logged-in full access" on lists FOR
SELECT USING (auth.role() = 'authenticated');
CREATE POLICY "Allow individual insert access" on lists FOR
INSERT WITH CHECK (auth.role() = 'authenticated');
CREATE POLICY "Allow individual update access" on lists FOR
UPDATE USING (auth.role() = 'authenticated');
-- user should see other tasks in lists they are a member of
-- todo
-- try using count?
- - CREATE POLICY "Allow logged-in read access to shared list" on tasks FOR
SELECT USING (
select count(user_id)
from (
SELECT user_id
from userlists
where userlists.list_id = list_id
) > 0
);
-- CREATE POLICY "Allow read access to shared lists" on tasks FOR SELECT USING (SELECT user_id from userlists where userlists.lists_id=lists_id );
-- no to RS
-- ALTER TABLE tasks SET ROW SECURITY FOR SELECT TO (SELECT users_id from userslists where userlists.lists_id=list_id);
-- CREATE POLICY "Allow logged in user to see items on their current list" on tasks FOR SELECT USING ( select list_id from public.users where public.users.list_id=list_id AND public.users.user_id=auth.uid() )
CREATE POLICY "Allow logged in user to see items on their current list" on tasks FOR
SELECT USING (
EXISTS(
select 1
from userlists
where userlists.lists_id = tasks.list_id
AND userlists.users_id = auth.uid()
)
) -- user can update their tasks
CREATE POLICY "Allow individual insert access" on tasks FOR
INSERT WITH CHECK (auth.uid() = user_id);
CREATE POLICY "Allow individual update access" on tasks FOR
UPDATE USING (auth.uid() = user_id);
57 changes: 44 additions & 13 deletions examples/todo/db/task_list_schema.sql
@@ -1,14 +1,45 @@
CREATE TABLE lists (
uuid text,
id bigserial PRIMARY KEY,
inserted_at timestamp without time zone DEFAULT timezone('utc' :: text, now()) NOT NULL,
updated_at timestamp without time zone DEFAULT timezone('utc' :: text, now()) NOT NULL
create table lists (
id bigint generated by default as identity primary key,
name text not null,
user_id uuid references auth.users not null,
inserted_at timestamp with time zone default timezone('utc'::text, now()) not null
);
CREATE TABLE tasks (
task_text text NOT NULL,
complete boolean DEFAULT false,
id bigserial PRIMARY KEY,
list_id bigint REFERENCES lists NOT NULL,
inserted_at timestamp without time zone DEFAULT timezone('utc' :: text, now()) NOT NULL,
updated_at timestamp without time zone DEFAULT timezone('utc' :: text, now()) NOT NULL
);
create table tasks (
id bigint generated by default as identity primary key,
task_text text not null,
complete boolean default false,
list_id bigint REFERENCES lists not null,
inserted_at timestamp with time zone default timezone('utc'::text, now()) not null
);
alter table lists enable row level security;
alter table tasks enable row level security;
create policy "Individuals can create lists." on lists for
insert with check (auth.uid() = user_id);
create policy "Individuals can view their own lists. " on lists for
select using (auth.uid() = user_id);
create policy "Individuals can update their own lists." on lists for
update using (auth.uid() = user_id);
create policy "Individuals can create tasks in their own lists." on tasks for
insert with check (
list_id in (
select id
from lists
where user_id = auth.uid()
)
);
create policy "Individuals can view tasks that exist in one of their lists." on tasks for
select using (
list_id in (
select id
from lists
where user_id = auth.uid()
)
);
create policy "Individuals can update their own tasks." on tasks for
update using (
list_id in (
select id
from lists
where user_id = auth.uid()
)
);

1 comment on commit e3c10ff

@vercel
Copy link

@vercel vercel bot commented on e3c10ff Oct 7, 2020

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Please sign in to comment.