| 1 | --- Trigger before update/insert za check na iminjata topic/discussion -> OK
|
|---|
| 2 | --- Trigger za ko ke adnit dete na topic thread sho e vo proekt, da go dodajt kako belongs_to vo proektot
|
|---|
| 3 | --- Trigger za check dali reply na discussion thread pripagjat na ist topic thread kako na toj so mu pret reply
|
|---|
| 4 | --- IMENUVANJE: triggeri so provervat nesto prefix = check, funkcii za istite prefix = validate
|
|---|
| 5 | --- Nemame contraint sho velit deka sekoj topic thread trebat da e moderiran
|
|---|
| 6 | DROP TABLE IF EXISTS users CASCADE;
|
|---|
| 7 | DROP TABLE IF EXISTS moderator CASCADE;
|
|---|
| 8 | DROP TABLE IF EXISTS developer CASCADE;
|
|---|
| 9 | DROP TABLE IF EXISTS project_manager CASCADE;
|
|---|
| 10 | DROP TABLE IF EXISTS thread CASCADE;
|
|---|
| 11 | DROP TABLE IF EXISTS likes CASCADE;
|
|---|
| 12 | DROP TABLE IF EXISTS topic_threads_moderators CASCADE;
|
|---|
| 13 | DROP TABLE IF EXISTS tag CASCADE;
|
|---|
| 14 | DROP TABLE IF EXISTS tag_threads CASCADE;
|
|---|
| 15 | DROP TABLE IF EXISTS topic_thread CASCADE;
|
|---|
| 16 | DROP TABLE IF EXISTS topic_belongs_to_project CASCADE;
|
|---|
| 17 | DROP TABLE IF EXISTS blacklisted_user CASCADE;
|
|---|
| 18 | DROP TABLE IF EXISTS project_thread CASCADE;
|
|---|
| 19 | DROP TABLE IF EXISTS discussion_thread CASCADE;
|
|---|
| 20 | DROP TABLE IF EXISTS developer_associated_with_project CASCADE;
|
|---|
| 21 | DROP TABLE IF EXISTS permissions CASCADE;
|
|---|
| 22 | DROP TABLE IF EXISTS project_roles CASCADE;
|
|---|
| 23 | DROP TABLE IF EXISTS users_project_roles CASCADE;
|
|---|
| 24 | DROP TABLE IF EXISTS project_roles_permissions CASCADE;
|
|---|
| 25 | DROP TABLE IF EXISTS project_request CASCADE;
|
|---|
| 26 | DROP TABLE IF EXISTS report CASCADE;
|
|---|
| 27 | DROP TABLE IF EXISTS channel CASCADE;
|
|---|
| 28 | DROP TABLE IF EXISTS messages CASCADE;
|
|---|
| 29 | DROP TABLE IF EXISTS threads_moderators CASCADE;
|
|---|
| 30 | DROP TYPE IF EXISTS status;
|
|---|
| 31 | DROP VIEW IF EXISTS v_topic_thread CASCADE;
|
|---|
| 32 | DROP VIEW IF EXISTS v_project_thread CASCADE;
|
|---|
| 33 | DROP VIEW IF EXISTS v_discussion_thread CASCADE;
|
|---|
| 34 | DROP VIEW IF EXISTS v_project_owner CASCADE;
|
|---|
| 35 | DROP VIEW IF EXISTS v_moderator CASCADE;
|
|---|
| 36 | drop function if exists fn_insert_project_manager CASCADE;
|
|---|
| 37 | drop function if exists fn_insert_topics_creator_as_moderator CASCADE;
|
|---|
| 38 | drop function if exists fn_validate_topic_title CASCADE;
|
|---|
| 39 | drop function if exists clean_tables CASCADE;
|
|---|
| 40 | drop function if exists clean_routines CASCADE;
|
|---|
| 41 | DROP TRIGGER IF EXISTS validate_same_parent ON discussion_thread CASCADE;
|
|---|
| 42 | drop table if exists topic_guidelines cascade;
|
|---|
| 43 | drop table if exists submission cascade;
|
|---|
| 44 | drop table if exists feedback;
|
|---|
| 45 | drop table if exists embeddable_thread;
|
|---|
| 46 |
|
|---|
| 47 |
|
|---|
| 48 | ---- DDL
|
|---|
| 49 | CREATE TABLE users
|
|---|
| 50 | (
|
|---|
| 51 | id SERIAL PRIMARY KEY,
|
|---|
| 52 | username VARCHAR(32) UNIQUE NOT NULL,
|
|---|
| 53 | email varchar(60) not null,
|
|---|
| 54 | name varchar(32) not null,
|
|---|
| 55 | is_activate bool DEFAULT true,
|
|---|
| 56 | password VARCHAR(72),
|
|---|
| 57 | description VARCHAR(200),
|
|---|
| 58 | registered_at TIMESTAMP DEFAULT NOW() NOT NULL,
|
|---|
| 59 | sex VARCHAR(1)
|
|---|
| 60 | );
|
|---|
| 61 | CREATE TABLE moderator
|
|---|
| 62 | (
|
|---|
| 63 | id INT PRIMARY KEY REFERENCES users (id) on delete cascade
|
|---|
| 64 | );
|
|---|
| 65 | CREATE TABLE developer
|
|---|
| 66 | (
|
|---|
| 67 | id INT PRIMARY KEY REFERENCES users (id) on delete cascade
|
|---|
| 68 | );
|
|---|
| 69 | CREATE TABLE project_manager
|
|---|
| 70 | (
|
|---|
| 71 | id INT PRIMARY KEY REFERENCES users (id) on delete cascade
|
|---|
| 72 | );
|
|---|
| 73 | CREATE TABLE thread
|
|---|
| 74 | (
|
|---|
| 75 | id SERIAL PRIMARY KEY,
|
|---|
| 76 | content TEXT,
|
|---|
| 77 | created_at timestamp DEFAULT NOW() NOT NULL,
|
|---|
| 78 | user_id INT REFERENCES users (id) NOT NULL --IS_CREATED_BY TOTAL
|
|---|
| 79 | );
|
|---|
| 80 | CREATE TABLE project_thread
|
|---|
| 81 | (
|
|---|
| 82 | title VARCHAR(256) UNIQUE NOT NULL,
|
|---|
| 83 | repo_url TEXT,
|
|---|
| 84 | id INT PRIMARY KEY REFERENCES thread (id) on delete cascade --INHERITANCE
|
|---|
| 85 | );
|
|---|
| 86 | create table embeddable_thread(
|
|---|
| 87 | id int primary key references thread(id) on delete cascade
|
|---|
| 88 | );
|
|---|
| 89 |
|
|---|
| 90 | CREATE TABLE topic_thread
|
|---|
| 91 | (
|
|---|
| 92 | title VARCHAR(256) NOT NULL,
|
|---|
| 93 | id INT PRIMARY KEY REFERENCES embeddable_thread(id) on delete cascade, --INHERITANCE
|
|---|
| 94 | parent_id int REFERENCES project_thread(id) on delete CASCADE --PARENT
|
|---|
| 95 | );
|
|---|
| 96 | create table topic_guidelines
|
|---|
| 97 | (
|
|---|
| 98 | id serial,
|
|---|
| 99 | topic_id int references topic_thread(id) on delete cascade,
|
|---|
| 100 | description text,
|
|---|
| 101 | PRIMARY KEY (id, topic_id)
|
|---|
| 102 | );
|
|---|
| 103 | CREATE TABLE discussion_thread
|
|---|
| 104 | (
|
|---|
| 105 | id INT PRIMARY KEY REFERENCES embeddable_thread(id) on delete cascade, --INHERITANCE,
|
|---|
| 106 | parent_id int REFERENCES embeddable_thread(id) NOT NULL --on delete CASCADE ne tuku preku trigger PARENT TOTAL BIGINT
|
|---|
| 107 | );
|
|---|
| 108 |
|
|---|
| 109 | CREATE TABLE likes
|
|---|
| 110 | (
|
|---|
| 111 | user_id INT REFERENCES users (id) on delete cascade,
|
|---|
| 112 | thread_id INT REFERENCES thread (id) on delete cascade,
|
|---|
| 113 | PRIMARY KEY (user_id, thread_id)
|
|---|
| 114 | );
|
|---|
| 115 | CREATE TABLE topic_threads_moderators
|
|---|
| 116 | (
|
|---|
| 117 | thread_id INT REFERENCES topic_thread(id) ON DELETE CASCADE,
|
|---|
| 118 | user_id INT REFERENCES moderator(id) ON DELETE CASCADE,
|
|---|
| 119 | started_at TIMESTAMP DEFAULT NOW() NOT NULL,
|
|---|
| 120 | PRIMARY KEY (thread_id, user_id)
|
|---|
| 121 | );
|
|---|
| 122 | CREATE TABLE tag
|
|---|
| 123 | (
|
|---|
| 124 | name VARCHAR(64) PRIMARY KEY,
|
|---|
| 125 | creator_id int REFERENCES moderator(id) on delete CASCADE not null
|
|---|
| 126 | );
|
|---|
| 127 | CREATE TABLE tag_threads
|
|---|
| 128 | (
|
|---|
| 129 | thread_id INT REFERENCES thread (id) ON DELETE CASCADE,
|
|---|
| 130 | tag_name VARCHAR(64) REFERENCES tag (name) ON DELETE CASCADE,
|
|---|
| 131 | PRIMARY KEY (thread_id, tag_name)
|
|---|
| 132 | );
|
|---|
| 133 |
|
|---|
| 134 | CREATE TABLE blacklisted_user
|
|---|
| 135 | (
|
|---|
| 136 | topic_id INT REFERENCES topic_thread(id) ON DELETE CASCADE, --BLACLISTED_FROM
|
|---|
| 137 | user_id INT REFERENCES users(id) ON DELETE CASCADE, --REFERS_TO
|
|---|
| 138 | moderator_id INT REFERENCES moderator(id) ON DELETE CASCADE, --BLACKLISTED_BY
|
|---|
| 139 | start_date TIMESTAMP,
|
|---|
| 140 | end_date TIMESTAMP,
|
|---|
| 141 | reason TEXT,
|
|---|
| 142 | PRIMARY KEY (user_id, moderator_id, topic_id, start_date)
|
|---|
| 143 | );
|
|---|
| 144 |
|
|---|
| 145 | CREATE TABLE developer_associated_with_project
|
|---|
| 146 | (
|
|---|
| 147 | project_id INT REFERENCES project_thread(id) on delete cascade,
|
|---|
| 148 | developer_id INT REFERENCES developer(id) on delete cascade,
|
|---|
| 149 | started_at TIMESTAMP DEFAULT NOW() NOT NULL,
|
|---|
| 150 | ended_at TIMESTAMP,
|
|---|
| 151 | PRIMARY KEY (project_id, developer_id, started_at)
|
|---|
| 152 | );
|
|---|
| 153 | ---DO TUKA
|
|---|
| 154 | CREATE TABLE permissions
|
|---|
| 155 | (
|
|---|
| 156 | name VARCHAR(32) PRIMARY KEY
|
|---|
| 157 | );
|
|---|
| 158 | CREATE TABLE project_roles
|
|---|
| 159 | (
|
|---|
| 160 | name VARCHAR(32),
|
|---|
| 161 | project_id INT REFERENCES project_thread(id) ON DELETE CASCADE NOT NULL, --VALID_IN
|
|---|
| 162 | description TEXT,
|
|---|
| 163 | PRIMARY KEY (name, project_id)
|
|---|
| 164 | );
|
|---|
| 165 | CREATE TABLE users_project_roles
|
|---|
| 166 | (
|
|---|
| 167 | user_id INT REFERENCES developer(id) on delete cascade,
|
|---|
| 168 | project_id INT,
|
|---|
| 169 | role_name VARCHAR(32),
|
|---|
| 170 | FOREIGN KEY (role_name, project_id)
|
|---|
| 171 | REFERENCES project_roles (name, project_id) ON DELETE CASCADE,
|
|---|
| 172 | PRIMARY KEY (user_id, project_id, role_name)
|
|---|
| 173 | );
|
|---|
| 174 | CREATE TABLE project_roles_permissions
|
|---|
| 175 | (
|
|---|
| 176 | permission_name VARCHAR(32) REFERENCES permissions (name),
|
|---|
| 177 | role_name VARCHAR(32),
|
|---|
| 178 | project_id INT,
|
|---|
| 179 | FOREIGN KEY (role_name, project_id)
|
|---|
| 180 | REFERENCES project_roles (name, project_id) ON DELETE CASCADE,
|
|---|
| 181 | PRIMARY KEY (permission_name, role_name, project_id)
|
|---|
| 182 | );
|
|---|
| 183 |
|
|---|
| 184 | create table submission(
|
|---|
| 185 | id serial primary key,
|
|---|
| 186 | created_at TIMESTAMP default now() not null,
|
|---|
| 187 | description VARCHAR(200) NOT NULL,
|
|---|
| 188 | status varchar(32) default 'PENDING' CHECK(status IN ( 'ACCEPTED', 'DENIED', 'PENDING')) NOT NULL,
|
|---|
| 189 | created_by int REFERENCES users(id) not null
|
|---|
| 190 | );
|
|---|
| 191 |
|
|---|
| 192 | CREATE TABLE project_request
|
|---|
| 193 | (
|
|---|
| 194 | id int PRIMARY KEY REFERENCES submission(id),
|
|---|
| 195 | project_id INT REFERENCES thread (id) ON DELETE CASCADE NOT NULL --RECIEVES
|
|---|
| 196 | );
|
|---|
| 197 |
|
|---|
| 198 | create table feedback (
|
|---|
| 199 | description TEXT,
|
|---|
| 200 | submission_type varchar(1) CHECK(submission_type IN ('P','R')),
|
|---|
| 201 | created_at timestamp default now() not null,
|
|---|
| 202 | created_by int references users(id) NOT NULL, --WRITTEN_BY
|
|---|
| 203 | submission_id int PRIMARY KEY references submission(id) on delete cascade
|
|---|
| 204 | );
|
|---|
| 205 |
|
|---|
| 206 | CREATE TABLE report
|
|---|
| 207 | (
|
|---|
| 208 | id int PRIMARY KEY REFERENCES submission(id),
|
|---|
| 209 | thread_id INT REFERENCES topic_thread(id) on delete cascade not null, --FOR_MISCONDUCT
|
|---|
| 210 | for_user_id INT REFERENCES users (id) on delete cascade not null --ABOUT
|
|---|
| 211 | );
|
|---|
| 212 | CREATE TABLE channel
|
|---|
| 213 | (
|
|---|
| 214 | name VARCHAR(64),
|
|---|
| 215 | description VARCHAR(200),
|
|---|
| 216 | project_id INT REFERENCES project_thread(id) ON DELETE CASCADE NOT NULL, --HAS
|
|---|
| 217 | developer_id INT REFERENCES developer(id) NOT NULL, --CONSTRUCTS
|
|---|
| 218 | PRIMARY KEY (name, project_id)
|
|---|
| 219 | );
|
|---|
| 220 | CREATE TABLE messages
|
|---|
| 221 | (
|
|---|
| 222 | sent_at TIMESTAMP,
|
|---|
| 223 | content VARCHAR(200) NOT NULL,
|
|---|
| 224 | sent_by INT REFERENCES developer(id),
|
|---|
| 225 | project_id INT,
|
|---|
| 226 | channel_name VARCHAR(64),
|
|---|
| 227 | FOREIGN KEY (channel_name, project_id)
|
|---|
| 228 | REFERENCES channel (name, project_id) ON DELETE CASCADE,
|
|---|
| 229 | PRIMARY KEY (channel_name, project_id, sent_at, sent_by)
|
|---|
| 230 | );
|
|---|
| 231 |
|
|---|
| 232 |
|
|---|
| 233 | ------------------------VIEWS-----------------------------
|
|---|
| 234 | CREATE OR REPLACE VIEW v_project_thread
|
|---|
| 235 | AS
|
|---|
| 236 | SELECT thread.id, content, user_id, title, repo_url
|
|---|
| 237 | FROM project_thread project
|
|---|
| 238 | JOIN thread
|
|---|
| 239 | ON project.id = thread.id;
|
|---|
| 240 | CREATE OR REPLACE VIEW v_topic_thread
|
|---|
| 241 | AS
|
|---|
| 242 | SELECT thread.id, content, user_id, title, parent_id
|
|---|
| 243 | FROM topic_thread topic
|
|---|
| 244 | JOIN thread
|
|---|
| 245 | ON topic.id = thread.id;
|
|---|
| 246 | CREATE OR REPLACE VIEW v_moderator
|
|---|
| 247 | AS
|
|---|
| 248 | SELECT users.id, username, is_activate, password, description, registered_at, sex
|
|---|
| 249 | FROM moderator
|
|---|
| 250 | JOIN users ON moderator.id = users.id;
|
|---|
| 251 |
|
|---|
| 252 | create or replace view v_discussion_thread
|
|---|
| 253 | as
|
|---|
| 254 | with recursive
|
|---|
| 255 | depth_table as
|
|---|
| 256 | (select parent_id, id, 0 as depth
|
|---|
| 257 | from discussion_thread
|
|---|
| 258 | UNION ALL
|
|---|
| 259 | select discuss.parent_id, dpth.id, dpth.depth + 1
|
|---|
| 260 | from depth_table dpth
|
|---|
| 261 | join discussion_thread discuss
|
|---|
| 262 | on dpth.parent_id = discuss.id),
|
|---|
| 263 | tmp as (select id, max(depth) as depth
|
|---|
| 264 | from depth_table
|
|---|
| 265 | group by id)
|
|---|
| 266 | select d.id as id, t.user_id as user_id, d.depth as depth, d1.parent_id as parent_id, t.created_at as "created_at"
|
|---|
| 267 | from tmp d
|
|---|
| 268 | join depth_table d1
|
|---|
| 269 | on d.id = d1.id and d1.depth = d.depth
|
|---|
| 270 | join thread t
|
|---|
| 271 | on t.id = d.id;
|
|---|
| 272 | -------------------------- FUNCTIONS ----------------------
|
|---|
| 273 | CREATE OR REPLACE FUNCTION fn_validate_topic_title()
|
|---|
| 274 | RETURNS TRIGGER
|
|---|
| 275 | LANGUAGE plpgsql
|
|---|
| 276 | AS
|
|---|
| 277 | $$
|
|---|
| 278 | BEGIN
|
|---|
| 279 | IF new.title IN
|
|---|
| 280 | (SELECT title
|
|---|
| 281 | FROM topic_thread
|
|---|
| 282 | AS t
|
|---|
| 283 | WHERE t.parent_id = new.parent_id
|
|---|
| 284 | OR (t.parent_id IS NULL AND new.parent_id IS NULL)
|
|---|
| 285 | )
|
|---|
| 286 | THEN
|
|---|
| 287 | RAISE EXCEPTION 'There already exists a topic with title % in parent topic with id %',new.title,new.parent_id;
|
|---|
| 288 | END IF;
|
|---|
| 289 | RETURN new;
|
|---|
| 290 | END;
|
|---|
| 291 | $$;
|
|---|
| 292 | create or replace function check_if_user_exists_in(table_name text, field_name text, field_value text) returns boolean
|
|---|
| 293 | language plpgsql
|
|---|
| 294 | as
|
|---|
| 295 | $$
|
|---|
| 296 | DECLARE
|
|---|
| 297 | result BOOL;
|
|---|
| 298 | BEGIN
|
|---|
| 299 | EXECUTE format('SELECT EXISTS (SELECT 1 FROM %I WHERE %I = %L)', table_name, field_name, field_value)
|
|---|
| 300 | INTO result;
|
|---|
| 301 | RETURN result;
|
|---|
| 302 | END
|
|---|
| 303 | $$;
|
|---|
| 304 | CREATE OR REPLACE FUNCTION fn_insert_topics_creator_as_moderator()
|
|---|
| 305 | RETURNS TRIGGER
|
|---|
| 306 | LANGUAGE plpgsql
|
|---|
| 307 | AS
|
|---|
| 308 | $$
|
|---|
| 309 | DECLARE
|
|---|
| 310 | v_user_id INT;
|
|---|
| 311 | BEGIN
|
|---|
| 312 | SELECT v_topic_thread.user_id
|
|---|
| 313 | INTO v_user_id
|
|---|
| 314 | FROM v_topic_thread
|
|---|
| 315 | WHERE v_topic_thread.id = new.id;
|
|---|
| 316 | IF not check_if_user_exists_in('moderator', 'id', v_user_id::text) THEN
|
|---|
| 317 | INSERT INTO moderator values (v_user_id);
|
|---|
| 318 | END IF;
|
|---|
| 319 | INSERT INTO topic_threads_moderators(thread_id, user_id) VALUES (new.id, v_user_id);
|
|---|
| 320 | RETURN NEW;
|
|---|
| 321 | END
|
|---|
| 322 | $$;
|
|---|
| 323 |
|
|---|
| 324 | CREATE OR REPLACE FUNCTION fn_insert_project_manager()
|
|---|
| 325 | RETURNS TRIGGER
|
|---|
| 326 | LANGUAGE plpgsql
|
|---|
| 327 | AS
|
|---|
| 328 | $$
|
|---|
| 329 | DECLARE
|
|---|
| 330 | usrId INT;
|
|---|
| 331 | new_project_id INT;
|
|---|
| 332 | BEGIN
|
|---|
| 333 | SELECT user_id, id
|
|---|
| 334 | into usrId,new_project_id
|
|---|
| 335 | FROM v_project_thread p
|
|---|
| 336 | WHERE NEW.id = p.id;
|
|---|
| 337 | IF not EXISTS(
|
|---|
| 338 | select 1
|
|---|
| 339 | from developer_associated_with_project dawp
|
|---|
| 340 | where dawp.project_id=new_project_id and dawp.developer_id=usrId
|
|---|
| 341 | ) THEN
|
|---|
| 342 | INSERT INTO developer_associated_with_project(project_id, developer_id, started_at)
|
|---|
| 343 | values (new_project_id, usrId, NOW());
|
|---|
| 344 | end if;
|
|---|
| 345 | IF not check_if_user_exists_in('project_manager', 'id', usrId::text) THEN
|
|---|
| 346 | INSERT INTO project_manager VALUES (usrId);
|
|---|
| 347 | end if;
|
|---|
| 348 | RETURN NEW;
|
|---|
| 349 | END
|
|---|
| 350 | $$;
|
|---|
| 351 | create or replace function fn_remove_unused_tags()
|
|---|
| 352 | returns trigger
|
|---|
| 353 | language plpgsql
|
|---|
| 354 | as
|
|---|
| 355 | $$
|
|---|
| 356 | BEGIN
|
|---|
| 357 | IF not check_if_user_exists_in('tag_threads', 'tag_name', old.tag_name)
|
|---|
| 358 | THEN
|
|---|
| 359 | delete from tag t where t.name = old.tag_name;
|
|---|
| 360 | end if;
|
|---|
| 361 | return old;
|
|---|
| 362 | end;
|
|---|
| 363 | $$;
|
|---|
| 364 | create or replace function fn_add_dev_if_not_exist()
|
|---|
| 365 | returns trigger
|
|---|
| 366 | language plpgsql
|
|---|
| 367 | as $$
|
|---|
| 368 | BEGIN
|
|---|
| 369 | IF NOT check_if_user_exists_in('developer','id',new.developer_id::text) THEN
|
|---|
| 370 | INSERT INTO developer values (NEW.developer_id);
|
|---|
| 371 | end if;
|
|---|
| 372 | RETURN new;
|
|---|
| 373 | end;
|
|---|
| 374 | $$;
|
|---|
| 375 |
|
|---|
| 376 | create or replace function fn_insert_general_for_project()
|
|---|
| 377 | returns trigger
|
|---|
| 378 | language plpgsql
|
|---|
| 379 | as $$
|
|---|
| 380 | DECLARE
|
|---|
| 381 | developer_id INT;
|
|---|
| 382 | BEGIN
|
|---|
| 383 | select user_id
|
|---|
| 384 | into developer_id
|
|---|
| 385 | from thread t
|
|---|
| 386 | where t.id=NEW.id;
|
|---|
| 387 |
|
|---|
| 388 | insert into channel(name,description,project_id,developer_id)
|
|---|
| 389 | values ('General','General',NEW.id,developer_id);
|
|---|
| 390 |
|
|---|
| 391 | return new;
|
|---|
| 392 | end;
|
|---|
| 393 | $$;
|
|---|
| 394 |
|
|---|
| 395 | CREATE OR REPLACE FUNCTION fn_defined_by_total_custom_roles()
|
|---|
| 396 | RETURNS trigger
|
|---|
| 397 | LANGUAGE plpgsql
|
|---|
| 398 | AS $$
|
|---|
| 399 | BEGIN
|
|---|
| 400 | IF not exists(
|
|---|
| 401 | select 1
|
|---|
| 402 | from project_roles_permissions p
|
|---|
| 403 | where p.role_name=OLD.role_name and p.project_id = OLD.project_id
|
|---|
| 404 | ) THEN
|
|---|
| 405 | DELETE FROM project_roles
|
|---|
| 406 | where name=OLD.role_name and project_id=OLD.project_id;
|
|---|
| 407 | END IF;
|
|---|
| 408 | RETURN OLD;
|
|---|
| 409 | END;
|
|---|
| 410 | $$
|
|---|
| 411 | ;
|
|---|
| 412 |
|
|---|
| 413 | CREATE OR REPLACE FUNCTION fn_remove_orphan_moderator()
|
|---|
| 414 | RETURNS trigger
|
|---|
| 415 | LANGUAGE plpgsql
|
|---|
| 416 | AS $function$
|
|---|
| 417 | BEGIN
|
|---|
| 418 | IF not exists (
|
|---|
| 419 | select 1
|
|---|
| 420 | from topic_threads_moderators t
|
|---|
| 421 | where t.user_id = OLD.user_id
|
|---|
| 422 | )
|
|---|
| 423 | THEN
|
|---|
| 424 | DELETE FROM moderator where id=OLD.user_id;
|
|---|
| 425 | END IF;
|
|---|
| 426 | IF not exists (
|
|---|
| 427 | select 1
|
|---|
| 428 | from topic_threads_moderators t
|
|---|
| 429 | where t.thread_id = OLD.thread_id
|
|---|
| 430 | )
|
|---|
| 431 | THEN
|
|---|
| 432 | delete from discussion_thread where parent_id=OLD.thread_id;
|
|---|
| 433 | DELETE FROM topic_thread where id = OLD.thread_id;
|
|---|
| 434 | -- delete from thread where id = OLD.thread_id;
|
|---|
| 435 | END IF;
|
|---|
| 436 | RETURN OLD;
|
|---|
| 437 | END;
|
|---|
| 438 | $function$
|
|---|
| 439 | ;
|
|---|
| 440 | create or replace function fn_aa_rm_orphan_dics()
|
|---|
| 441 | returns trigger
|
|---|
| 442 | language plpgsql
|
|---|
| 443 | as
|
|---|
| 444 | $$
|
|---|
| 445 | BEGIN
|
|---|
| 446 | -- RAISE NOTICE '%',OLD.id;
|
|---|
| 447 |
|
|---|
| 448 | delete from discussion_thread dt
|
|---|
| 449 | where dt.parent_id=OLD.id;
|
|---|
| 450 | delete from embeddable_thread
|
|---|
| 451 | where id = OLD.id;
|
|---|
| 452 | delete from thread t
|
|---|
| 453 | where t.id=OLD.id;
|
|---|
| 454 | RETURN OLD;
|
|---|
| 455 | END;
|
|---|
| 456 | $$;
|
|---|
| 457 |
|
|---|
| 458 |
|
|---|
| 459 |
|
|---|
| 460 | -- create or replace function fn_remove_thread()
|
|---|
| 461 | -- returns trigger
|
|---|
| 462 | -- language plpgsql
|
|---|
| 463 | -- as
|
|---|
| 464 | -- $$
|
|---|
| 465 | -- BEGIN
|
|---|
| 466 | -- delete from thread where id = OLD.id;
|
|---|
| 467 | -- return OLD;
|
|---|
| 468 | -- END;
|
|---|
| 469 | -- $$;
|
|---|
| 470 |
|
|---|
| 471 |
|
|---|
| 472 | -------------------------- TRIGGERS ----------------------
|
|---|
| 473 |
|
|---|
| 474 | CREATE OR REPLACE TRIGGER tr_check_topic_name --RADI
|
|---|
| 475 | BEFORE INSERT OR UPDATE
|
|---|
| 476 | ON topic_thread
|
|---|
| 477 | FOR EACH ROW
|
|---|
| 478 | EXECUTE FUNCTION fn_validate_topic_title();
|
|---|
| 479 | CREATE OR REPLACE TRIGGER tr_insert_topics_creator_as_moderator --RADI
|
|---|
| 480 | AFTER INSERT
|
|---|
| 481 | ON topic_thread
|
|---|
| 482 | FOR EACH ROW
|
|---|
| 483 | EXECUTE FUNCTION fn_insert_topics_creator_as_moderator();
|
|---|
| 484 | ----
|
|---|
| 485 | create or replace TRIGGER tr_defined_by_total_custom_roles
|
|---|
| 486 | after delete
|
|---|
| 487 | on project_roles_permissions
|
|---|
| 488 | for each row
|
|---|
| 489 | execute function fn_defined_by_total_custom_roles();
|
|---|
| 490 |
|
|---|
| 491 | CREATE OR REPLACE TRIGGER tr_remove_orphan_moderator --RADI
|
|---|
| 492 | AFTER DELETE
|
|---|
| 493 | ON topic_threads_moderators
|
|---|
| 494 | FOR EACH ROW
|
|---|
| 495 | EXECUTE FUNCTION fn_remove_orphan_moderator();
|
|---|
| 496 |
|
|---|
| 497 |
|
|---|
| 498 | CREATE OR REPLACE TRIGGER tr_a_insert_project_manager --RADI
|
|---|
| 499 | AFTER INSERT
|
|---|
| 500 | ON project_thread
|
|---|
| 501 | FOR EACH ROW
|
|---|
| 502 | EXECUTE FUNCTION fn_insert_project_manager();
|
|---|
| 503 |
|
|---|
| 504 | create or replace trigger tr_remove_unused_tags --RADI
|
|---|
| 505 | after delete
|
|---|
| 506 | on tag_threads
|
|---|
| 507 | for each row
|
|---|
| 508 | execute function fn_remove_unused_tags();
|
|---|
| 509 |
|
|---|
| 510 | create or replace trigger tr_add_dev_if_not_exist --RADI
|
|---|
| 511 | before insert on developer_associated_with_project
|
|---|
| 512 | for each row
|
|---|
| 513 | execute function fn_add_dev_if_not_exist();
|
|---|
| 514 |
|
|---|
| 515 | create or replace trigger tr_insert_general_for_project --RADI
|
|---|
| 516 | after insert on project_thread
|
|---|
| 517 | for each row
|
|---|
| 518 | execute function fn_insert_general_for_project();
|
|---|
| 519 |
|
|---|
| 520 | create or replace trigger tr_rm_orphan_disc
|
|---|
| 521 | after delete
|
|---|
| 522 | on discussion_thread
|
|---|
| 523 | for each row
|
|---|
| 524 | execute function fn_aa_rm_orphan_dics();
|
|---|
| 525 |
|
|---|
| 526 | create or replace trigger tr_rm_orphan_disc
|
|---|
| 527 | after delete
|
|---|
| 528 | on topic_thread
|
|---|
| 529 | for each row
|
|---|
| 530 | execute function fn_aa_rm_orphan_dics();
|
|---|
| 531 |
|
|---|
| 532 | -- create or replace trigger tr_remove_thread_from_project
|
|---|
| 533 | -- after delete
|
|---|
| 534 | -- on project_thread
|
|---|
| 535 | -- for each row
|
|---|
| 536 | -- execute function fn_remove_thread();
|
|---|
| 537 | --
|
|---|
| 538 | -- create or replace trigger tr_remove_thread_from_topic
|
|---|
| 539 | -- after delete
|
|---|
| 540 | -- on topic_thread
|
|---|
| 541 | -- for each row
|
|---|
| 542 | -- execute function fn_remove_thread();
|
|---|
| 543 | --
|
|---|
| 544 | -- create or replace trigger tr_remove_thread_from_discussion
|
|---|
| 545 | -- after delete
|
|---|
| 546 | -- on discussion_thread
|
|---|
| 547 | -- for each row
|
|---|
| 548 | -- execute function fn_remove_thread(); |
|---|