Initial commit: Angular frontend and Expressjs backend
This commit is contained in:
1901
worklenz-backend/database/1_tables.sql
Normal file
1901
worklenz-backend/database/1_tables.sql
Normal file
File diff suppressed because it is too large
Load Diff
161
worklenz-backend/database/2_triggers.sql
Normal file
161
worklenz-backend/database/2_triggers.sql
Normal file
@@ -0,0 +1,161 @@
|
||||
-- Lowercase email
|
||||
CREATE OR REPLACE FUNCTION lower_email() RETURNS TRIGGER AS
|
||||
$$
|
||||
DECLARE
|
||||
BEGIN
|
||||
|
||||
IF (is_null_or_empty(NEW.email) IS FALSE)
|
||||
THEN
|
||||
NEW.email = LOWER(TRIM(NEW.email));
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
DROP TRIGGER IF EXISTS users_email_lower ON users;
|
||||
CREATE TRIGGER users_email_lower
|
||||
BEFORE INSERT OR UPDATE
|
||||
ON users
|
||||
EXECUTE FUNCTION lower_email();
|
||||
|
||||
DROP TRIGGER IF EXISTS email_invitations_email_lower ON email_invitations;
|
||||
CREATE TRIGGER email_invitations_email_lower
|
||||
BEFORE INSERT OR UPDATE
|
||||
ON email_invitations
|
||||
EXECUTE FUNCTION lower_email();
|
||||
-- Lowercase email
|
||||
|
||||
-- Set task completed date
|
||||
CREATE OR REPLACE FUNCTION task_status_change_trigger_fn() RETURNS TRIGGER AS
|
||||
$$
|
||||
DECLARE
|
||||
BEGIN
|
||||
IF EXISTS(SELECT 1
|
||||
FROM sys_task_status_categories
|
||||
WHERE id = (SELECT category_id FROM task_statuses WHERE id = NEW.status_id)
|
||||
AND is_done IS TRUE)
|
||||
THEN
|
||||
UPDATE tasks SET completed_at = CURRENT_TIMESTAMP WHERE id = NEW.id;
|
||||
ELSE
|
||||
UPDATE tasks SET completed_at = NULL WHERE id = NEW.id;
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE TRIGGER tasks_status_id_change
|
||||
AFTER UPDATE OF status_id
|
||||
ON tasks
|
||||
FOR EACH ROW
|
||||
WHEN (OLD.status_id IS DISTINCT FROM new.status_id)
|
||||
EXECUTE FUNCTION task_status_change_trigger_fn();
|
||||
-- Set task completed date
|
||||
|
||||
-- Insert notification settings for new team members
|
||||
CREATE OR REPLACE FUNCTION notification_settings_insert_trigger_fn() RETURNS TRIGGER AS
|
||||
$$
|
||||
DECLARE
|
||||
BEGIN
|
||||
|
||||
IF (NOT EXISTS(SELECT 1 FROM notification_settings WHERE team_id = NEW.team_id AND user_id = NEW.user_id)) AND
|
||||
(is_null_or_empty(NEW.user_id) IS FALSE) AND (EXISTS(SELECT 1 FROM users WHERE id = NEW.user_id))
|
||||
THEN
|
||||
INSERT INTO notification_settings (popup_notifications_enabled, show_unread_items_count, user_id,
|
||||
team_id)
|
||||
VALUES (TRUE, TRUE, NEW.user_id, NEW.team_id);
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
DROP TRIGGER IF EXISTS insert_notification_settings ON team_members;
|
||||
CREATE TRIGGER insert_notification_settings
|
||||
AFTER INSERT
|
||||
ON team_members
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION notification_settings_insert_trigger_fn();
|
||||
-- Insert notification settings for new team members
|
||||
|
||||
-- Delete notification settings when removing team members
|
||||
CREATE OR REPLACE FUNCTION notification_settings_delete_trigger_fn() RETURNS TRIGGER AS
|
||||
$$
|
||||
DECLARE
|
||||
BEGIN
|
||||
DELETE FROM notification_settings WHERE user_id = OLD.user_id AND team_id = OLD.team_id;
|
||||
RETURN OLD;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
DROP TRIGGER IF EXISTS remove_notification_settings ON team_members;
|
||||
CREATE TRIGGER remove_notification_settings
|
||||
BEFORE DELETE
|
||||
ON team_members
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION notification_settings_delete_trigger_fn();
|
||||
-- Delete notification settings when removing team members
|
||||
|
||||
-- Set task updated at
|
||||
CREATE OR REPLACE FUNCTION set_task_updated_at_trigger_fn() RETURNS TRIGGER AS
|
||||
$$
|
||||
DECLARE
|
||||
BEGIN
|
||||
NEW.updated_at = CURRENT_TIMESTAMP;
|
||||
RETURN NEW;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER set_task_updated_at
|
||||
BEFORE UPDATE
|
||||
ON tasks
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION set_task_updated_at_trigger_fn();
|
||||
-- Set task updated at
|
||||
|
||||
-- Update project tasks counter
|
||||
CREATE OR REPLACE FUNCTION update_project_tasks_counter_trigger_fn() RETURNS TRIGGER AS
|
||||
$$
|
||||
DECLARE
|
||||
BEGIN
|
||||
|
||||
UPDATE projects SET tasks_counter = (tasks_counter + 1) WHERE id = NEW.project_id;
|
||||
NEW.task_no = (SELECT tasks_counter FROM projects WHERE id = NEW.project_id);
|
||||
|
||||
RETURN NEW;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
DROP TRIGGER IF EXISTS projects_tasks_counter_trigger ON tasks;
|
||||
CREATE TRIGGER projects_tasks_counter_trigger
|
||||
BEFORE INSERT
|
||||
ON tasks
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_project_tasks_counter_trigger_fn();
|
||||
-- Update project tasks counter
|
||||
|
||||
-- Task status change trigger
|
||||
CREATE OR REPLACE FUNCTION tasks_task_subscriber_notify_done_trigger() RETURNS TRIGGER AS
|
||||
$$
|
||||
DECLARE
|
||||
BEGIN
|
||||
IF (EXISTS(SELECT 1
|
||||
FROM sys_task_status_categories
|
||||
WHERE id = (SELECT category_id FROM task_statuses WHERE id = NEW.status_id)
|
||||
AND is_done IS TRUE))
|
||||
THEN
|
||||
PERFORM pg_notify('db_task_status_changed', NEW.id::TEXT);
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE TRIGGER tasks_task_subscriber_notify_done
|
||||
BEFORE UPDATE OF status_id
|
||||
ON tasks
|
||||
FOR EACH ROW
|
||||
WHEN (OLD.status_id IS DISTINCT FROM NEW.status_id)
|
||||
EXECUTE FUNCTION tasks_task_subscriber_notify_done_trigger();
|
||||
-- Task status change trigger
|
||||
77
worklenz-backend/database/3_system-data.sql
Normal file
77
worklenz-backend/database/3_system-data.sql
Normal file
@@ -0,0 +1,77 @@
|
||||
CREATE OR REPLACE FUNCTION sys_insert_task_priorities() RETURNS VOID AS
|
||||
$$
|
||||
BEGIN
|
||||
INSERT INTO task_priorities (name, value, color_code) VALUES ('Low', 0, '#75c997');
|
||||
INSERT INTO task_priorities (name, value, color_code) VALUES ('Medium', 1, '#fbc84c');
|
||||
INSERT INTO task_priorities (name, value, color_code) VALUES ('High', 2, '#f37070');
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys_insert_project_access_levels() RETURNS VOID AS
|
||||
$$
|
||||
BEGIN
|
||||
INSERT INTO project_access_levels (name, key)
|
||||
VALUES ('Admin', 'ADMIN');
|
||||
INSERT INTO project_access_levels (name, key)
|
||||
VALUES ('Member', 'MEMBER');
|
||||
INSERT INTO project_access_levels (name, key)
|
||||
VALUES ('Project Manager', 'PROJECT_MANAGER');
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys_insert_task_status_categories() RETURNS VOID AS
|
||||
$$
|
||||
BEGIN
|
||||
INSERT INTO sys_task_status_categories (name, color_code, index, is_todo)
|
||||
VALUES ('To do', '#a9a9a9', 0, TRUE);
|
||||
INSERT INTO sys_task_status_categories (name, color_code, index, is_doing)
|
||||
VALUES ('Doing', '#70a6f3', 1, TRUE);
|
||||
INSERT INTO sys_task_status_categories (name, color_code, index, is_done)
|
||||
VALUES ('Done', '#75c997', 2, TRUE);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys_insert_project_statuses() RETURNS VOID AS
|
||||
$$
|
||||
BEGIN
|
||||
INSERT INTO sys_project_statuses (name, color_code, icon, sort_order, is_default)
|
||||
VALUES ('Cancelled', '#f37070', 'close-circle', 0, FALSE),
|
||||
('Blocked', '#cbc8a1', 'stop', 1, FALSE),
|
||||
('On Hold', '#cbc8a1', 'stop', 2, FALSE),
|
||||
('Proposed', '#cbc8a1', 'clock-circle', 3, TRUE),
|
||||
('In Planning', '#cbc8a1', 'clock-circle', 4, FALSE),
|
||||
('In Progress', '#80ca79', 'clock-circle', 5, FALSE),
|
||||
('Completed', '#80ca79', 'check-circle', 6, FALSE);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys_insert_project_healths() RETURNS VOID AS
|
||||
$$
|
||||
BEGIN
|
||||
INSERT INTO sys_project_healths (name, color_code, sort_order, is_default)
|
||||
VALUES ('Not Set', '#a9a9a9', 0, TRUE);
|
||||
INSERT INTO sys_project_healths (name, color_code, sort_order, is_default)
|
||||
VALUES ('Needs Attention', '#fbc84c', 1, FALSE);
|
||||
INSERT INTO sys_project_healths (name, color_code, sort_order, is_default)
|
||||
VALUES ('At Risk', '#f37070', 2, FALSE);
|
||||
INSERT INTO sys_project_healths (name, color_code, sort_order, is_default)
|
||||
VALUES ('Good', '#75c997', 3, FALSE);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
SELECT sys_insert_task_priorities();
|
||||
SELECT sys_insert_project_access_levels();
|
||||
SELECT sys_insert_task_status_categories();
|
||||
SELECT sys_insert_project_statuses();
|
||||
SELECT sys_insert_project_healths();
|
||||
|
||||
DROP FUNCTION sys_insert_task_priorities();
|
||||
DROP FUNCTION sys_insert_project_access_levels();
|
||||
DROP FUNCTION sys_insert_task_status_categories();
|
||||
DROP FUNCTION sys_insert_project_statuses();
|
||||
DROP FUNCTION sys_insert_project_healths();
|
||||
|
||||
INSERT INTO timezones (name, abbrev, utc_offset)
|
||||
SELECT name, abbrev, utc_offset
|
||||
FROM pg_timezone_names;
|
||||
34
worklenz-backend/database/4_views.sql
Normal file
34
worklenz-backend/database/4_views.sql
Normal file
@@ -0,0 +1,34 @@
|
||||
CREATE VIEW task_labels_view(name, task_id, label_id) AS
|
||||
SELECT (SELECT team_labels.name
|
||||
FROM team_labels
|
||||
WHERE team_labels.id = task_labels.label_id) AS name,
|
||||
task_labels.task_id,
|
||||
task_labels.label_id
|
||||
FROM task_labels;
|
||||
|
||||
CREATE VIEW tasks_with_status_view(task_id, parent_task_id, is_todo, is_doing, is_done) AS
|
||||
SELECT tasks.id AS task_id,
|
||||
tasks.parent_task_id,
|
||||
stsc.is_todo,
|
||||
stsc.is_doing,
|
||||
stsc.is_done
|
||||
FROM tasks
|
||||
JOIN task_statuses ts ON tasks.status_id = ts.id
|
||||
JOIN sys_task_status_categories stsc ON ts.category_id = stsc.id
|
||||
WHERE tasks.archived IS FALSE;
|
||||
|
||||
CREATE VIEW team_member_info_view(avatar_url, email, name, user_id, team_member_id, team_id) AS
|
||||
SELECT u.avatar_url,
|
||||
COALESCE(u.email, (SELECT email_invitations.email
|
||||
FROM email_invitations
|
||||
WHERE email_invitations.team_member_id = team_members.id)) AS email,
|
||||
COALESCE(u.name, (SELECT email_invitations.name
|
||||
FROM email_invitations
|
||||
WHERE email_invitations.team_member_id = team_members.id)) AS name,
|
||||
u.id AS user_id,
|
||||
team_members.id AS team_member_id,
|
||||
team_members.team_id
|
||||
FROM team_members
|
||||
LEFT JOIN users u ON team_members.user_id = u.id;
|
||||
|
||||
|
||||
5791
worklenz-backend/database/5_functions.sql
Normal file
5791
worklenz-backend/database/5_functions.sql
Normal file
File diff suppressed because it is too large
Load Diff
31
worklenz-backend/database/6_user-permission.sql
Normal file
31
worklenz-backend/database/6_user-permission.sql
Normal file
@@ -0,0 +1,31 @@
|
||||
REVOKE CREATE ON SCHEMA public FROM PUBLIC;
|
||||
CREATE ROLE worklenz_client;
|
||||
|
||||
GRANT CONNECT ON DATABASE "DATABASE_NAME" TO worklenz_client;
|
||||
GRANT INSERT, SELECT, UPDATE, DELETE ON ALL TABLES IN SCHEMA public TO worklenz_client;
|
||||
|
||||
GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO worklenz_client;
|
||||
|
||||
REVOKE ALL PRIVILEGES ON task_priorities FROM worklenz_client;
|
||||
GRANT SELECT ON task_priorities TO worklenz_client;
|
||||
|
||||
REVOKE ALL PRIVILEGES ON project_access_levels FROM worklenz_client;
|
||||
GRANT SELECT ON project_access_levels TO worklenz_client;
|
||||
|
||||
REVOKE ALL PRIVILEGES ON timezones FROM worklenz_client;
|
||||
GRANT SELECT ON timezones TO worklenz_client;
|
||||
|
||||
REVOKE ALL PRIVILEGES ON worklenz_alerts FROM worklenz_client;
|
||||
GRANT SELECT ON worklenz_alerts TO worklenz_client;
|
||||
|
||||
REVOKE ALL PRIVILEGES ON sys_task_status_categories FROM worklenz_client;
|
||||
GRANT SELECT ON sys_task_status_categories TO worklenz_client;
|
||||
|
||||
REVOKE ALL PRIVILEGES ON sys_project_statuses FROM worklenz_client;
|
||||
GRANT SELECT ON sys_project_statuses TO worklenz_client;
|
||||
|
||||
REVOKE ALL PRIVILEGES ON sys_project_healths FROM worklenz_client;
|
||||
GRANT SELECT ON sys_project_healths TO worklenz_client;
|
||||
|
||||
CREATE USER worklenz_backend WITH PASSWORD 'PASSWORD';
|
||||
GRANT worklenz_client TO worklenz_backend;
|
||||
1
worklenz-backend/database/README.md
Normal file
1
worklenz-backend/database/README.md
Normal file
@@ -0,0 +1 @@
|
||||
All database DDLs, DMLs and migrations relates to the application should be stored here as well.
|
||||
Reference in New Issue
Block a user