Skip to content

Commit 646f7ae

Browse files
committed
Fixed insert trigger
1 parent 4286c25 commit 646f7ae

File tree

6 files changed

+133
-129
lines changed

6 files changed

+133
-129
lines changed

code/server/sql/create_tables.sql

Lines changed: 133 additions & 46 deletions
Original file line numberDiff line numberDiff line change
@@ -1,46 +1,133 @@
1-
begin;
2-
3-
create extension if not exists "pgcrypto";
4-
5-
create type resource_type as enum ('D', 'F');
6-
7-
create table if not exists workspace (
8-
id char(16) primary key default encode(gen_random_bytes(8), 'hex'),
9-
name text not null,
10-
"isPrivate" boolean not null default false,
11-
"createdAt" timestamp not null default now(),
12-
members text[] not null default '{}'::text[] -- references "user"(email)
13-
);
14-
15-
create table if not exists resource(
16-
id char(16) primary key default encode(gen_random_bytes(8), 'hex'),
17-
workspace char(16) not null references workspace(id) on delete cascade,
18-
name text not null,
19-
type resource_type not null,
20-
"createdAt" timestamp not null default now(),
21-
"updatedAt" timestamp not null default now(),
22-
parent char(16) default null references resource(id) on delete cascade,
23-
children char(16)[] not null default '{}'::char(16)[] -- references resource(id)
24-
);
25-
26-
create table if not exists "user" (
27-
id char(28) primary key,
28-
name text not null,
29-
email text not null unique,
30-
"createdAt" timestamp not null default now()
31-
);
32-
33-
-- Triggers
34-
create or replace trigger on_workspace_insert_trigger
35-
after insert on workspace
36-
for each row execute function add_root_resource();
37-
38-
create or replace trigger on_resource_delete_trigger
39-
after delete on resource
40-
for each row execute function on_child_removed();
41-
42-
create or replace trigger on_resource_update_trigger
43-
after update on resource
44-
for each row execute function on_child_updated();
45-
46-
commit;
1+
BEGIN;
2+
3+
-- Create extension if it doesn't exist
4+
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
5+
6+
-- Create enum type
7+
CREATE TYPE resource_type AS ENUM ('D', 'F');
8+
9+
-- Create workspace table
10+
CREATE TABLE IF NOT EXISTS workspace (
11+
id CHAR(16) PRIMARY KEY DEFAULT encode(gen_random_bytes(8), 'hex'),
12+
name TEXT NOT NULL,
13+
"isPrivate" BOOLEAN NOT NULL DEFAULT false,
14+
"createdAt" TIMESTAMP NOT NULL DEFAULT now(),
15+
members TEXT[] NOT NULL DEFAULT '{}'::TEXT[] -- references "user"(email)
16+
);
17+
18+
-- Create resource table
19+
CREATE TABLE IF NOT EXISTS resource (
20+
id CHAR(16) PRIMARY KEY DEFAULT encode(gen_random_bytes(8), 'hex'),
21+
workspace CHAR(16) NOT NULL REFERENCES workspace(id) ON DELETE CASCADE,
22+
name TEXT NOT NULL,
23+
type resource_type NOT NULL,
24+
"createdAt" TIMESTAMP NOT NULL DEFAULT now(),
25+
"updatedAt" TIMESTAMP NOT NULL DEFAULT now(),
26+
parent CHAR(16) DEFAULT NULL REFERENCES resource(id) ON DELETE CASCADE,
27+
children CHAR(16)[] NOT NULL DEFAULT '{}'::CHAR(16)[] -- references resource(id)
28+
);
29+
30+
-- Create user table
31+
CREATE TABLE IF NOT EXISTS "user" (
32+
id CHAR(28) PRIMARY KEY,
33+
name TEXT NOT NULL,
34+
email TEXT NOT NULL UNIQUE,
35+
"createdAt" TIMESTAMP NOT NULL DEFAULT now()
36+
);
37+
38+
-- Trigger functions
39+
40+
-- Resource is deleted -> Remove self from parent's children array
41+
create or replace function on_child_removed() returns trigger as $$
42+
begin
43+
--- Check if parent resource exists
44+
if old.parent is not null then
45+
---- Remove self from parent's children array
46+
update resource
47+
set children = array_remove(children, old.id)
48+
where id = old.parent;
49+
end if;
50+
return old;
51+
end;
52+
$$ language plpgsql;
53+
54+
-- Resource is updated -> Update new and old parent's children array
55+
create or replace function on_child_updated() returns trigger as $$
56+
begin
57+
if new.parent = old.parent then
58+
return new;
59+
end if;
60+
--- Append self to children array of new parent
61+
if new.parent is not null then
62+
update resource
63+
set children = array_append(children, new.id)
64+
where id = new.parent;
65+
end if;
66+
--- Remove self from children array of old parent
67+
if old.parent is not null then
68+
update resource
69+
set children = array_remove(children, old.id)
70+
where id = old.parent;
71+
end if;
72+
return new;
73+
end;
74+
$$ language plpgsql;
75+
76+
-- NEW RESOURCE IS CREATED -> UPDATE SELF'S PARENT ID AND APPEND SELF TO PARENT'S CHILDREN ARRAY
77+
create or replace function on_new_resource_created() returns trigger as $$
78+
begin
79+
--- parent_id is null
80+
if new.parent is null then
81+
if new.id != new.workspace then ---- Workspace resource with root as parent
82+
update resource
83+
set parent = new.workspace
84+
where id = new.id;
85+
---- Append self to root resource's children array
86+
update resource
87+
set children = array_append(children, new.id)
88+
where id = new.workspace;
89+
return new;
90+
else return new; ---- Root resource - do nothing
91+
end if;
92+
--- parent_id is not null
93+
else
94+
---- check if parent resource exists
95+
if not exists (select 1 from resource where id = new.parent) then
96+
raise exception 'Parent resource does not exist';
97+
end if;
98+
--- Append self to children array of parent resource
99+
update resource
100+
set children = array_append(children, new.id)
101+
where id = new.parent;
102+
return new;
103+
end if;
104+
end;
105+
$$ language plpgsql;
106+
107+
-- Add root resource to resource table when a workspace is created
108+
create or replace function add_root_resource() returns trigger as $$
109+
begin
110+
insert into resource (id, workspace, name, type)
111+
values (new.id, new.id, 'root', 'F');
112+
return new;
113+
end;
114+
$$ language plpgsql;
115+
116+
-- Create triggers
117+
CREATE OR REPLACE TRIGGER on_workspace_insert_trigger
118+
AFTER INSERT ON workspace
119+
FOR EACH ROW EXECUTE FUNCTION add_root_resource();
120+
121+
CREATE OR REPLACE TRIGGER on_resource_delete_trigger
122+
AFTER DELETE ON resource
123+
FOR EACH ROW EXECUTE FUNCTION on_child_removed();
124+
125+
CREATE OR REPLACE TRIGGER on_resource_update_trigger
126+
AFTER UPDATE ON resource
127+
FOR EACH ROW EXECUTE FUNCTION on_child_updated();
128+
129+
CREATE OR REPLACE TRIGGER on_resource_insert_trigger
130+
AFTER INSERT ON resource
131+
FOR EACH ROW EXECUTE FUNCTION on_new_resource_created();
132+
133+
COMMIT;

code/server/sql/drop_tables.sql

Lines changed: 0 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -3,5 +3,4 @@ begin ;
33
drop table if exists resource cascade;
44
drop table if exists workspace cascade;
55
drop type if exists resource_type cascade;
6-
76
commit ;

code/server/sql/triggers/resource_delete.sql

Lines changed: 0 additions & 15 deletions
This file was deleted.

code/server/sql/triggers/resource_insert.sql

Lines changed: 0 additions & 33 deletions
This file was deleted.

code/server/sql/triggers/resource_update.sql

Lines changed: 0 additions & 23 deletions
This file was deleted.

code/server/sql/triggers/workspace_insert.sql

Lines changed: 0 additions & 11 deletions
This file was deleted.

0 commit comments

Comments
 (0)