Skip to content

Commit

Permalink
Fixed insert trigger
Browse files Browse the repository at this point in the history
  • Loading branch information
GuilhermeF03 committed Jun 27, 2024
1 parent 4286c25 commit 646f7ae
Show file tree
Hide file tree
Showing 6 changed files with 133 additions and 129 deletions.
179 changes: 133 additions & 46 deletions code/server/sql/create_tables.sql
Original file line number Diff line number Diff line change
@@ -1,46 +1,133 @@
begin;

create extension if not exists "pgcrypto";

create type resource_type as enum ('D', 'F');

create table if not exists workspace (
id char(16) primary key default encode(gen_random_bytes(8), 'hex'),
name text not null,
"isPrivate" boolean not null default false,
"createdAt" timestamp not null default now(),
members text[] not null default '{}'::text[] -- references "user"(email)
);

create table if not exists resource(
id char(16) primary key default encode(gen_random_bytes(8), 'hex'),
workspace char(16) not null references workspace(id) on delete cascade,
name text not null,
type resource_type not null,
"createdAt" timestamp not null default now(),
"updatedAt" timestamp not null default now(),
parent char(16) default null references resource(id) on delete cascade,
children char(16)[] not null default '{}'::char(16)[] -- references resource(id)
);

create table if not exists "user" (
id char(28) primary key,
name text not null,
email text not null unique,
"createdAt" timestamp not null default now()
);

-- Triggers
create or replace trigger on_workspace_insert_trigger
after insert on workspace
for each row execute function add_root_resource();

create or replace trigger on_resource_delete_trigger
after delete on resource
for each row execute function on_child_removed();

create or replace trigger on_resource_update_trigger
after update on resource
for each row execute function on_child_updated();

commit;
BEGIN;

-- Create extension if it doesn't exist
CREATE EXTENSION IF NOT EXISTS "pgcrypto";

-- Create enum type
CREATE TYPE resource_type AS ENUM ('D', 'F');

-- Create workspace table
CREATE TABLE IF NOT EXISTS workspace (
id CHAR(16) PRIMARY KEY DEFAULT encode(gen_random_bytes(8), 'hex'),
name TEXT NOT NULL,
"isPrivate" BOOLEAN NOT NULL DEFAULT false,
"createdAt" TIMESTAMP NOT NULL DEFAULT now(),
members TEXT[] NOT NULL DEFAULT '{}'::TEXT[] -- references "user"(email)
);

-- Create resource table
CREATE TABLE IF NOT EXISTS resource (
id CHAR(16) PRIMARY KEY DEFAULT encode(gen_random_bytes(8), 'hex'),
workspace CHAR(16) NOT NULL REFERENCES workspace(id) ON DELETE CASCADE,
name TEXT NOT NULL,
type resource_type NOT NULL,
"createdAt" TIMESTAMP NOT NULL DEFAULT now(),
"updatedAt" TIMESTAMP NOT NULL DEFAULT now(),
parent CHAR(16) DEFAULT NULL REFERENCES resource(id) ON DELETE CASCADE,
children CHAR(16)[] NOT NULL DEFAULT '{}'::CHAR(16)[] -- references resource(id)
);

-- Create user table
CREATE TABLE IF NOT EXISTS "user" (
id CHAR(28) PRIMARY KEY,
name TEXT NOT NULL,
email TEXT NOT NULL UNIQUE,
"createdAt" TIMESTAMP NOT NULL DEFAULT now()
);

-- Trigger functions

-- Resource is deleted -> Remove self from parent's children array
create or replace function on_child_removed() returns trigger as $$
begin
--- Check if parent resource exists
if old.parent is not null then
---- Remove self from parent's children array
update resource
set children = array_remove(children, old.id)
where id = old.parent;
end if;
return old;
end;
$$ language plpgsql;

-- Resource is updated -> Update new and old parent's children array
create or replace function on_child_updated() returns trigger as $$
begin
if new.parent = old.parent then
return new;
end if;
--- Append self to children array of new parent
if new.parent is not null then
update resource
set children = array_append(children, new.id)
where id = new.parent;
end if;
--- Remove self from children array of old parent
if old.parent is not null then
update resource
set children = array_remove(children, old.id)
where id = old.parent;
end if;
return new;
end;
$$ language plpgsql;

-- NEW RESOURCE IS CREATED -> UPDATE SELF'S PARENT ID AND APPEND SELF TO PARENT'S CHILDREN ARRAY
create or replace function on_new_resource_created() returns trigger as $$
begin
--- parent_id is null
if new.parent is null then
if new.id != new.workspace then ---- Workspace resource with root as parent
update resource
set parent = new.workspace
where id = new.id;
---- Append self to root resource's children array
update resource
set children = array_append(children, new.id)
where id = new.workspace;
return new;
else return new; ---- Root resource - do nothing
end if;
--- parent_id is not null
else
---- check if parent resource exists
if not exists (select 1 from resource where id = new.parent) then
raise exception 'Parent resource does not exist';
end if;
--- Append self to children array of parent resource
update resource
set children = array_append(children, new.id)
where id = new.parent;
return new;
end if;
end;
$$ language plpgsql;

-- Add root resource to resource table when a workspace is created
create or replace function add_root_resource() returns trigger as $$
begin
insert into resource (id, workspace, name, type)
values (new.id, new.id, 'root', 'F');
return new;
end;
$$ language plpgsql;

-- Create triggers
CREATE OR REPLACE TRIGGER on_workspace_insert_trigger
AFTER INSERT ON workspace
FOR EACH ROW EXECUTE FUNCTION add_root_resource();

CREATE OR REPLACE TRIGGER on_resource_delete_trigger
AFTER DELETE ON resource
FOR EACH ROW EXECUTE FUNCTION on_child_removed();

CREATE OR REPLACE TRIGGER on_resource_update_trigger
AFTER UPDATE ON resource
FOR EACH ROW EXECUTE FUNCTION on_child_updated();

CREATE OR REPLACE TRIGGER on_resource_insert_trigger
AFTER INSERT ON resource
FOR EACH ROW EXECUTE FUNCTION on_new_resource_created();

COMMIT;
1 change: 0 additions & 1 deletion code/server/sql/drop_tables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,5 +3,4 @@ begin ;
drop table if exists resource cascade;
drop table if exists workspace cascade;
drop type if exists resource_type cascade;

commit ;
15 changes: 0 additions & 15 deletions code/server/sql/triggers/resource_delete.sql

This file was deleted.

33 changes: 0 additions & 33 deletions code/server/sql/triggers/resource_insert.sql

This file was deleted.

23 changes: 0 additions & 23 deletions code/server/sql/triggers/resource_update.sql

This file was deleted.

11 changes: 0 additions & 11 deletions code/server/sql/triggers/workspace_insert.sql

This file was deleted.

0 comments on commit 646f7ae

Please sign in to comment.