diff --git a/database.sql b/database.sql index 099cbb3..6b7b3eb 100644 --- a/database.sql +++ b/database.sql @@ -14,8 +14,10 @@ BEGIN; \i database/items-functions.sql -- Task management and task dependencies +\i database/task-containers.sql \i database/tasks-functions.sql \i database/task-dependencies.sql +\i database/tasks-move-sub.sql \i database/tasks-view.sql COMMIT; diff --git a/database/create-tables.sql b/database/create-tables.sql index 7cccf82..78ed93e 100644 --- a/database/create-tables.sql +++ b/database/create-tables.sql @@ -27,6 +27,43 @@ GRANT SELECT,UPDATE ON task_dependencies_taskdep_id_seq TO :webapp_user; -- Tables +/* + * Task containers + * ---------------- + * + * A task container is either an item or a task. Task names within the + * same task container are unique. + */ +CREATE TABLE task_containers ( + tc_id SERIAL NOT NULL PRIMARY KEY , + task_id INT UNIQUE , + item_id INT UNIQUE , + CHECK( task_id IS NULL AND item_id IS NOT NULL OR task_id IS NOT NULL AND item_id IS NULL ) +); + +GRANT SELECT ON task_containers TO :webapp_user; + + +/* + * Logical task containers + * ------------------------ + * + * A logical task container is a group of tasks that can depend on each other. + * One such container exists for all top-level tasks, and each task defines a + * container as well. + */ +CREATE TABLE logical_task_containers( + ltc_id SERIAL NOT NULL PRIMARY KEY , + task_id INT UNIQUE , + CHECK( ltc_id = 1 AND task_id IS NULL OR ltc_id <> 1 AND task_id IS NOT NULL ) +); + +INSERT INTO logical_task_containers DEFAULT VALUES; + +GRANT SELECT ON logical_task_containers TO :webapp_user; + + + -- Table items CREATE TABLE items ( item_id INT NOT NULL DEFAULT NEXTVAL('items_item_id_seq'::TEXT), @@ -51,6 +88,13 @@ ALTER TABLE items ADD FOREIGN KEY (item_id_parent) GRANT SELECT,INSERT,UPDATE,DELETE ON items TO :webapp_user; +-- Add reference from task containers to items +ALTER TABLE task_containers + ADD FOREIGN KEY ( item_id ) REFERENCES items( item_id ) + ON UPDATE NO ACTION + ON DELETE CASCADE; + + -- Table users CREATE TABLE users ( @@ -70,21 +114,38 @@ GRANT SELECT,INSERT,UPDATE ON users TO :webapp_user; -- Table tasks CREATE TABLE tasks ( - task_id INT NOT NULL DEFAULT NEXTVAL('tasks_task_id_seq'::TEXT), - item_id INT NOT NULL REFERENCES items(item_id) ON UPDATE NO ACTION ON DELETE CASCADE, - task_title VARCHAR(256) NOT NULL, - task_priority INT NOT NULL, - task_description TEXT NOT NULL, - task_added TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT now(), - user_id INT NOT NULL REFERENCES users(user_id) ON UPDATE NO ACTION ON DELETE CASCADE, - user_id_assigned INT REFERENCES users(user_id) ON UPDATE NO ACTION ON DELETE SET NULL , - PRIMARY KEY(task_id) + task_id INT NOT NULL DEFAULT NEXTVAL('tasks_task_id_seq'::TEXT), + ltc_id INT NOT NULL REFERENCES logical_task_containers( ltc_id ) + ON UPDATE NO ACTION ON DELETE CASCADE , + tc_id INT NOT NULL REFERENCES task_containers( tc_id ) + ON UPDATE NO ACTION ON DELETE CASCADE , + task_title VARCHAR(256) NOT NULL, + task_priority INT NOT NULL, + task_description TEXT NOT NULL, + task_added TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT now(), + user_id INT NOT NULL REFERENCES users(user_id) ON UPDATE NO ACTION ON DELETE CASCADE, + user_id_assigned INT REFERENCES users(user_id) ON UPDATE NO ACTION ON DELETE SET NULL , + + PRIMARY KEY( task_id ) ); -CREATE UNIQUE INDEX i_tasks_item_id_task_title ON tasks (item_id,task_title); +CREATE UNIQUE INDEX i_tasks_title ON tasks (tc_id,task_title); +CREATE UNIQUE INDEX i_tasks_ltc ON tasks (task_id , ltc_id); GRANT SELECT,INSERT,UPDATE,DELETE ON tasks TO :webapp_user; +-- Add reference from task containers to tasks +ALTER TABLE task_containers + ADD FOREIGN KEY ( task_id ) REFERENCES tasks( task_id ) + ON UPDATE NO ACTION + ON DELETE CASCADE; + +-- Add reference from logical task containers to tasks +ALTER TABLE logical_task_containers + ADD FOREIGN KEY ( task_id ) REFERENCES tasks( task_id ) + ON UPDATE NO ACTION + ON DELETE CASCADE; + -- Table items_tree CREATE TABLE items_tree ( @@ -112,13 +173,23 @@ GRANT SELECT,INSERT,UPDATE,DELETE ON completed_tasks TO :webapp_user; -- Table task_dependencies CREATE TABLE task_dependencies ( taskdep_id INT NOT NULL DEFAULT NEXTVAL('task_dependencies_taskdep_id_seq'::TEXT), - task_id INT NOT NULL REFERENCES tasks(task_id) ON UPDATE NO ACTION ON DELETE CASCADE, - task_id_depends INT NOT NULL REFERENCES tasks(task_id) ON UPDATE NO ACTION ON DELETE CASCADE, + ltc_id INT NOT NULL , + task_id INT NOT NULL , + task_id_depends INT NOT NULL , PRIMARY KEY(taskdep_id) ); CREATE UNIQUE INDEX i_taskdep_unicity ON task_dependencies (task_id,task_id_depends); CREATE INDEX i_taskdep_bydependency ON task_dependencies (task_id_depends); + +ALTER TABLE task_dependencies + ADD CONSTRAINT fk_taskdep_task + FOREIGN KEY ( ltc_id , task_id ) REFERENCES tasks( ltc_id , task_id ) + ON UPDATE NO ACTION ON DELETE CASCADE , + ADD CONSTRAINT fk_taskdep_dependency + FOREIGN KEY ( ltc_id , task_id_depends ) REFERENCES tasks( ltc_id , task_id ) + ON UPDATE NO ACTION ON DELETE CASCADE; + GRANT SELECT,INSERT,DELETE ON task_dependencies TO :webapp_user; diff --git a/database/task-containers.sql b/database/task-containers.sql new file mode 100644 index 0000000..360504b --- /dev/null +++ b/database/task-containers.sql @@ -0,0 +1,43 @@ +/* + * Triggers to handle task containers + */ + + +DROP FUNCTION IF EXISTS tgf_item_tc_ai( ) CASCADE; +CREATE FUNCTION tgf_item_tc_ai( ) + RETURNS TRIGGER + LANGUAGE PLPGSQL + SECURITY DEFINER + AS $tgf_item_tc_ai$ +BEGIN + INSERT INTO task_containers ( item_id ) + VALUES ( NEW.item_id ); + RETURN NEW; +END; +$tgf_item_tc_ai$; + +REVOKE EXECUTE ON FUNCTION tgf_item_tc_ai( ) FROM PUBLIC; + +CREATE TRIGGER tg_item_tc_ai AFTER INSERT ON items + FOR EACH ROW EXECUTE PROCEDURE tgf_item_tc_ai( ); + + +DROP FUNCTION IF EXISTS tgf_task_tc_ai( ) CASCADE; +CREATE FUNCTION tgf_task_tc_ai( ) + RETURNS TRIGGER + LANGUAGE PLPGSQL + SECURITY DEFINER + AS $tgf_task_tc_ai$ +BEGIN + INSERT INTO task_containers ( task_id ) + VALUES ( NEW.task_id ); + INSERT INTO logical_task_containers ( task_id ) + VALUES ( NEW.task_id ); + RETURN NEW; +END; +$tgf_task_tc_ai$; + +REVOKE EXECUTE ON FUNCTION tgf_task_tc_ai( ) FROM PUBLIC; + +CREATE TRIGGER tg_task_tc_ai AFTER INSERT ON tasks + FOR EACH ROW EXECUTE PROCEDURE tgf_task_tc_ai( ); diff --git a/database/task-dependencies.sql b/database/task-dependencies.sql index 312139b..14012dd 100644 --- a/database/task-dependencies.sql +++ b/database/task-dependencies.sql @@ -252,12 +252,15 @@ REVOKE EXECUTE ON FUNCTION tgf_taskdep_bi() FROM PUBLIC; -- -- List all dependencies that can be added to a task. -- -CREATE OR REPLACE FUNCTION tasks_possible_dependencies( o_id INT ) +DROP FUNCTION IF EXISTS tasks_possible_dependencies( INT ); +CREATE FUNCTION tasks_possible_dependencies( o_id INT ) RETURNS SETOF tasks STRICT STABLE AS $tasks_possible_dependencies$ - SELECT * FROM tasks - WHERE task_id NOT IN ( + SELECT t.* + FROM tasks t + INNER JOIN tasks t2 USING ( ltc_id ) + WHERE t2.task_id = $1 AND t.task_id NOT IN ( SELECT d.task_id_depends AS id FROM taskdep_nodes n1 INNER JOIN task_dependencies d @@ -281,18 +284,28 @@ GRANT EXECUTE ON FUNCTION tasks_possible_dependencies( INT ) TO :webapp_user; -- -- Add a dependency -- -CREATE OR REPLACE FUNCTION tasks_add_dependency( t_id INT , t_dependency INT ) +DROP FUNCTION IF EXISTS tasks_add_dependency( INT , INT ); +CREATE FUNCTION tasks_add_dependency( t_id INT , t_dependency INT ) RETURNS INT STRICT VOLATILE SECURITY INVOKER AS $tasks_add_dependency$ + +DECLARE + ltc INT; + BEGIN - INSERT INTO task_dependencies( task_id , task_id_depends ) - VALUES ( t_id , t_dependency ); + SELECT INTO ltc ltc_id FROM tasks WHERE task_id = t_id; + IF NOT FOUND THEN + RETURN 1; + END IF; + + INSERT INTO task_dependencies( ltc_id , task_id , task_id_depends ) + VALUES ( ltc , t_id , t_dependency ); RETURN 0; EXCEPTION WHEN foreign_key_violation THEN - RETURN 1; + RETURN 3; WHEN check_violation THEN RETURN 2; END; diff --git a/database/tasks-functions.sql b/database/tasks-functions.sql index df9ea6a..7c9abf0 100644 --- a/database/tasks-functions.sql +++ b/database/tasks-functions.sql @@ -1,29 +1,109 @@ -- Create a new task -CREATE OR REPLACE FUNCTION add_task( t_item INT , t_title TEXT , t_description TEXT , t_priority INT , t_user INT ) +DROP FUNCTION IF EXISTS add_task( INT , TEXT , TEXT , INT , INT ) CASCADE; +CREATE FUNCTION add_task( t_item INT , t_title TEXT , t_description TEXT , t_priority INT , t_user INT ) RETURNS INT STRICT VOLATILE SECURITY INVOKER AS $add_task$ +DECLARE + _container INT; + _logical_container INT; BEGIN - INSERT INTO tasks ( item_id , task_title , task_description , task_priority , user_id ) - VALUES ( t_item , t_title , t_description , t_priority , t_user ); + SELECT INTO _container tc_id + FROM task_containers + WHERE item_id = t_item; + IF NOT FOUND THEN + RETURN 2; + END IF; + + SELECT INTO _logical_container ltc_id + FROM logical_task_containers + WHERE task_id IS NULL; + + INSERT INTO tasks ( tc_id , ltc_id , task_title , task_description , task_priority , user_id ) + VALUES ( _container , _logical_container , t_title , t_description , t_priority , t_user ); RETURN 0; EXCEPTION WHEN unique_violation THEN RETURN 1; - WHEN foreign_key_violation THEN - RETURN 2; END; $add_task$ LANGUAGE plpgsql; +REVOKE EXECUTE ON FUNCTION add_task( INT , TEXT , TEXT , INT , INT ) FROM PUBLIC; +GRANT EXECUTE ON FUNCTION add_task( INT , TEXT , TEXT , INT , INT ) TO :webapp_user; + +-- Create a new nested task +DROP FUNCTION IF EXISTS tasks_add_nested( INT , TEXT , TEXT , INT , INT ) CASCADE; +CREATE FUNCTION tasks_add_nested( t_parent INT , t_title TEXT , t_description TEXT , t_priority INT , t_user INT ) + RETURNS INT + STRICT VOLATILE + SECURITY INVOKER + AS $tasks_add_nested$ +DECLARE + _container INT; + _logical_container INT; +BEGIN + SELECT INTO _container tc.tc_id + FROM task_containers tc + INNER JOIN tasks t USING ( task_id ) + LEFT OUTER JOIN completed_tasks ct USING ( task_id ) + WHERE t.task_id = t_parent AND ct.task_id IS NULL; + IF NOT FOUND THEN + RETURN 2; + END IF; + + SELECT INTO _logical_container ltc_id + FROM logical_task_containers + WHERE task_id = t_parent; + + INSERT INTO tasks ( tc_id , ltc_id , task_title , task_description , task_priority , user_id ) + VALUES ( _container , _logical_container , t_title , t_description , t_priority , t_user ); + RETURN 0; +EXCEPTION + WHEN unique_violation THEN + RETURN 1; +END; +$tasks_add_nested$ LANGUAGE plpgsql; + +REVOKE EXECUTE ON FUNCTION tasks_add_nested( INT , TEXT , TEXT , INT , INT ) FROM PUBLIC; +GRANT EXECUTE ON FUNCTION tasks_add_nested( INT , TEXT , TEXT , INT , INT ) TO :webapp_user; + -- Mark a task as finished -CREATE OR REPLACE FUNCTION finish_task( t_id INT , u_id INT , n_text TEXT ) +DROP FUNCTION IF EXISTS finish_task( INT , INT , TEXT ); +CREATE FUNCTION finish_task( t_id INT , u_id INT , n_text TEXT ) RETURNS INT STRICT VOLATILE SECURITY INVOKER AS $finish_task$ BEGIN + PERFORM 1 + FROM tasks t + LEFT OUTER JOIN ( + SELECT ltc.task_id , COUNT( * ) AS c + FROM logical_task_containers ltc + INNER JOIN tasks t + USING ( ltc_id ) + LEFT OUTER JOIN completed_tasks ct + ON ct.task_id = t.task_id + WHERE ltc.task_id = t_id + AND ct.task_id IS NULL + GROUP BY ltc.task_id + ) s1 USING ( task_id ) + LEFT OUTER JOIN ( + SELECT td.task_id , COUNT( * ) AS c + FROM task_dependencies td + LEFT OUTER JOIN completed_tasks ct + ON ct.task_id = td.task_id_depends + WHERE td.task_id = t_id + AND ct.task_id IS NULL + GROUP BY td.task_id + ) s2 USING ( task_id ) + WHERE task_id = t_id AND s1.c IS NULL AND s2.c IS NULL; + IF NOT FOUND THEN + RETURN 2; + END IF; + BEGIN INSERT INTO completed_tasks ( task_id , user_id ) VALUES ( t_id , u_id ); @@ -45,12 +125,33 @@ GRANT EXECUTE ON FUNCTION finish_task( INT , INT , TEXT ) TO :webapp_user; -- Restart a task -CREATE OR REPLACE FUNCTION restart_task( t_id INT , u_id INT , n_text TEXT ) +DROP FUNCTION IF EXISTS restart_task( INT , INT , TEXT ); +CREATE FUNCTION restart_task( t_id INT , u_id INT , n_text TEXT ) RETURNS INT STRICT VOLATILE SECURITY INVOKER AS $restart_task$ BEGIN + PERFORM 1 + FROM tasks t + INNER JOIN logical_task_containers ltc + USING ( ltc_id ) + INNER JOIN completed_tasks ct + ON ct.task_id = ltc.task_id + WHERE t.task_id = t_id; + IF FOUND THEN + RETURN 2; + END IF; + + PERFORM 1 + FROM task_dependencies td + INNER JOIN completed_tasks ct + USING ( task_id ) + WHERE td.task_id_depends = t_id; + IF FOUND THEN + RETURN 2; + END IF; + DELETE FROM completed_tasks WHERE task_id = t_id; IF NOT FOUND THEN RETURN 1; @@ -68,7 +169,62 @@ GRANT EXECUTE ON FUNCTION restart_task( INT , INT , TEXT ) TO :webapp_user; -- Update a task -CREATE OR REPLACE FUNCTION update_task( t_id INT , p_id INT , t_title TEXT , t_description TEXT , t_priority INT , t_assignee INT ) +DROP FUNCTION IF EXISTS update_task( INT , INT , TEXT , TEXT , INT , INT ); +CREATE FUNCTION update_task( t_id INT , p_id INT , t_title TEXT , t_description TEXT , t_priority INT , t_assignee INT ) + RETURNS INT + STRICT VOLATILE + SECURITY INVOKER + AS $update_task$ + +DECLARE + tc INT; + +BEGIN + PERFORM 1 + FROM tasks + INNER JOIN logical_task_containers + USING ( ltc_id ) + LEFT OUTER JOIN completed_tasks + ON tasks.task_id = completed_tasks.task_id + WHERE tasks.task_id = t_id + AND logical_task_containers.task_id IS NULL + AND completed_task_time IS NULL + FOR UPDATE OF tasks; + IF NOT FOUND THEN + RETURN 4; + END IF; + + SELECT INTO tc tc_id FROM task_containers + WHERE item_id = p_id; + IF NOT FOUND THEN + RETURN 2; + END IF; + + IF t_assignee = 0 THEN + t_assignee := NULL; + END IF; + UPDATE tasks SET tc_id = tc , task_title = t_title , + task_description = t_description , + task_priority = t_priority , + user_id_assigned = t_assignee + WHERE task_id = t_id; + + RETURN 0; +EXCEPTION + WHEN unique_violation THEN + RETURN 1; + WHEN foreign_key_violation THEN + RETURN 3; +END; +$update_task$ LANGUAGE plpgsql; + +REVOKE EXECUTE ON FUNCTION update_task( INT , INT , TEXT , TEXT , INT , INT ) FROM PUBLIC; +GRANT EXECUTE ON FUNCTION update_task( INT , INT , TEXT , TEXT , INT , INT ) TO :webapp_user; + + +-- Update a nested task +DROP FUNCTION IF EXISTS update_task( INT , TEXT , TEXT , INT , INT ); +CREATE FUNCTION update_task( t_id INT , t_title TEXT , t_description TEXT , t_priority INT , t_assignee INT ) RETURNS INT STRICT VOLATILE SECURITY INVOKER @@ -76,41 +232,35 @@ CREATE OR REPLACE FUNCTION update_task( t_id INT , p_id INT , t_title TEXT , t_d BEGIN PERFORM 1 FROM tasks + INNER JOIN logical_task_containers + USING ( ltc_id ) LEFT OUTER JOIN completed_tasks - USING( task_id ) - WHERE task_id = t_id AND completed_task_time IS NULL + ON tasks.task_id = completed_tasks.task_id + WHERE tasks.task_id = t_id + AND logical_task_containers.task_id IS NOT NULL + AND completed_task_time IS NULL FOR UPDATE OF tasks; IF NOT FOUND THEN RETURN 4; END IF; - BEGIN - IF t_assignee <= 0 THEN - t_assignee := NULL; - END IF; - BEGIN - UPDATE tasks SET user_id_assigned = t_assignee WHERE task_id = t_id; - EXCEPTION - WHEN foreign_key_violation THEN - RAISE EXCEPTION 'bad user'; - END; - UPDATE tasks SET item_id = p_id , task_title = t_title , - task_description = t_description , - task_priority = t_priority - WHERE task_id = t_id; - EXCEPTION - WHEN unique_violation THEN - RETURN 1; - WHEN foreign_key_violation THEN - RETURN 2; - WHEN raise_exception THEN - RETURN 3; - END; - + IF t_assignee = 0 THEN + t_assignee := NULL; + END IF; + UPDATE tasks + SET task_title = t_title , + task_description = t_description , + task_priority = t_priority , + user_id_assigned = t_assignee + WHERE task_id = t_id; RETURN 0; +EXCEPTION + WHEN unique_violation THEN + RETURN 1; + WHEN foreign_key_violation THEN + RETURN 2; END; $update_task$ LANGUAGE plpgsql; - -REVOKE EXECUTE ON FUNCTION update_task( INT , INT , TEXT , TEXT , INT , INT ) FROM PUBLIC; -GRANT EXECUTE ON FUNCTION update_task( INT , INT , TEXT , TEXT , INT , INT ) TO :webapp_user; +REVOKE EXECUTE ON FUNCTION update_task( INT , TEXT , TEXT , INT , INT ) FROM PUBLIC; +GRANT EXECUTE ON FUNCTION update_task( INT , TEXT , TEXT , INT , INT ) TO :webapp_user; diff --git a/database/tasks-move-sub.sql b/database/tasks-move-sub.sql new file mode 100644 index 0000000..90bd5e3 --- /dev/null +++ b/database/tasks-move-sub.sql @@ -0,0 +1,148 @@ +/* + * View that represents possible "move down" targets for a task + */ +DROP VIEW IF EXISTS tasks_move_down_targets; +CREATE VIEW tasks_move_down_targets + AS SELECT t.task_id , tgt.task_id AS target_id , tgt.task_title AS target_title + FROM tasks t + LEFT OUTER JOIN completed_tasks tct + USING ( task_id ) + INNER JOIN tasks tgt + USING ( ltc_id ) + INNER JOIN logical_task_containers ltc + ON ltc.task_id = tgt.task_id + LEFT OUTER JOIN tasks tsubs + ON tsubs.ltc_id = ltc.ltc_id + AND LOWER( tsubs.task_title ) = LOWER( t.task_title ) + LEFT OUTER JOIN completed_tasks csubs + ON csubs.task_id = tgt.task_id + WHERE tgt.task_id <> t.task_id + AND tsubs.task_id IS NULL + AND tct.task_id IS NULL + AND csubs.task_id IS NULL; + +GRANT SELECT ON tasks_move_down_targets TO :webapp_user; + + +/* + * View that represents all tasks which can be moved up one level + */ +DROP VIEW IF EXISTS tasks_can_move_up CASCADE; +CREATE VIEW tasks_can_move_up + AS SELECT t.task_id + FROM tasks t + LEFT OUTER JOIN completed_tasks tct + USING ( task_id ) + INNER JOIN logical_task_containers ptc + USING ( ltc_id ) + INNER JOIN tasks tgt + ON tgt.task_id = ptc.task_id + LEFT OUTER JOIN tasks psubs + ON psubs.ltc_id = tgt.ltc_id + AND LOWER( psubs.task_title ) = LOWER( t.task_title ) + WHERE tct IS NULL + AND psubs IS NULL; + + + +/* + * Move the task to its grand-parent, if: + * - there are no dependencies and reverse dependencies, + * - or the _force parameter is true. + */ +DROP FUNCTION IF EXISTS tasks_move_up( _task INT , _force BOOLEAN ); +CREATE FUNCTION tasks_move_up( _task INT , _force BOOLEAN ) + RETURNS BOOLEAN + LANGUAGE PLPGSQL + STRICT VOLATILE + SECURITY DEFINER + AS $tasks_move_up$ + +DECLARE + _gp_container INT; + _gp_lcontainer INT; + +BEGIN + PERFORM 1 FROM tasks_can_move_up WHERE task_id = _task; + IF NOT FOUND THEN + RETURN FALSE; + END IF; + + PERFORM 1 FROM task_dependencies + WHERE ( task_id = _task OR task_id_depends = _task ) AND NOT _force; + IF FOUND THEN + RETURN FALSE; + END IF; + + SELECT INTO _gp_container , _gp_lcontainer + gp.tc_id , gp.ltc_id + FROM tasks t + INNER JOIN logical_task_containers lt + USING ( ltc_id ) + INNER JOIN tasks gp + ON gp.task_id = lt.task_id + WHERE t.task_id = _task; + + DELETE FROM task_dependencies + WHERE task_id = _task OR task_id_depends = _task; + UPDATE tasks + SET tc_id = _gp_container , + ltc_id = _gp_lcontainer + WHERE task_id = _task; + RETURN TRUE; +END; +$tasks_move_up$; + +REVOKE EXECUTE ON FUNCTION tasks_move_up( INT , BOOLEAN ) FROM PUBLIC; +GRANT EXECUTE ON FUNCTION tasks_move_up( INT , BOOLEAN ) TO :webapp_user; + + +/* + * Move the task into one of its siblings, if: + * - there are no dependencies and reverse dependencies, + * - or the _force parameter is true. + */ +DROP FUNCTION IF EXISTS tasks_move_down( _task INT , _sibling INT , _force BOOLEAN ); +CREATE FUNCTION tasks_move_down( _task INT , _sibling INT , _force BOOLEAN ) + RETURNS BOOLEAN + LANGUAGE PLPGSQL + STRICT VOLATILE + SECURITY DEFINER + AS $tasks_move_down$ + +DECLARE + _s_container INT; + _s_lcontainer INT; + +BEGIN + PERFORM 1 FROM tasks_move_down_targets + WHERE task_id = _task AND target_id = _sibling; + IF NOT FOUND THEN + RETURN FALSE; + END IF; + + PERFORM 1 FROM task_dependencies + WHERE ( task_id = _task OR task_id_depends = _task ) AND NOT _force; + IF FOUND THEN + RETURN FALSE; + END IF; + + SELECT INTO _s_container tc_id + FROM task_containers + WHERE task_id = _sibling; + SELECT INTO _s_lcontainer ltc_id + FROM logical_task_containers + WHERE task_id = _sibling; + + DELETE FROM task_dependencies + WHERE task_id = _task OR task_id_depends = _task; + UPDATE tasks + SET tc_id = _s_container , + ltc_id = _s_lcontainer + WHERE task_id = _task; + RETURN TRUE; +END; +$tasks_move_down$; + +REVOKE EXECUTE ON FUNCTION tasks_move_down( INT , INT , BOOLEAN ) FROM PUBLIC; +GRANT EXECUTE ON FUNCTION tasks_move_down( INT , INT , BOOLEAN ) TO :webapp_user; diff --git a/database/tasks-view.sql b/database/tasks-view.sql index 7afb61a..f7e7595 100644 --- a/database/tasks-view.sql +++ b/database/tasks-view.sql @@ -1,3 +1,29 @@ +/* + * Task view + * + * This view is used by the application when loading individual tasks. + */ +DROP VIEW IF EXISTS tasks_single_view; +CREATE VIEW tasks_single_view + AS SELECT t.task_id AS id, t.task_title AS title, tc.item_id AS item , tc.task_id AS parent_task , + t.task_description AS description, t.task_added AS added_at, + u1.user_view_name AS added_by, ct.completed_task_time AS completed_at, + u2.user_view_name AS assigned_to , u2.user_id AS assigned_id , + u3.user_view_name AS completed_by, t.user_id AS uid , + t.task_priority AS priority , + ( cmu IS NOT NULL ) AS can_move_up + FROM tasks t + INNER JOIN task_containers tc USING ( tc_id ) + INNER JOIN users_view u1 ON u1.user_id = t.user_id + LEFT OUTER JOIN completed_tasks ct ON ct.task_id = t.task_id + LEFT OUTER JOIN users_view u2 ON u2.user_id = t.user_id_assigned + LEFT OUTER JOIN users_view u3 ON u3.user_id = ct.user_id + LEFT OUTER JOIN tasks_can_move_up cmu ON cmu.task_id = t.task_id; + +GRANT SELECT ON tasks_single_view TO :webapp_user; + + + -- -- Task list view -- @@ -6,7 +32,8 @@ DROP VIEW IF EXISTS tasks_list; CREATE VIEW tasks_list - AS SELECT t.task_id AS id, t.item_id AS item, t.task_title AS title, + AS SELECT t.task_id AS id, tc.item_id AS item , tc.task_id AS parent_task , + t.task_title AS title, t.task_description AS description, t.task_added AS added_at, u1.user_view_name AS added_by, ct.completed_task_time AS completed_at, @@ -15,8 +42,19 @@ CREATE VIEW tasks_list u3.user_view_name AS completed_by , t.task_priority AS priority , bd.bad_deps AS missing_dependencies , - mtd.trans_missing AS total_missing_dependencies + bc.bad_children AS missing_subtasks , + ( CASE + WHEN mtd.trans_missing IS NULL AND bc.bad_children IS NULL THEN + NULL::BIGINT + WHEN mtd.trans_missing IS NULL THEN + bc.bad_children + WHEN bc.bad_children IS NULL THEN + mtd.trans_missing + ELSE + bc.bad_children + mtd.trans_missing + END ) AS total_missing_dependencies FROM tasks t + INNER JOIN task_containers tc USING( tc_id ) INNER JOIN users_view u1 ON u1.user_id = t.user_id LEFT OUTER JOIN completed_tasks ct ON ct.task_id = t.task_id LEFT OUTER JOIN users_view u2 ON u2.user_id = t.user_id_assigned @@ -29,6 +67,16 @@ CREATE VIEW tasks_list WHERE dct.task_id IS NULL GROUP BY td.task_id ) AS bd ON bd.task_id = t.task_id + LEFT OUTER JOIN ( + SELECT ltc.task_id , COUNT( * ) AS bad_children + FROM logical_task_containers ltc + INNER JOIN tasks t + USING ( ltc_id ) + LEFT OUTER JOIN completed_tasks ct + ON ct.task_id = t.task_id + WHERE ct.task_id IS NULL + GROUP BY ltc.task_id + ) AS bc ON bc.task_id = t.task_id LEFT OUTER JOIN ( SELECT tdn.task_id , COUNT( DISTINCT task_id_copyof ) AS trans_missing FROM taskdep_nodes tdn diff --git a/database/upgrade/from-49cc53e31f80084bd5f530f0f37d6f8d219ea3b0.sql b/database/upgrade/from-49cc53e31f80084bd5f530f0f37d6f8d219ea3b0.sql new file mode 100644 index 0000000..98c1a23 --- /dev/null +++ b/database/upgrade/from-49cc53e31f80084bd5f530f0f37d6f8d219ea3b0.sql @@ -0,0 +1,612 @@ +-- +-- Upgrade the database from commit ID 49cc53e31f80084bd5f530f0f37d6f8d219ea3b0 +-- +-- Run this from the top-level directory +-- + +\i database/config.sql +\c :db_name + +BEGIN; + + CREATE TABLE task_containers ( + tc_id SERIAL NOT NULL PRIMARY KEY , + task_id INT UNIQUE , + item_id INT UNIQUE , + CHECK( task_id IS NULL AND item_id IS NOT NULL OR task_id IS NOT NULL AND item_id IS NULL ) + ); + GRANT SELECT ON task_containers TO :webapp_user; + ALTER TABLE task_containers + ADD FOREIGN KEY ( item_id ) REFERENCES items( item_id ) + ON UPDATE NO ACTION + ON DELETE CASCADE , + ADD FOREIGN KEY ( task_id ) REFERENCES tasks( task_id ) + ON UPDATE NO ACTION + ON DELETE CASCADE; + INSERT INTO task_containers ( item_id ) + SELECT item_id FROM items; + INSERT INTO task_containers ( task_id ) + SELECT task_id FROM tasks; + + CREATE TABLE logical_task_containers( + ltc_id SERIAL NOT NULL PRIMARY KEY , + task_id INT UNIQUE , + CHECK( ltc_id = 1 AND task_id IS NULL OR ltc_id <> 1 AND task_id IS NOT NULL ) + ); + INSERT INTO logical_task_containers DEFAULT VALUES; + ALTER TABLE logical_task_containers + ADD FOREIGN KEY ( task_id ) REFERENCES tasks( task_id ) + ON UPDATE NO ACTION + ON DELETE CASCADE; + GRANT SELECT ON logical_task_containers TO :webapp_user; + INSERT INTO logical_task_containers (task_id) + SELECT task_id FROM tasks; + + ALTER TABLE tasks + ADD tc_id INT , + ADD ltc_id INT; + UPDATE tasks t + SET ltc_id = 1 , tc_id = tc.tc_id + FROM task_containers tc + WHERE tc.item_id = t.item_id; + ALTER TABLE tasks + ALTER tc_id SET NOT NULL , + ALTER ltc_id SET NOT NULL , + ADD FOREIGN KEY ( tc_id ) REFERENCES task_containers ( tc_id ) + ON UPDATE NO ACTION ON DELETE CASCADE , + ADD FOREIGN KEY ( ltc_id ) REFERENCES logical_task_containers ( ltc_id ) + ON UPDATE NO ACTION ON DELETE CASCADE , + DROP COLUMN item_id CASCADE; + CREATE UNIQUE INDEX i_tasks_title ON tasks (tc_id, task_title); + CREATE UNIQUE INDEX i_tasks_ltc ON tasks (task_id , ltc_id); + + ALTER TABLE task_dependencies ADD ltc_id INT; + UPDATE task_dependencies SET ltc_id = 1; + ALTER TABLE task_dependencies + ALTER ltc_id SET NOT NULL , + DROP CONSTRAINT task_dependencies_task_id_depends_fkey , + DROP CONSTRAINT task_dependencies_task_id_fkey , + ADD CONSTRAINT fk_taskdep_task + FOREIGN KEY ( ltc_id , task_id ) REFERENCES tasks( ltc_id , task_id ) + ON UPDATE NO ACTION ON DELETE CASCADE , + ADD CONSTRAINT fk_taskdep_dependency + FOREIGN KEY ( ltc_id , task_id_depends ) REFERENCES tasks( ltc_id , task_id ) + ON UPDATE NO ACTION ON DELETE CASCADE; + + CREATE FUNCTION tgf_item_tc_ai( ) + RETURNS TRIGGER + LANGUAGE PLPGSQL + SECURITY DEFINER + AS $tgf_item_tc_ai$ + BEGIN + INSERT INTO task_containers ( item_id ) + VALUES ( NEW.item_id ); + RETURN NEW; + END; + $tgf_item_tc_ai$; + REVOKE EXECUTE ON FUNCTION tgf_item_tc_ai( ) FROM PUBLIC; + CREATE TRIGGER tg_item_tc_ai AFTER INSERT ON items + FOR EACH ROW EXECUTE PROCEDURE tgf_item_tc_ai( ); + + CREATE FUNCTION tgf_task_tc_ai( ) + RETURNS TRIGGER + LANGUAGE PLPGSQL + SECURITY DEFINER + AS $tgf_task_tc_ai$ + BEGIN + INSERT INTO task_containers ( task_id ) + VALUES ( NEW.task_id ); + INSERT INTO logical_task_containers ( task_id ) + VALUES ( NEW.task_id ); + RETURN NEW; + END; + $tgf_task_tc_ai$; + REVOKE EXECUTE ON FUNCTION tgf_task_tc_ai( ) FROM PUBLIC; + CREATE TRIGGER tg_task_tc_ai AFTER INSERT ON tasks + FOR EACH ROW EXECUTE PROCEDURE tgf_task_tc_ai( ); + + DROP FUNCTION add_task( INT , TEXT , TEXT , INT , INT ) CASCADE; + CREATE FUNCTION add_task( t_item INT , t_title TEXT , t_description TEXT , t_priority INT , t_user INT ) + RETURNS INT + STRICT VOLATILE + SECURITY INVOKER + AS $add_task$ + DECLARE + _container INT; + _logical_container INT; + BEGIN + SELECT INTO _container tc_id + FROM task_containers + WHERE item_id = t_item; + IF NOT FOUND THEN + RETURN 2; + END IF; + + SELECT INTO _logical_container ltc_id + FROM logical_task_containers + WHERE task_id IS NULL; + + INSERT INTO tasks ( tc_id , ltc_id , task_title , task_description , task_priority , user_id ) + VALUES ( _container , _logical_container , t_title , t_description , t_priority , t_user ); + RETURN 0; + EXCEPTION + WHEN unique_violation THEN + RETURN 1; + END; + $add_task$ LANGUAGE plpgsql; + REVOKE EXECUTE ON FUNCTION add_task( INT , TEXT , TEXT , INT , INT ) FROM PUBLIC; + GRANT EXECUTE ON FUNCTION add_task( INT , TEXT , TEXT , INT , INT ) TO :webapp_user; + + CREATE FUNCTION tasks_add_nested( t_parent INT , t_title TEXT , t_description TEXT , t_priority INT , t_user INT ) + RETURNS INT + STRICT VOLATILE + SECURITY INVOKER + AS $tasks_add_nested$ + DECLARE + _container INT; + _logical_container INT; + BEGIN + SELECT INTO _container tc.tc_id + FROM task_containers tc + INNER JOIN tasks t USING ( task_id ) + LEFT OUTER JOIN completed_tasks ct USING ( task_id ) + WHERE t.task_id = t_parent AND ct.task_id IS NULL; + IF NOT FOUND THEN + RETURN 2; + END IF; + + SELECT INTO _logical_container ltc_id + FROM logical_task_containers + WHERE task_id = t_parent; + + INSERT INTO tasks ( tc_id , ltc_id , task_title , task_description , task_priority , user_id ) + VALUES ( _container , _logical_container , t_title , t_description , t_priority , t_user ); + RETURN 0; + EXCEPTION + WHEN unique_violation THEN + RETURN 1; + END; + $tasks_add_nested$ LANGUAGE plpgsql; + REVOKE EXECUTE ON FUNCTION tasks_add_nested( INT , TEXT , TEXT , INT , INT ) FROM PUBLIC; + GRANT EXECUTE ON FUNCTION tasks_add_nested( INT , TEXT , TEXT , INT , INT ) TO :webapp_user; + + + DROP FUNCTION finish_task( INT , INT , TEXT ); + CREATE FUNCTION finish_task( t_id INT , u_id INT , n_text TEXT ) + RETURNS INT + STRICT VOLATILE + SECURITY INVOKER + AS $finish_task$ + BEGIN + PERFORM 1 + FROM tasks t + LEFT OUTER JOIN ( + SELECT ltc.task_id , COUNT( * ) AS c + FROM logical_task_containers ltc + INNER JOIN tasks t + USING ( ltc_id ) + LEFT OUTER JOIN completed_tasks ct + ON ct.task_id = t.task_id + WHERE ltc.task_id = t_id + AND ct.task_id IS NULL + GROUP BY ltc.task_id + ) s1 USING ( task_id ) + LEFT OUTER JOIN ( + SELECT td.task_id , COUNT( * ) AS c + FROM task_dependencies td + LEFT OUTER JOIN completed_tasks ct + ON ct.task_id = td.task_id_depends + WHERE td.task_id = t_id + AND ct.task_id IS NULL + GROUP BY td.task_id + ) s2 USING ( task_id ) + WHERE task_id = t_id AND s1.c IS NULL AND s2.c IS NULL; + IF NOT FOUND THEN + RETURN 2; + END IF; + + BEGIN + INSERT INTO completed_tasks ( task_id , user_id ) + VALUES ( t_id , u_id ); + EXCEPTION + WHEN unique_violation THEN + RETURN 1; + END; + + UPDATE tasks SET user_id_assigned = NULL WHERE task_id = t_id; + + INSERT INTO notes ( task_id , user_id , note_text ) + VALUES ( t_id , u_id , n_text ); + RETURN 0; + END; + $finish_task$ LANGUAGE plpgsql; + REVOKE EXECUTE ON FUNCTION finish_task( INT , INT , TEXT ) FROM PUBLIC; + GRANT EXECUTE ON FUNCTION finish_task( INT , INT , TEXT ) TO :webapp_user; + + DROP FUNCTION restart_task( INT , INT , TEXT ); + CREATE FUNCTION restart_task( t_id INT , u_id INT , n_text TEXT ) + RETURNS INT + STRICT VOLATILE + SECURITY INVOKER + AS $restart_task$ + BEGIN + PERFORM 1 + FROM tasks t + INNER JOIN logical_task_containers ltc + USING ( ltc_id ) + INNER JOIN completed_tasks ct + ON ct.task_id = ltc.task_id + WHERE t.task_id = t_id; + IF FOUND THEN + RETURN 2; + END IF; + + PERFORM 1 + FROM task_dependencies td + INNER JOIN completed_tasks ct + USING ( task_id ) + WHERE td.task_id_depends = t_id; + IF FOUND THEN + RETURN 2; + END IF; + + DELETE FROM completed_tasks WHERE task_id = t_id; + IF NOT FOUND THEN + RETURN 1; + END IF; + UPDATE tasks SET user_id_assigned = u_id + WHERE task_id = t_id; + INSERT INTO notes ( task_id , user_id , note_text ) + VALUES ( t_id , u_id , n_text ); + RETURN 0; + END; + $restart_task$ LANGUAGE plpgsql; + REVOKE EXECUTE ON FUNCTION restart_task( INT , INT , TEXT ) FROM PUBLIC; + GRANT EXECUTE ON FUNCTION restart_task( INT , INT , TEXT ) TO :webapp_user; + + DROP FUNCTION update_task( INT , INT , TEXT , TEXT , INT , INT ); + CREATE FUNCTION update_task( t_id INT , p_id INT , t_title TEXT , t_description TEXT , t_priority INT , t_assignee INT ) + RETURNS INT + STRICT VOLATILE + SECURITY INVOKER + AS $update_task$ + + DECLARE + tc INT; + + BEGIN + PERFORM 1 + FROM tasks + INNER JOIN logical_task_containers + USING ( ltc_id ) + LEFT OUTER JOIN completed_tasks + ON tasks.task_id = completed_tasks.task_id + WHERE tasks.task_id = t_id + AND logical_task_containers.task_id IS NULL + AND completed_task_time IS NULL + FOR UPDATE OF tasks; + IF NOT FOUND THEN + RETURN 4; + END IF; + + SELECT INTO tc tc_id FROM task_containers + WHERE item_id = p_id; + IF NOT FOUND THEN + RETURN 2; + END IF; + + IF t_assignee = 0 THEN + t_assignee := NULL; + END IF; + UPDATE tasks SET tc_id = tc , task_title = t_title , + task_description = t_description , + task_priority = t_priority , + user_id_assigned = t_assignee + WHERE task_id = t_id; + + RETURN 0; + EXCEPTION + WHEN unique_violation THEN + RETURN 1; + WHEN foreign_key_violation THEN + RETURN 3; + END; + $update_task$ LANGUAGE plpgsql; + REVOKE EXECUTE ON FUNCTION update_task( INT , INT , TEXT , TEXT , INT , INT ) FROM PUBLIC; + GRANT EXECUTE ON FUNCTION update_task( INT , INT , TEXT , TEXT , INT , INT ) TO :webapp_user; + + + -- Update a nested task + CREATE FUNCTION update_task( t_id INT , t_title TEXT , t_description TEXT , t_priority INT , t_assignee INT ) + RETURNS INT + STRICT VOLATILE + SECURITY INVOKER + AS $update_task$ + BEGIN + PERFORM 1 + FROM tasks + INNER JOIN logical_task_containers + USING ( ltc_id ) + LEFT OUTER JOIN completed_tasks + ON tasks.task_id = completed_tasks.task_id + WHERE tasks.task_id = t_id + AND logical_task_containers.task_id IS NOT NULL + AND completed_task_time IS NULL + FOR UPDATE OF tasks; + IF NOT FOUND THEN + RETURN 4; + END IF; + + IF t_assignee = 0 THEN + t_assignee := NULL; + END IF; + UPDATE tasks + SET task_title = t_title , + task_description = t_description , + task_priority = t_priority , + user_id_assigned = t_assignee + WHERE task_id = t_id; + RETURN 0; + EXCEPTION + WHEN unique_violation THEN + RETURN 1; + WHEN foreign_key_violation THEN + RETURN 2; + END; + $update_task$ LANGUAGE plpgsql; + REVOKE EXECUTE ON FUNCTION update_task( INT , TEXT , TEXT , INT , INT ) FROM PUBLIC; + GRANT EXECUTE ON FUNCTION update_task( INT , TEXT , TEXT , INT , INT ) TO :webapp_user; + + DROP FUNCTION tasks_possible_dependencies( INT ); + CREATE FUNCTION tasks_possible_dependencies( o_id INT ) + RETURNS SETOF tasks + STRICT STABLE + AS $tasks_possible_dependencies$ + SELECT t.* + FROM tasks t + INNER JOIN tasks t2 USING ( ltc_id ) + WHERE t2.task_id = $1 AND t.task_id NOT IN ( + SELECT d.task_id_depends AS id + FROM taskdep_nodes n1 + INNER JOIN task_dependencies d + ON d.task_id = n1.task_id_copyof + WHERE n1.task_id = $1 AND n1.tnode_reverse + UNION ALL SELECT n.task_id_copyof AS id + FROM task_dependencies d1 + INNER JOIN taskdep_nodes n + ON n.task_id = d1.task_id_depends + WHERE d1.task_id = $1 AND n.tnode_reverse + UNION ALL SELECT task_id_copyof AS id + FROM taskdep_nodes + WHERE task_id = $1 + ); + $tasks_possible_dependencies$ LANGUAGE sql; + REVOKE EXECUTE ON FUNCTION tasks_possible_dependencies( INT ) FROM PUBLIC; + GRANT EXECUTE ON FUNCTION tasks_possible_dependencies( INT ) TO :webapp_user; + + DROP FUNCTION tasks_add_dependency( INT , INT ); + CREATE FUNCTION tasks_add_dependency( t_id INT , t_dependency INT ) + RETURNS INT + STRICT VOLATILE + SECURITY INVOKER + AS $tasks_add_dependency$ + + DECLARE + ltc INT; + + BEGIN + SELECT INTO ltc ltc_id FROM tasks WHERE task_id = t_id; + IF NOT FOUND THEN + RETURN 1; + END IF; + + INSERT INTO task_dependencies( ltc_id , task_id , task_id_depends ) + VALUES ( ltc , t_id , t_dependency ); + RETURN 0; + EXCEPTION + WHEN foreign_key_violation THEN + RETURN 3; + WHEN check_violation THEN + RETURN 2; + END; + $tasks_add_dependency$ LANGUAGE plpgsql; + REVOKE EXECUTE ON FUNCTION tasks_add_dependency( INT , INT ) FROM PUBLIC; + GRANT EXECUTE ON FUNCTION tasks_add_dependency( INT , INT ) TO :webapp_user; + + CREATE VIEW tasks_move_down_targets + AS SELECT t.task_id , tgt.task_id AS target_id , tgt.task_title AS target_title + FROM tasks t + LEFT OUTER JOIN completed_tasks tct + USING ( task_id ) + INNER JOIN tasks tgt + USING ( ltc_id ) + INNER JOIN logical_task_containers ltc + ON ltc.task_id = tgt.task_id + LEFT OUTER JOIN tasks tsubs + ON tsubs.ltc_id = ltc.ltc_id + AND LOWER( tsubs.task_title ) = LOWER( t.task_title ) + LEFT OUTER JOIN completed_tasks csubs + ON csubs.task_id = tgt.task_id + WHERE tgt.task_id <> t.task_id + AND tsubs.task_id IS NULL + AND tct.task_id IS NULL + AND csubs.task_id IS NULL; + GRANT SELECT ON tasks_move_down_targets TO :webapp_user; + CREATE VIEW tasks_can_move_up + AS SELECT t.task_id + FROM tasks t + LEFT OUTER JOIN completed_tasks tct + USING ( task_id ) + INNER JOIN logical_task_containers ptc + USING ( ltc_id ) + INNER JOIN tasks tgt + ON tgt.task_id = ptc.task_id + LEFT OUTER JOIN tasks psubs + ON psubs.ltc_id = tgt.ltc_id + AND LOWER( psubs.task_title ) = LOWER( t.task_title ) + WHERE tct IS NULL + AND psubs IS NULL; + + CREATE FUNCTION tasks_move_up( _task INT , _force BOOLEAN ) + RETURNS BOOLEAN + LANGUAGE PLPGSQL + STRICT VOLATILE + SECURITY DEFINER + AS $tasks_move_up$ + + DECLARE + _gp_container INT; + _gp_lcontainer INT; + + BEGIN + PERFORM 1 FROM tasks_can_move_up WHERE task_id = _task; + IF NOT FOUND THEN + RETURN FALSE; + END IF; + + PERFORM 1 FROM task_dependencies + WHERE ( task_id = _task OR task_id_depends = _task ) AND NOT _force; + IF FOUND THEN + RETURN FALSE; + END IF; + + SELECT INTO _gp_container , _gp_lcontainer + gp.tc_id , gp.ltc_id + FROM tasks t + INNER JOIN logical_task_containers lt + USING ( ltc_id ) + INNER JOIN tasks gp + ON gp.task_id = lt.task_id + WHERE t.task_id = _task; + + DELETE FROM task_dependencies + WHERE task_id = _task OR task_id_depends = _task; + UPDATE tasks + SET tc_id = _gp_container , + ltc_id = _gp_lcontainer + WHERE task_id = _task; + RETURN TRUE; + END; + $tasks_move_up$; + REVOKE EXECUTE ON FUNCTION tasks_move_up( INT , BOOLEAN ) FROM PUBLIC; + GRANT EXECUTE ON FUNCTION tasks_move_up( INT , BOOLEAN ) TO :webapp_user; + + CREATE FUNCTION tasks_move_down( _task INT , _sibling INT , _force BOOLEAN ) + RETURNS BOOLEAN + LANGUAGE PLPGSQL + STRICT VOLATILE + SECURITY DEFINER + AS $tasks_move_down$ + + DECLARE + _s_container INT; + _s_lcontainer INT; + + BEGIN + PERFORM 1 FROM tasks_move_down_targets + WHERE task_id = _task AND target_id = _sibling; + IF NOT FOUND THEN + RETURN FALSE; + END IF; + + PERFORM 1 FROM task_dependencies + WHERE ( task_id = _task OR task_id_depends = _task ) AND NOT _force; + IF FOUND THEN + RETURN FALSE; + END IF; + + SELECT INTO _s_container tc_id + FROM task_containers + WHERE task_id = _sibling; + SELECT INTO _s_lcontainer ltc_id + FROM logical_task_containers + WHERE task_id = _sibling; + + DELETE FROM task_dependencies + WHERE task_id = _task OR task_id_depends = _task; + UPDATE tasks + SET tc_id = _s_container , + ltc_id = _s_lcontainer + WHERE task_id = _task; + RETURN TRUE; + END; + $tasks_move_down$; + REVOKE EXECUTE ON FUNCTION tasks_move_down( INT , INT , BOOLEAN ) FROM PUBLIC; + GRANT EXECUTE ON FUNCTION tasks_move_down( INT , INT , BOOLEAN ) TO :webapp_user; + + CREATE VIEW tasks_single_view + AS SELECT t.task_id AS id, t.task_title AS title, tc.item_id AS item , tc.task_id AS parent_task , + t.task_description AS description, t.task_added AS added_at, + u1.user_view_name AS added_by, ct.completed_task_time AS completed_at, + u2.user_view_name AS assigned_to , u2.user_id AS assigned_id , + u3.user_view_name AS completed_by, t.user_id AS uid , + t.task_priority AS priority , + ( cmu IS NOT NULL ) AS can_move_up + FROM tasks t + INNER JOIN task_containers tc USING ( tc_id ) + INNER JOIN users_view u1 ON u1.user_id = t.user_id + LEFT OUTER JOIN completed_tasks ct ON ct.task_id = t.task_id + LEFT OUTER JOIN users_view u2 ON u2.user_id = t.user_id_assigned + LEFT OUTER JOIN users_view u3 ON u3.user_id = ct.user_id + LEFT OUTER JOIN tasks_can_move_up cmu ON cmu.task_id = t.task_id; + GRANT SELECT ON tasks_single_view TO :webapp_user; + + CREATE VIEW tasks_list + AS SELECT t.task_id AS id, tc.item_id AS item , tc.task_id AS parent_task , + t.task_title AS title, + t.task_description AS description, t.task_added AS added_at, + u1.user_view_name AS added_by, + ct.completed_task_time AS completed_at, + u2.user_view_name AS assigned_to , + u2.user_id AS assigned_to_id , + u3.user_view_name AS completed_by , + t.task_priority AS priority , + bd.bad_deps AS missing_dependencies , + bc.bad_children AS missing_subtasks , + ( CASE + WHEN mtd.trans_missing IS NULL AND bc.bad_children IS NULL THEN + NULL::BIGINT + WHEN mtd.trans_missing IS NULL THEN + bc.bad_children + WHEN bc.bad_children IS NULL THEN + mtd.trans_missing + ELSE + bc.bad_children + mtd.trans_missing + END ) AS total_missing_dependencies + FROM tasks t + INNER JOIN task_containers tc USING( tc_id ) + INNER JOIN users_view u1 ON u1.user_id = t.user_id + LEFT OUTER JOIN completed_tasks ct ON ct.task_id = t.task_id + LEFT OUTER JOIN users_view u2 ON u2.user_id = t.user_id_assigned + LEFT OUTER JOIN users_view u3 ON u3.user_id = ct.user_id + LEFT OUTER JOIN ( + SELECT td.task_id , COUNT(*) AS bad_deps + FROM task_dependencies td + LEFT OUTER JOIN completed_tasks dct + ON dct.task_id = td.task_id_depends + WHERE dct.task_id IS NULL + GROUP BY td.task_id + ) AS bd ON bd.task_id = t.task_id + LEFT OUTER JOIN ( + SELECT ltc.task_id , COUNT( * ) AS bad_children + FROM logical_task_containers ltc + INNER JOIN tasks t + USING ( ltc_id ) + LEFT OUTER JOIN completed_tasks ct + ON ct.task_id = t.task_id + WHERE ct.task_id IS NULL + GROUP BY ltc.task_id + ) AS bc ON bc.task_id = t.task_id + LEFT OUTER JOIN ( + SELECT tdn.task_id , COUNT( DISTINCT task_id_copyof ) AS trans_missing + FROM taskdep_nodes tdn + LEFT OUTER JOIN completed_tasks ct + ON ct.task_id = task_id_copyof + WHERE NOT tnode_reverse AND ct.task_id IS NULL + AND tdn.task_id <> tdn.task_id_copyof + GROUP BY tdn.task_id + ) AS mtd ON mtd.task_id = t.task_id; + + GRANT SELECT ON tasks_list TO :webapp_user; + +COMMIT; diff --git a/includes/t-data/dao_items.inc.php b/includes/t-data/dao_items.inc.php index cfb77a2..ada9761 100644 --- a/includes/t-data/dao_items.inc.php +++ b/includes/t-data/dao_items.inc.php @@ -177,8 +177,9 @@ class DAO_Items $query = $this->query( 'SELECT p.item_id , p.item_name , p.item_description , COUNT(*) AS t_count ' . 'FROM items p ' - . 'INNER JOIN tasks t USING( item_id ) ' - . 'LEFT OUTER JOIN completed_tasks c USING( task_id ) ' + . 'INNER JOIN task_containers USING ( item_id ) ' + . 'INNER JOIN tasks t USING( tc_id ) ' + . 'LEFT OUTER JOIN completed_tasks c ON t.task_id = c.task_id ' . 'WHERE c.task_id IS NULL ' . 'GROUP BY item_id, p.item_name' ); $results = $query->execute( ); diff --git a/includes/t-data/dao_tasks.inc.php b/includes/t-data/dao_tasks.inc.php index ff2af9c..83bd0d4 100644 --- a/includes/t-data/dao_tasks.inc.php +++ b/includes/t-data/dao_tasks.inc.php @@ -35,6 +35,7 @@ class DAO_Tasks return $this->query( 'SELECT * FROM tasks_list ' . 'WHERE completed_at IS NULL AND missing_dependencies IS NULL ' + . 'AND missing_subtasks IS NULL ' . 'ORDER BY priority DESC , added_at DESC' )->execute( ); } @@ -42,7 +43,8 @@ class DAO_Tasks { return $this->query( 'SELECT * FROM tasks_list ' - . 'WHERE completed_at IS NULL AND missing_dependencies IS NOT NULL ' + . 'WHERE completed_at IS NULL ' + . 'AND ( missing_dependencies IS NOT NULL OR missing_subtasks IS NOT NULL ) ' . 'ORDER BY priority DESC , total_missing_dependencies ASC , added_at DESC' )->execute( ); } @@ -57,7 +59,7 @@ class DAO_Tasks . 'priority ' . 'ELSE ' . '-1 ' - . 'END ) DESC , missing_dependencies ASC NULLS FIRST , added_at DESC' + . 'END ) DESC , total_missing_dependencies ASC NULLS FIRST , added_at DESC' )->execute( $item->id ); } @@ -80,21 +82,17 @@ class DAO_Tasks } + public function addNestedTask( $parent , $title , $priority , $description ) + { + $result = $this->query( 'SELECT tasks_add_nested( $1 , $2 , $3 , $4 , $5 ) AS error' ) + ->execute( $parent , $title , $description , $priority , $_SESSION[ 'uid' ] ); + return $result[0]->error; + } + + public function get( $id ) { - $result = $this->query( - 'SELECT t.task_id AS id, t.task_title AS title, t.item_id AS item ,' - . 't.task_description AS description, t.task_added AS added_at, ' - . 'u1.user_view_name AS added_by, ct.completed_task_time AS completed_at, ' - . 'u2.user_view_name AS assigned_to , u2.user_id AS assigned_id , ' - . 'u3.user_view_name AS completed_by, t.user_id AS uid , ' - . 't.task_priority AS priority ' - . 'FROM tasks t ' - . 'INNER JOIN users_view u1 ON u1.user_id = t.user_id ' - . 'LEFT OUTER JOIN completed_tasks ct ON ct.task_id = t.task_id ' - . 'LEFT OUTER JOIN users_view u2 ON u2.user_id = t.user_id_assigned ' - . 'LEFT OUTER JOIN users_view u3 ON u3.user_id = ct.user_id ' - . 'WHERE t.task_id = $1' )->execute( $id ); + $result = $this->query( 'SELECT * FROM tasks_single_view WHERE id = $1' )->execute( $id ); if ( empty( $result ) ) { return null; } @@ -107,33 +105,50 @@ class DAO_Tasks . 'INNER JOIN users_view u USING (user_id) ' . 'WHERE n.task_id = $1 ' . 'ORDER BY n.note_added DESC' )->execute( $id ); + $task->subtasks = $this->query( + 'SELECT * FROM tasks_list ' + . 'WHERE parent_task = $1 ' + . 'ORDER BY ( CASE ' + . 'WHEN completed_at IS NULL THEN ' + . 'priority ' + . 'ELSE ' + . '-1 ' + . 'END ) DESC , missing_dependencies ASC NULLS FIRST , added_at DESC' + )->execute( $id ); + $task->moveDownTargets = $this->query( + 'SELECT * FROM tasks_move_down_targets ' + . 'WHERE task_id = $1 ' + . 'ORDER BY target_title' )->execute( $id ); $task->dependencies = $this->query( - 'SELECT t.task_id AS id , t.task_title AS title , t.item_id AS item , ' + 'SELECT t.task_id AS id , t.task_title AS title , tc.item_id AS item , ' . 'i.item_name AS item_name , ' . '( ct.completed_task_time IS NOT NULL ) AS completed , ' . 'tl.total_missing_dependencies AS missing_dependencies ' . 'FROM task_dependencies td ' . 'INNER JOIN tasks t ON t.task_id = td.task_id_depends ' - . 'INNER JOIN items i USING ( item_id ) ' + . 'INNER JOIN task_containers tc USING ( tc_id ) ' . 'INNER JOIN tasks_list tl ON tl.id = t.task_id ' + . 'LEFT OUTER JOIN items i USING ( item_id ) ' . 'LEFT OUTER JOIN completed_tasks ct ON ct.task_id = t.task_id ' . 'WHERE td.task_id = $1 ' . 'ORDER BY i.item_name , t.task_priority DESC , t.task_title' )->execute( $id ); $task->reverseDependencies = $this->query( - 'SELECT t.task_id AS id , t.task_title AS title , t.item_id AS item , ' + 'SELECT t.task_id AS id , t.task_title AS title , tc.item_id AS item , ' . 'i.item_name AS item_name , ' . '( ct.completed_task_time IS NOT NULL ) AS completed ' . 'FROM task_dependencies td ' . 'INNER JOIN tasks t USING( task_id ) ' - . 'INNER JOIN items i USING ( item_id ) ' - . 'LEFT OUTER JOIN completed_tasks ct USING ( task_id ) ' + . 'INNER JOIN task_containers tc USING ( tc_id ) ' + . 'LEFT OUTER JOIN items i USING ( item_id ) ' + . 'LEFT OUTER JOIN completed_tasks ct ON t.task_id = ct.task_id ' . 'WHERE td.task_id_depends = $1 ' . 'ORDER BY i.item_name , t.task_priority DESC , t.task_title' )->execute( $id ); $task->possibleDependencies = $this->query( - 'SELECT t.task_id AS id , t.task_title AS title , t.item_id AS item , ' + 'SELECT t.task_id AS id , t.task_title AS title , tc.item_id AS item , ' . 'i.item_name AS item_name ' . 'FROM tasks_possible_dependencies( $1 ) t ' - . 'INNER JOIN items i USING ( item_id ) ' + . 'INNER JOIN task_containers tc USING ( tc_id ) ' + . 'LEFT OUTER JOIN items i USING ( item_id ) ' . 'ORDER BY i.item_name , t.task_priority , t.task_title' )->execute( $id ); return $task; @@ -159,6 +174,11 @@ class DAO_Tasks return false; } } + foreach ( $task->subtasks as $subtask ) { + if ( $subtask->completed_at === null ) { + return false; + } + } return true; } @@ -171,7 +191,12 @@ class DAO_Tasks return false; } } - return true; + + if ( $task->parent_task === null ) { + return true; + } + $parent = ( $task->parent_task instanceof StdClass ) ? $task->parent_task : $this->get( $task->parent_task ); + return $parent->completed_by === null; } @@ -201,6 +226,13 @@ class DAO_Tasks return $result[0]->error; } + public function updateNestedTask( $id , $title , $priority , $description , $assignee ) + { + $result = $this->query( 'SELECT update_task( $1 , $2 , $3 , $4 , $5 ) AS error' ) + ->execute( $id , $title , $description , $priority , $assignee ); + return $result[0]->error; + } + public function addNote( $task , $note ) { $this->query( 'INSERT INTO notes ( task_id , user_id , note_text ) VALUES ( $1 , $2 , $3 )' ) @@ -258,4 +290,18 @@ class DAO_Tasks . 'WHERE _task2.task_id = _task.task_id AND _completed.task_id IS NULL AND _task.task_id = $1' )->execute( $task , $user ); } + + public function moveUp( $task , $force = false ) + { + $result = $this->query( 'SELECT tasks_move_up( $1 , $2 ) AS success') + ->execute( $task->id , $force ? 't' : 'f' ); + return ( $result[0]->success == 't' ); + } + + public function moveDown( $task , $sibling , $force ) + { + $result = $this->query( 'SELECT tasks_move_down( $1 , $2 , $3 ) AS success') + ->execute( $task->id , $sibling , $force ? 't' : 'f' ); + return ( $result[0]->success == 't' ); + } } diff --git a/includes/t-items/controllers.inc.php b/includes/t-items/controllers.inc.php index f3e16e1..4beb1e8 100644 --- a/includes/t-items/controllers.inc.php +++ b/includes/t-items/controllers.inc.php @@ -280,6 +280,6 @@ class Ctrl_ItemTasks return Loader::View( 'box' , 'Tasks' , Loader::View( 'tasks_list' , $tasks , array( 'deps' , 'assigned' , 'completed' ) ) ) ->addButton( BoxButton::create( 'Add task' , 'tasks/add?to=' . $this->item->id ) - ->setClass( 'list-add' ) ); + ->setClass( 'list-add' ) ); } } diff --git a/includes/t-tasks/controllers.inc.php b/includes/t-tasks/controllers.inc.php index dac7b23..1ccfa00 100644 --- a/includes/t-tasks/controllers.inc.php +++ b/includes/t-tasks/controllers.inc.php @@ -13,6 +13,15 @@ class Ctrl_AddTask } public function handle( Page $page ) + { + $nested = $this->form->field( 'nested' )->value( ); + if ( 0 === (int) $nested ) { + return $this->addTopLevelTask( ); + } + return $this->addNestedTask( ); + } + + private function addTopLevelTask( ) { $item = $this->form->field( 'item' ); $name = $this->form->field( 'title' ); @@ -41,6 +50,32 @@ class Ctrl_AddTask return null; } + + private function addNestedTask( ) + { + $parent = $this->form->field( 'parent' ); + $name = $this->form->field( 'title' ); + $priority = $this->form->field( 'priority' ); + $description = $this->form->field( 'description' ); + + $error = Loader::DAO( 'tasks' )->addNestedTask( (int) $parent->value( ) , + $name->value( ) , (int) $priority->value( ) , $description->value( ) ); + switch ( $error ) { + + case 0: + return true; + + case 1: + $name->putError( 'Duplicate sub-task name.' ); + break; + + default: + $name->putError( "An unknown error occurred ($error)" ); + break; + } + + return null; + } } @@ -62,8 +97,13 @@ class Ctrl_TaskDetails } else { $bTitle = "Active task"; } - $items = Loader::DAO( 'items' ); - $items->getLineage( $this->task->item = $items->get( $this->task->item ) ); + + if ( $this->task->item !== null ) { + $items = Loader::DAO( 'items' ); + $items->getLineage( $this->task->item = $items->get( $this->task->item ) ); + } else { + $this->task->parent_task = Loader::DAO( 'tasks' )->get( $this->task->parent_task ); + } $box = Loader::View( 'box' , $bTitle , Loader::View( 'task_details' , $this->task ) ); @@ -81,6 +121,15 @@ class Ctrl_TaskDetails $box->addButton( BoxButton::create( 'Claim task' , 'tasks/claim?id=' . $this->task->id ) ->setClass( 'icon claim' ) ); } + + if ( $this->task->can_move_up == 't' ) { + $box->addButton( BoxButton::create( 'Move task to grandparent' , + 'tasks/move/up?id=' . $this->task->id )->setClass( 'icon move-up' ) ); + } + if ( ! empty( $this->task->moveDownTargets ) ) { + $box->addButton( BoxButton::create( 'Move task to sibling' , + 'tasks/move/down?id=' . $this->task->id )->setClass( 'icon move-down' ) ); + } } else { if ( $tasks->canRestart( $this->task ) ) { $box->addButton( BoxButton::create( 'Re-activate' , 'tasks/restart?id=' . $this->task->id ) @@ -99,6 +148,32 @@ class Ctrl_TaskDetails } +class Ctrl_TaskListSubtasks + extends Controller +{ + private $task; + + public function __construct( $task ) + { + $this->task = $task; + } + + + public function handle( Page $page ) + { + $box = Loader::View( 'box' , 'Sub-tasks' , + Loader::View( 'tasks_list' , $this->task->subtasks , array( 'deps' , 'assigned' , 'completed' ) ) ); + + if ( $this->task->completed_by === null ) { + $box->addButton( BoxButton::create( 'Add sub-task' , 'tasks/add?parent=' . $this->task->id ) + ->setClass( 'list-add' ) ); + } + + return $box; + } +} + + class Ctrl_TaskDependencies extends Controller { @@ -112,14 +187,17 @@ class Ctrl_TaskDependencies public function handle( Page $page ) { - $views = array( - $depBox = Loader::View( 'box' , 'Dependencies' , - Loader::View( 'task_dependencies' , $this->task , false ) ) - ); + $views = array( ); - if ( ! empty( $this->task->possibleDependencies ) ) { - $depBox->addButton( BoxButton::create( 'Add dependency' , 'tasks/deps/add?to=' . $this->task->id ) - ->setClass( 'list-add' ) ); + if ( ! empty( $this->task->dependencies ) + || ( $this->task->completed_by === null && ! empty( $this->task->possibleDependencies ) ) ) { + $views[] = ( $depBox = Loader::View( 'box' , 'Dependencies' , + Loader::View( 'task_dependencies' , $this->task , false ) ) ); + + if ( ! empty( $this->task->possibleDependencies ) ) { + $depBox->addButton( BoxButton::create( 'Add dependency' , 'tasks/deps/add?to=' . $this->task->id ) + ->setClass( 'list-add' ) ); + } } if ( ! empty( $this->task->reverseDependencies ) ) { @@ -230,12 +308,54 @@ class Ctrl_EditTask public function handle( Page $page ) { $id = $this->form->field( 'id' ); - $item = $this->form->field( 'item' ); + + $nested = $this->form->field( 'nested' )->value( ); + if ( 0 == (int) $nested ) { + $item = $this->form->field( 'item' ); + } else { + $item = null; + } + $name = $this->form->field( 'title' ); $priority = $this->form->field( 'priority' ); $description = $this->form->field( 'description' ); $assignee = $this->form->field( 'assigned-to' ); + if ( $item != null ) { + return $this->handleTopLevelTask( $id , $item , $name , $priority , $description , $assignee ); + } + return $this->handleNestedTask( $id , $name , $priority , $description , $assignee ); + } + + private function handleNestedTask( $id , $name , $priority , $description , $assignee ) + { + $error = Loader::DAO( 'tasks' )->updateNestedTask( (int) $id->value( ) , $name->value( ) , + (int) $priority->value( ) , $description->value( ) , + (int) $assignee->value( ) ); + + switch ( $error ) { + + case 0: + return true; + + case 1: + $name->putError( 'Another sub-task already uses this title.' ); + break; + + case 2: + $assignee->putError( 'This user has been deleted.' ); + break; + + default: + $name->putError( "An unknown error occurred ($error)" ); + break; + } + + return null; + } + + private function handleTopLevelTask( $id , $item , $name , $priority , $description , $assignee ) + { $error = Loader::DAO( 'tasks' )->updateTask( (int) $id->value( ) , (int) $item->value( ) , $name->value( ) , (int) $priority->value( ) , $description->value( ) , @@ -373,8 +493,8 @@ class Ctrl_DependencyAdd public function handle( Page $page ) { $id = (int) $this->form->field( 'to' )->value( ); - $dependency = $this->form->field( 'dependency' )->value( ); - $error = Loader::DAO( 'tasks' )->addDependency( $id , $dependency ); + $dependency = $this->form->field( 'dependency' ); + $error = Loader::DAO( 'tasks' )->addDependency( $id , $dependency->value( ) ); switch ( $error ) { @@ -382,15 +502,19 @@ class Ctrl_DependencyAdd return true; case 1: - $name->putError( 'The task you selected has been deleted.' ); + $dependency->putError( 'The task you selected has been deleted.' ); break; case 2: - $item->putError( 'This dependency is no longer possible.' ); + $dependency->putError( 'This dependency is no longer possible.' ); + break; + + case 3: + $dependency->putError( 'These tasks are no longer at the same level.' ); break; default: - $name->putError( "An unknown error occurred ($error)" ); + $dependency->putError( "An unknown error occurred ($error)" ); break; } diff --git a/includes/t-tasks/package.inc.php b/includes/t-tasks/package.inc.php index cabe7bf..bdb2b19 100644 --- a/includes/t-tasks/package.inc.php +++ b/includes/t-tasks/package.inc.php @@ -26,9 +26,12 @@ $package[ 'ctrls' ][] = 'edit_note_form'; $package[ 'ctrls' ][] = 'edit_note'; $package[ 'ctrls' ][] = 'edit_task_form'; $package[ 'ctrls' ][] = 'edit_task'; +$package[ 'ctrls' ][] = 'task_claim'; $package[ 'ctrls' ][] = 'task_dependencies'; $package[ 'ctrls' ][] = 'task_details'; -$package[ 'ctrls' ][] = 'task_claim'; +$package[ 'ctrls' ][] = 'task_list_subtasks'; +$package[ 'ctrls' ][] = 'task_move_down'; +$package[ 'ctrls' ][] = 'task_move_up'; $package[ 'ctrls' ][] = 'task_notes'; $package[ 'ctrls' ][] = 'toggle_task'; $package[ 'ctrls' ][] = 'view_task'; diff --git a/includes/t-tasks/page_controllers.inc.php b/includes/t-tasks/page_controllers.inc.php index 00e995c..c657995 100644 --- a/includes/t-tasks/page_controllers.inc.php +++ b/includes/t-tasks/page_controllers.inc.php @@ -75,8 +75,15 @@ class Ctrl_AddTaskForm { try { $target = (int) $this->getParameter( 'to' ); + $targetIsItem = true; } catch ( ParameterException $e ) { - $target = null; + try { + $target = (int) $this->getParameter( 'parent' ); + $targetIsItem = false; + } catch ( ParameterException $e ) { + $target = null; + $targetIsItem = null; + } } $form = Loader::Create( 'Form' , 'Add this task' , 'create-task' ); @@ -86,20 +93,43 @@ class Ctrl_AddTaskForm if ( ! $this->addItemSelector( $form ) ) { return 'items'; } - } else { + $form->addField( Loader::Create( 'Field' , 'nested' , 'hidden' ) + ->setDefaultValue( 0 ) ); + } elseif ( $targetIsItem ) { $item = Loader::DAO( 'items' )->get( $target ); if ( $item === null ) { - return 'items'; + return 'tasks'; } $returnURL = 'items/view?id=' . $target; $form->addField( Loader::Create( 'Field' , 'to' , 'hidden' ) ->setDefaultValue( $target ) ) + ->addField( Loader::Create( 'Field' , 'nested' , 'hidden' ) + ->setDefaultValue( 0 ) ) ->addField( Loader::Create( 'Field' , 'item' , 'hidden' ) ->setDefaultValue( $target ) ) ->addField( Loader::Create( 'Field' , 'item-name' , 'label' ) + ->setMandatory( false ) ->setDescription( 'Item:' ) ->setDefaultValue( $item->name ) ); + } else { + $parent = Loader::DAO( 'tasks' )->get( $target ); + if ( $parent === null ) { + return 'tasks'; + } + $returnURL = 'tasks/view?id=' . $target; + if ( $parent->completed_by !== null ) { + return $returnURL; + } + + $form->addField( Loader::Create( 'Field' , 'parent' , 'hidden' ) + ->setDefaultValue( $target ) ) + ->addField( Loader::Create( 'Field' , 'nested' , 'hidden' ) + ->setDefaultValue( 1 ) ) + ->addField( Loader::Create( 'Field' , 'item-name' , 'label' ) + ->setMandatory( false ) + ->setDescription( 'Sub-task of:' ) + ->setDefaultValue( $parent->title ) ); } $page->setTitle( 'New task' ); @@ -159,10 +189,13 @@ class Ctrl_ViewTask $page->setTitle( $task->title . ' (task)' ); $result = array( - Loader::Ctrl( 'task_details' , $task ) , - Loader::Ctrl( 'task_dependencies' , $task ) , + Loader::Ctrl( 'task_details' , $task ) ); + if ( $task->completed_by === null || ! empty( $task->subtasks ) ) { + $result[] = Loader::Ctrl( 'task_list_subtasks' , $task ); + } + $result[] = Loader::Ctrl( 'task_dependencies' , $task ); if ( $task->completed_by === null ) { array_push( $result , Loader::Ctrl( 'add_task_note_form' , $task ) ); } @@ -197,6 +230,13 @@ class Ctrl_DeleteTaskForm } $page->setTitle( $task->title . ' (task)' ); + // Create parent URL from either the item or parent task + if ( $task->parent_task === null ) { + $parentURL = 'items/view?id=' . $task->item; + } else { + $parentURL = 'tasks/view?id=' . $task->parent_task; + } + // Generate confirmation text $confText = HTML::make( 'div' ) ->appendElement( HTML::make( 'p' ) @@ -210,7 +250,7 @@ class Ctrl_DeleteTaskForm ->setDefaultValue( $task->id ) ) ->addField( Loader::Create( 'Field' , 'confirm' , 'html' )->setDefaultValue( $confText ) ) ->setCancelURL( 'tasks/view?id=' . $task->id ) - ->setSuccessURL( 'items/view?id=' . $task->item ) + ->setSuccessURL( $parentURL ) ->addController( Loader::Ctrl( 'delete_task' ) ) ->controller( ); @@ -242,13 +282,19 @@ class Ctrl_EditTaskForm $page->setTitle( $task->title . ' (task)' ); - return Loader::Create( 'Form' , 'Update task' , 'edit-task' , 'Editing task' ) + $form = Loader::Create( 'Form' , 'Update task' , 'edit-task' , 'Editing task' ) ->setURL( 'tasks/view?id=' . $task->id ) ->addField( Loader::Create( 'Field' , 'id' , 'hidden' ) ->setDefaultValue( $task->id ) ) - ->addField( $this->createItemSelector( ) - ->setDefaultValue( $task->item ) ) - ->addField( Loader::Create( 'Field' , 'title' , 'text' ) + ->addField( Loader::Create( 'Field' , 'nested' , 'hidden' ) + ->setDefaultValue( $task->item === null ? 1 : 0 ) ); + + if ( $task->item !== null ) { + $form->addField( $this->createItemSelector( ) + ->setDefaultValue( $task->item ) ); + } + + return $form->addField( Loader::Create( 'Field' , 'title' , 'text' ) ->setDescription( 'Title:' ) ->setModifier( Loader::Create( 'Modifier_TrimString' ) ) ->setValidator( Loader::Create( 'Validator_StringLength' , 'This title' , 5 , 256 ) ) @@ -411,31 +457,37 @@ class Ctrl_DependencyAddForm $form = Loader::Create( 'Form' , 'Add dependency' , 'add-dep' ) ->addField( Loader::Create( 'Field' , 'to' , 'hidden' ) ->setDefaultValue( $id ) ); - $this->addDependencySelector( $form , $task->possibleDependencies ); + $this->addDependencySelector( $form , $task->possibleDependencies , $task->item !== null ); return $form->setURL( 'tasks/view?id=' . $id ) ->addController( Loader::Ctrl( 'dependency_add' ) ) ->controller( ); } - private function addDependencySelector( $form , $possibleDependencies ) + private function addDependencySelector( $form , $possibleDependencies , $topLevel ) { $form->addField( $select = Loader::Create( 'Field' , 'dependency' , 'select' ) ->setDescription( 'Dependency to add:' ) ->addOption( '' , '(please select a task)' ) ); - $depsByItem = $this->getDependenciesByItem( $possibleDependencies ); - $items = $this->getItemsToDisplay( $depsByItem ); - foreach ( $items as $item ) { - $prefix = '-' . str_repeat( '--' , $item->depth ); - $name = $prefix . ' ' . $item->name; - $select->addOption( 'I' . $item->id , $name , true ); - if ( ! array_key_exists( $item->id , $depsByItem ) ) { - continue; - } + if ( $topLevel ) { + $depsByItem = $this->getDependenciesByItem( $possibleDependencies ); + $items = $this->getItemsToDisplay( $depsByItem ); + foreach ( $items as $item ) { + $prefix = '-' . str_repeat( '--' , $item->depth ); + $name = $prefix . ' ' . $item->name; + $select->addOption( 'I' . $item->id , $name , true ); + if ( ! array_key_exists( $item->id , $depsByItem ) ) { + continue; + } - foreach ( $depsByItem[ $item->id ] as $task ) { - $select->addOption( $task->id , $prefix . '-> ' . $task->title ); + foreach ( $depsByItem[ $item->id ] as $task ) { + $select->addOption( $task->id , $prefix . '-> ' . $task->title ); + } + } + } else { + foreach ( $possibleDependencies as $task ) { + $select->addOption( $task->id , $task->title ); } } return true; @@ -546,3 +598,155 @@ class Ctrl_DependencyDeleteForm } + +class Ctrl_TaskMoveDown + extends Controller +{ + + public function __construct( ) + { + $this->dao = Loader::DAO( 'tasks' ); + } + + public function handle( Page $page ) + { + try { + $id = (int) $this->getParameter( 'id' ); + } catch ( ParameterException $e ) { + return 'tasks'; + } + + $task = $this->dao->get( $id ); + if ( $task === null ) { + return 'tasks'; + } + + if ( empty( $task->moveDownTargets ) ) { + return 'tasks/view?id=' . $id; + } + + $page->setTitle( $task->title . ' (task)' ); + $sibling = $this->getSibling( $task ); + if ( $sibling != null ) { + if ( $this->handleSelectedSibling( $task , $sibling ) ) { + return 'tasks/view?id=' . $id; + } else { + return $this->confirmationForm( $task , $sibling ); + } + } + return $this->siblingSelectionForm( $task ); + } + + private function getSibling( $task ) + { + try { + $sibling = (int) $this->getParameter( 'sibling' ); + $okSiblings = array_map( function( $item ) { return $item->target_id; } , $task->moveDownTargets ); + if ( ! in_array( $sibling , $okSiblings ) ) { + $sibling = null; + } + } catch ( ParameterException $e ) { + $sibling = null; + } + return $sibling; + } + + private function handleSelectedSibling( $task , $sibling ) + { + try { + $force = (bool) $this->getParameter( 'force' ); + } catch ( ParameterException $e ) { + $force = false; + } + + return $this->dao->moveDown( $task , $sibling , $force ); + } + + private function confirmationForm( $task , $sibling ) + { + $sibling = $this->dao->get( $sibling ); + $confText = HTML::make( 'div' ) + ->appendElement( HTML::make( 'p' ) + ->appendText( 'All dependencies and reverse dependencies of the ' + . 'selected task will be lost when it is moved into ' ) + ->appendElement( HTML::make( 'strong' )->appendText( $sibling->title ) ) + ->appendText( '.' ) ) + ->appendElement( HTML::make( 'p' ) + ->appendText( 'Please confirm.' ) ); + + return Loader::Create( 'Form' , 'Move task' , 'move-down' ) + ->addField( Loader::Create( 'Field' , 'id' , 'hidden' ) + ->setDefaultValue( $task->id ) ) + ->addField( Loader::Create( 'Field' , 'sibling' , 'hidden' ) + ->setDefaultValue( $sibling->id ) ) + ->addField( Loader::Create( 'Field' , 'force' , 'hidden' ) + ->setDefaultValue( 1 ) ) + ->addField( Loader::Create( 'Field' , 'confirm' , 'html' )->setDefaultValue( $confText ) ) + ->setURL( 'tasks/view?id=' . $task->id ) + ->controller( ); + } + + private function siblingSelectionForm( $task ) + { + $selector = Loader::Create( 'Field' , 'sibling' , 'select' ) + ->setDescription( 'Move task into: ' ); + foreach ( $task->moveDownTargets as $target ) { + $selector->addOption( $target->target_id , $target->target_title ); + } + return Loader::Create( 'Form' , 'Move task' , 'move-down' , 'Move task to sibling' ) + ->addField( Loader::Create( 'Field' , 'id' , 'hidden' ) + ->setDefaultValue( $task->id ) ) + ->addField( $selector ) + ->setURL( 'tasks/view?id=' . $task->id ) + ->controller( ); + } +} + + +class Ctrl_TaskMoveUp + extends Controller +{ + + public function handle( Page $page ) + { + try { + $id = (int) $this->getParameter( 'id' ); + } catch ( ParameterException $e ) { + return 'tasks'; + } + + $dao = Loader::DAO( 'tasks' ); + $task = $dao->get( $id ); + if ( $task === null ) { + return 'tasks'; + } + + try { + $force = (bool) $this->getParameter( 'force' ); + } catch ( ParameterException $e ) { + $force = false; + } + + if ( ! $task->can_move_up || $dao->moveUp( $task , $force ) ) { + return 'tasks/view?id=' . $id; + } + + $confText = HTML::make( 'div' ) + ->appendElement( HTML::make( 'p' ) + ->appendText( 'All dependencies and reverse dependencies of the ' + . 'selected task will be lost when it is moved.' ) ) + ->appendElement( HTML::make( 'p' ) + ->appendText( 'Please confirm.' ) ); + + $page->setTitle( $task->title . ' (task)' ); + return Loader::Create( 'Form' , 'Move task' , 'move-up' ) + ->addField( Loader::Create( 'Field' , 'id' , 'hidden' ) + ->setDefaultValue( $id ) ) + ->addField( Loader::Create( 'Field' , 'force' , 'hidden' ) + ->setDefaultValue( 1 ) ) + ->addField( Loader::Create( 'Field' , 'confirm' , 'html' )->setDefaultValue( $confText ) ) + ->setURL( 'tasks/view?id=' . $id ) + ->controller( ); + } + +} diff --git a/includes/t-tasks/pages.inc.php b/includes/t-tasks/pages.inc.php index bf81799..c5a714f 100644 --- a/includes/t-tasks/pages.inc.php +++ b/includes/t-tasks/pages.inc.php @@ -15,10 +15,12 @@ class Page_TasksTasks 'finish' => array( 'toggle_task' , false ) , 'restart' => array( 'toggle_task' , true ) , 'view' => 'view_task' , - 'notes/edit' => 'edit_note_form' , - 'notes/delete' => 'delete_note_form' , 'deps/add' => 'dependency_add_form' , 'deps/delete' => 'dependency_delete_form' , + 'move/down' => 'task_move_down' , + 'move/up' => 'task_move_up' , + 'notes/edit' => 'edit_note_form' , + 'notes/delete' => 'delete_note_form' , )); } diff --git a/includes/t-tasks/views.inc.php b/includes/t-tasks/views.inc.php index d66bc03..f855147 100644 --- a/includes/t-tasks/views.inc.php +++ b/includes/t-tasks/views.inc.php @@ -60,7 +60,7 @@ class View_TasksList ->appendElement( HTML::make( 'a' ) ->setAttribute( 'href' , $this->base . '/tasks/view?id=' . $task->id ) ->appendText( $task->title ) ) ); - $this->addItem( $cell , $task ); + $this->addParent( $cell , $task ); $classes = array( ); $addedAt = strtotime( $task->added_at ); @@ -75,6 +75,9 @@ class View_TasksList if ( $task->missing_dependencies !== null ) { $this->generateMissingDependencies( $cell , $classes , $task ); } + if ( $task->missing_subtasks !== null ) { + $this->generateMissingSubtasks( $cell , $classes , $task ); + } if ( $task->assigned_to !== null ) { $this->generateAssignedTask( $cell , $classes , $task ); } @@ -82,19 +85,28 @@ class View_TasksList if ( ! empty( $classes ) ) { foreach ( $cell as $entry ) { - $entry->setAttribute( 'class' , join( ' ' , $classes ) ); + $entry->setAttribute( 'class' , join( ' ' , array_unique( $classes ) ) ); } } return $cell; } - protected function addItem( &$cell , $task ) + protected function addParent( &$cell , $task ) { if ( ! array_key_exists( 'item' , $this->features ) ) { return; } + if ( $task->item !== null ) { + $this->addItem( $cell , $task ); + } else { + $this->addParentTask( $cell , $task ); + } + } + + protected function addItem( &$cell , $task ) + { $itemsDao = Loader::DAO( 'items' ); $item = $itemsDao->get( $task->item ); $lineage = $itemsDao->getLineage( $item ); @@ -114,6 +126,17 @@ class View_TasksList array_push( $cell , HTML::make( 'dd' )->append( $contents ) ); } + protected function addParentTask( &$cell , $task ) + { + $parent = $this->dao->get( $task->parent_task ); + + array_push( $cell , HTML::make( 'dd' ) + ->appendText( 'Sub-task of ' ) + ->appendElement( HTML::make( 'a' ) + ->setAttribute( 'href' , $this->base . '/tasks/view?id=' . $parent->id ) + ->appendText( $parent->title ) ) ); + } + protected function generateMissingDependencies( &$cell , &$classes , $task ) { if ( ! array_key_exists( 'deps' , $this->features ) ) { @@ -134,6 +157,23 @@ class View_TasksList array_push( $classes , 'missing-deps' ); } + protected function generateMissingSubtasks( &$cell , &$classes , $task ) + { + if ( ! array_key_exists( 'deps' , $this->features ) ) { + return; + } + + if ( $task->missing_subtasks > 1 ) { + $end = 's'; + } else { + $end = ''; + } + array_push( $cell , + $md = HTML::make( 'dd' )->appendText( "{$task->missing_subtasks} incomplete sub-task$end" ) ); + + array_push( $classes , 'missing-deps' ); + } + protected function generateAssignedTask( &$cell , &$classes , $task ) { if ( ! array_key_exists( 'assigned' , $this->features ) ) { @@ -173,11 +213,22 @@ class View_TaskDetails public function render( ) { $list = HTML::make( 'dl' ) - ->setAttribute( 'class' , 'tasks' ) - ->appendElement( HTML::make( 'dt' ) - ->appendText( 'On item:' ) ) - ->appendElement( HTML::make( 'dd' ) - ->append( $this->formatPlaceLineage( $this->task->item ) ) ); + ->setAttribute( 'class' , 'tasks' ); + + if ( $this->task->item !== null ) { + $list->appendElement( HTML::make( 'dt' ) + ->appendText( 'On item:' ) ) + ->appendElement( HTML::make( 'dd' ) + ->append( $this->formatPlaceLineage( $this->task->item ) ) ); + } else { + $list->appendElement( HTML::make( 'dt' ) + ->appendText( 'Sub-task of:' ) ) + ->appendElement( HTML::make( 'dd' ) + ->appendElement( HTML::make( 'a' ) + ->setAttribute( 'href' , $this->base . + '/tasks/view?id=' . $this->task->parent_task->id ) + ->appendText( $this->task->parent_task->title ) ) ); + } if ( $this->task->description != '' ) { $list->appendElement( HTML::make( 'dt' ) @@ -317,6 +368,8 @@ class View_TaskDependencies ->appendText( $dependency->item_name ) ) ->appendElement( $itemList ) ); $prevItem = $dependency->item; + } elseif ( $itemList === null ) { + $itemList = $list; } $entry = HTML::make( 'li' )->appendElement( diff --git a/site/icons.png b/site/icons.png index b45d755..c9b5700 100644 Binary files a/site/icons.png and b/site/icons.png differ diff --git a/site/style.css b/site/style.css index caccd0d..72fe711 100644 --- a/site/style.css +++ b/site/style.css @@ -360,6 +360,12 @@ div.box-buttons a.start:hover { background-position: -18px -90px } div.box-buttons a.claim { background-position: 0px -108px } div.box-buttons a.claim:hover { background-position: -18px -108px } +div.box-buttons a.move-up { background-position: 0px -126px } +div.box-buttons a.move-up:hover { background-position: -18px -126px } + +div.box-buttons a.move-down { background-position: 0px -144px } +div.box-buttons a.move-down:hover { background-position: -18px -144px } + div.box-buttons a.list-add::after { content: '+'; font-weight: bold;