Fixed sub-task handling

The previous implementation of sub-tasks did not work as expected: it
was possible to mark sub-tasks as completed before the parent task's
dependencies were satisfied. In addition, it was impossible to retrieve
a task's path from the database without running a recursive query.

Full paths to sub-tasks added to views, since it is now possible to
obtain them.
This commit is contained in:
Emmanuel BENOîT 2012-02-15 10:04:11 +01:00
parent 91ae4f81fd
commit 2051303262
13 changed files with 1023 additions and 224 deletions

View file

@ -27,23 +27,6 @@ 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
* ------------------------
@ -88,13 +71,6 @@ 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 (
@ -117,8 +93,9 @@ CREATE TABLE tasks (
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 )
item_id INT NOT NULL REFERENCES items ( item_id )
ON UPDATE NO ACTION ON DELETE CASCADE ,
task_id_parent INT ,
task_title VARCHAR(256) NOT NULL,
task_priority INT NOT NULL,
task_description TEXT NOT NULL,
@ -129,17 +106,22 @@ CREATE TABLE tasks (
PRIMARY KEY( task_id )
);
CREATE UNIQUE INDEX i_tasks_title ON tasks (tc_id,task_title);
ALTER TABLE tasks
ADD FOREIGN KEY ( task_id_parent ) REFERENCES tasks ( task_id )
ON DELETE CASCADE ON UPDATE NO ACTION;
CREATE UNIQUE INDEX i_tasks_title_toplevel
ON tasks ( item_id , task_title )
WHERE task_id_parent IS NULL;
CREATE UNIQUE INDEX i_tasks_title_subtask
ON tasks ( task_id_parent , task_title )
WHERE task_id_parent IS NULL;
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 )
@ -157,6 +139,27 @@ CREATE TABLE items_tree (
GRANT SELECT ON items_tree TO :webapp_user;
/*
* Tree of tasks
*
* This table caches the hierarchy of tasks. Its contents are generated
* automatically when tasks are added, deleted or modified.
*/
CREATE TABLE tasks_tree (
task_id_parent INT NOT NULL
REFERENCES tasks( task_id )
ON UPDATE NO ACTION
ON DELETE CASCADE ,
task_id_child INT NOT NULL
REFERENCES tasks( task_id )
ON UPDATE NO ACTION
ON DELETE CASCADE ,
tt_depth INT NOT NULL,
PRIMARY KEY( task_id_parent , task_id_child )
);
GRANT SELECT ON tasks_tree TO :webapp_user;
-- Table completed_tasks
CREATE TABLE completed_tasks (

View file

@ -1,43 +1,141 @@
/*
* Triggers to handle task containers
* Triggers to handle the task hierarchy
*/
DROP FUNCTION IF EXISTS tgf_item_tc_ai( ) CASCADE;
CREATE FUNCTION tgf_item_tc_ai( )
/*
* Create a logical task container for each new task
* (deleting the task will delete the container due to
* "on delete cascade"). Also insert data about the tree's
* current structure.
*/
DROP FUNCTION IF EXISTS tasks_tree_ai( ) CASCADE;
CREATE FUNCTION tasks_tree_ai( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
SECURITY DEFINER
AS $tgf_item_tc_ai$
AS $tasks_tree_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 );
INSERT INTO tasks_tree( task_id_parent , task_id_child , tt_depth )
VALUES ( NEW.task_id , NEW.task_id , 0 );
INSERT INTO tasks_tree( task_id_parent , task_id_child , tt_depth )
SELECT x.task_id_parent, NEW.task_id, x.tt_depth + 1
FROM tasks_tree x WHERE x.task_id_child = NEW.task_id_parent;
RETURN NEW;
END;
$tgf_task_tc_ai$;
$tasks_tree_ai$;
REVOKE EXECUTE ON FUNCTION tgf_task_tc_ai( ) FROM PUBLIC;
REVOKE EXECUTE
ON FUNCTION tasks_tree_ai( )
FROM PUBLIC;
CREATE TRIGGER tg_task_tc_ai AFTER INSERT ON tasks
FOR EACH ROW EXECUTE PROCEDURE tgf_task_tc_ai( );
CREATE TRIGGER tasks_tree_ai
AFTER INSERT ON tasks
FOR EACH ROW EXECUTE PROCEDURE tasks_tree_ai( );
/*
* Before updates on the task hierarchy, make sure everything the changes
* are valid
*/
DROP FUNCTION IF EXISTS tasks_tree_bu( ) CASCADE;
CREATE FUNCTION tasks_tree_bu( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
SECURITY DEFINER
AS $tasks_tree_bu$
BEGIN
PERFORM 1 FROM tasks_tree
WHERE ( task_id_parent , task_id_child ) = ( NEW.task_id , NEW.task_id_parent );
IF FOUND THEN
RAISE EXCEPTION 'Update blocked, it would create a loop.';
END IF;
RETURN NEW;
END;
$tasks_tree_bu$;
REVOKE EXECUTE
ON FUNCTION tasks_tree_bu( )
FROM PUBLIC;
CREATE TRIGGER tasks_tree_bu
BEFORE UPDATE OF task_id_parent ON tasks
FOR EACH ROW EXECUTE PROCEDURE tasks_tree_bu( );
/*
* After updates of the task hierarchy, make sure the tree structure cache
* is up-to-date.
*/
DROP FUNCTION IF EXISTS tasks_tree_au( ) CASCADE;
CREATE FUNCTION tasks_tree_au( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
SECURITY DEFINER
AS $tasks_tree_au$
BEGIN
-- Remove existing lineage for the updated object and its children
IF OLD.task_id_parent IS NOT NULL THEN
DELETE FROM tasks_tree AS te2
USING tasks_tree te1
WHERE te2.task_id_child = te1.task_id_child
AND te1.task_id_parent = NEW.task_id
AND te2.tt_depth > te1.tt_depth;
END IF;
-- Create new lineage
IF NEW.task_id_parent IS NOT NULL THEN
INSERT INTO tasks_tree ( task_id_parent , task_id_child , tt_depth )
SELECT te1.task_id_parent , te2.task_id_child , te1.tt_depth + te2.tt_depth + 1
FROM tasks_tree te1 , tasks_tree te2
WHERE te1.task_id_child = NEW.task_id_parent
AND te2.task_id_parent = NEW.task_id;
UPDATE tasks t1
SET item_id = t2.item_id
FROM tasks t2
WHERE t1.task_id = NEW.task_id
AND t2.task_id = NEW.task_id_parent;
END IF;
RETURN NEW;
END;
$tasks_tree_au$;
REVOKE EXECUTE
ON FUNCTION tasks_tree_au( )
FROM PUBLIC;
CREATE TRIGGER tasks_tree_au
AFTER UPDATE OF task_id_parent ON tasks
FOR EACH ROW EXECUTE PROCEDURE tasks_tree_au( );
/*
* After an update on some task's containing item, update all children accordingly.
*/
DROP FUNCTION IF EXISTS tasks_item_au( ) CASCADE;
CREATE FUNCTION tasks_item_au( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
SECURITY DEFINER
AS $tasks_item_au$
BEGIN
UPDATE tasks
SET item_id = NEW.item_id
WHERE task_id_parent = NEW.task_id;
RETURN NEW;
END;
$tasks_item_au$;
REVOKE EXECUTE
ON FUNCTION tasks_item_au( )
FROM PUBLIC;
CREATE TRIGGER tasks_item_au
AFTER UPDATE OF item_id ON tasks
FOR EACH ROW EXECUTE PROCEDURE tasks_item_au( );

View file

@ -6,26 +6,20 @@ CREATE FUNCTION add_task( t_item INT , t_title TEXT , t_description TEXT , t_pri
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 );
INSERT INTO tasks ( item_id , ltc_id , task_title , task_description , task_priority , user_id )
VALUES ( t_item , _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;
@ -40,14 +34,14 @@ CREATE FUNCTION tasks_add_nested( t_parent INT , t_title TEXT , t_description TE
SECURITY INVOKER
AS $tasks_add_nested$
DECLARE
_container INT;
_item INT;
_logical_container INT;
BEGIN
SELECT INTO _container tc.tc_id
FROM task_containers tc
INNER JOIN tasks t USING ( task_id )
SELECT INTO _item item_id
FROM tasks t
LEFT OUTER JOIN completed_tasks ct USING ( task_id )
WHERE t.task_id = t_parent AND ct.task_id IS NULL;
WHERE t.task_id = t_parent AND ct.task_id IS NULL
FOR UPDATE OF t;
IF NOT FOUND THEN
RETURN 2;
END IF;
@ -56,8 +50,8 @@ BEGIN
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 );
INSERT INTO tasks ( task_id_parent , item_id , ltc_id , task_title , task_description , task_priority , user_id )
VALUES ( t_parent , _item , _logical_container , t_title , t_description , t_priority , t_user );
RETURN 0;
EXCEPTION
WHEN unique_violation THEN
@ -77,29 +71,8 @@ CREATE FUNCTION finish_task( t_id INT , u_id INT , n_text TEXT )
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;
PERFORM 1 FROM tasks_single_view t
WHERE task_id = t_id AND badness = 0;
IF NOT FOUND THEN
RETURN 2;
END IF;
@ -113,7 +86,6 @@ BEGIN
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;
@ -194,8 +166,9 @@ BEGIN
RETURN 4;
END IF;
SELECT INTO tc tc_id FROM task_containers
WHERE item_id = p_id;
PERFORM 1 FROM items
WHERE item_id = p_id
FOR UPDATE;
IF NOT FOUND THEN
RETURN 2;
END IF;
@ -203,7 +176,7 @@ BEGIN
IF t_assignee = 0 THEN
t_assignee := NULL;
END IF;
UPDATE tasks SET tc_id = tc , task_title = t_title ,
UPDATE tasks SET item_id = p_id , task_title = t_title ,
task_description = t_description ,
task_priority = t_priority ,
user_id_assigned = t_assignee

View file

@ -75,7 +75,7 @@ BEGIN
END IF;
SELECT INTO _gp_container , _gp_lcontainer
gp.tc_id , gp.ltc_id
gp.item_id , gp.ltc_id
FROM tasks t
INNER JOIN logical_task_containers lt
USING ( ltc_id )
@ -86,7 +86,7 @@ BEGIN
DELETE FROM task_dependencies
WHERE task_id = _task OR task_id_depends = _task;
UPDATE tasks
SET tc_id = _gp_container ,
SET item_id = _gp_container ,
ltc_id = _gp_lcontainer
WHERE task_id = _task;
RETURN TRUE;
@ -127,8 +127,7 @@ BEGIN
RETURN FALSE;
END IF;
SELECT INTO _s_container tc_id
FROM task_containers
SELECT INTO _s_container item_id FROM tasks
WHERE task_id = _sibling;
SELECT INTO _s_lcontainer ltc_id
FROM logical_task_containers
@ -137,7 +136,7 @@ BEGIN
DELETE FROM task_dependencies
WHERE task_id = _task OR task_id_depends = _task;
UPDATE tasks
SET tc_id = _s_container ,
SET item_id = _s_container ,
ltc_id = _s_lcontainer
WHERE task_id = _task;
RETURN TRUE;

View file

@ -1,3 +1,87 @@
/*
* Direct dependencies view
* -------------------------
*
* This view counts the amount of direct dependencies (total and unsatisfied)
* for each task.
*/
DROP VIEW IF EXISTS tasks_deps_view CASCADE;
CREATE VIEW tasks_deps_view
AS SELECT t.task_id , COUNT( td ) AS deps_total ,
COUNT( NULLIF( td IS NOT NULL AND dct IS NULL , FALSE ) ) AS deps_unsatisfied
FROM tasks t
LEFT OUTER JOIN task_dependencies td
USING ( task_id )
LEFT OUTER JOIN completed_tasks dct
ON dct.task_id = td.task_id_depends
GROUP BY t.task_id;
/*
* Transitive dependencies view
* -----------------------------
*
* This view counts the amount of total and unsatisfied dependencies for each
* task, based on the fact that task dependencies are transitive. Each task
* in the graph is only counted once.
*/
DROP VIEW IF EXISTS tasks_tdeps_view CASCADE;
CREATE VIEW tasks_tdeps_view
AS SELECT t.task_id , COUNT( DISTINCT task_id_copyof ) AS tdeps_total ,
COUNT( DISTINCT ( CASE
WHEN tdn.task_id_copyof IS NOT NULL AND ct.task_id IS NULL
THEN tdn.task_id_copyof
ELSE NULL
END ) ) AS tdeps_unsatisfied
FROM tasks t
LEFT OUTER JOIN taskdep_nodes tdn
ON NOT tdn.tnode_reverse AND tdn.task_id = t.task_id
AND tdn.task_id_copyof <> tdn.task_id
LEFT OUTER JOIN completed_tasks ct
ON ct.task_id = tdn.task_id_copyof
GROUP BY t.task_id;
/*
* Inherited dependencies view
* ----------------------------
*
* This view includes dependency counts for all tasks, including dependencies inherited
* from parents in the case of sub-tasks.
*/
DROP VIEW IF EXISTS tasks_ideps_view CASCADE;
CREATE VIEW tasks_ideps_view
AS SELECT task_id_child AS task_id ,
SUM( deps_total ) AS ideps_total ,
SUM( deps_unsatisfied ) AS ideps_unsatisfied ,
SUM( tdeps_total ) AS tideps_total ,
SUM( tdeps_unsatisfied ) AS tideps_unsatisfied
FROM tasks_tree tt
INNER JOIN tasks_deps_view td
ON td.task_id = tt.task_id_parent
INNER JOIN tasks_tdeps_view ttd
ON ttd.task_id = tt.task_id_parent
GROUP BY task_id_child;
/*
* Sub-tasks view
* ---------------
*
* This view counts sub-tasks and the amount of sub-tasks that have not been
* completed yet.
*/
DROP VIEW IF EXISTS tasks_sdeps_view CASCADE;
CREATE VIEW tasks_sdeps_view
AS SELECT t.task_id AS task_id ,
COUNT( st ) AS sdeps_total ,
COUNT( NULLIF( st.task_id IS NOT NULL AND sct.task_id IS NULL , FALSE ) ) AS sdeps_unsatisfied
FROM tasks t
LEFT OUTER JOIN tasks st
ON st.task_id_parent = t.task_id
LEFT OUTER JOIN completed_tasks sct
ON sct.task_id = st.task_id
GROUP BY t.task_id;
/*
* Task view
*
@ -5,15 +89,23 @@
*/
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 ,
AS SELECT t.task_id AS id, t.task_title AS title, t.item_id AS item , t.task_id_parent 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
( cmu IS NOT NULL ) AS can_move_up ,
( _inherited.ideps_unsatisfied + _direct.deps_unsatisfied + _subs.sdeps_unsatisfied ) AS badness
FROM tasks t
INNER JOIN task_containers tc USING ( tc_id )
INNER JOIN tasks_deps_view _direct
USING ( task_id )
INNER JOIN tasks_tdeps_view _transitive
USING ( task_id )
INNER JOIN tasks_ideps_view _inherited
USING ( task_id )
INNER JOIN tasks_sdeps_view _subs
USING ( task_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
@ -32,7 +124,7 @@ GRANT SELECT ON tasks_single_view TO :webapp_user;
DROP VIEW IF EXISTS tasks_list;
CREATE VIEW tasks_list
AS SELECT t.task_id AS id, tc.item_id AS item , tc.task_id AS parent_task ,
AS SELECT t.task_id AS id, t.item_id AS item , t.task_id_parent 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,
@ -41,51 +133,38 @@ CREATE VIEW tasks_list
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 ,
_direct.deps_total AS total_direct_dependencies ,
_direct.deps_unsatisfied AS unsatisfied_direct_dependencies ,
_transitive.tdeps_total AS total_transitive_dependencies ,
_transitive.tdeps_unsatisfied AS unsatisfied_transitive_dependencies ,
_subs.sdeps_total AS total_subtasks ,
_subs.sdeps_unsatisfied AS incomplete_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
WHEN _direct.deps_total <> 0 THEN
0
ELSE
bc.bad_children + mtd.trans_missing
END ) AS total_missing_dependencies
_inherited.ideps_total
END ) AS total_inherited_dependencies ,
( CASE
WHEN _direct.deps_total <> 0 THEN
0
ELSE
_inherited.ideps_unsatisfied
END ) AS unsatisfied_inherited_dependencies ,
( _inherited.ideps_unsatisfied + _direct.deps_unsatisfied + _subs.sdeps_unsatisfied ) AS badness
FROM tasks t
INNER JOIN task_containers tc USING( tc_id )
INNER JOIN tasks_deps_view _direct
USING ( task_id )
INNER JOIN tasks_tdeps_view _transitive
USING ( task_id )
INNER JOIN tasks_ideps_view _inherited
USING ( task_id )
INNER JOIN tasks_sdeps_view _subs
USING ( task_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;
LEFT OUTER JOIN users_view u3 ON u3.user_id = ct.user_id;
GRANT SELECT ON tasks_list TO :webapp_user;

View file

@ -0,0 +1,601 @@
--
-- Upgrade the database from commit ID 91ae4f81fd406a2a788320b9e71603040de77b70
--
-- Run this from the top-level directory
--
\i database/config.sql
\c :db_name
BEGIN;
CREATE TABLE tasks_tree (
task_id_parent INT NOT NULL
REFERENCES tasks( task_id )
ON UPDATE NO ACTION
ON DELETE CASCADE ,
task_id_child INT NOT NULL
REFERENCES tasks( task_id )
ON UPDATE NO ACTION
ON DELETE CASCADE ,
tt_depth INT NOT NULL,
PRIMARY KEY( task_id_parent , task_id_child )
);
GRANT SELECT ON tasks_tree TO :webapp_user;
DROP FUNCTION tgf_item_tc_ai( ) CASCADE;
DROP FUNCTION tgf_task_tc_ai( ) CASCADE;
ALTER TABLE tasks
ADD item_id INT REFERENCES items ( item_id )
ON UPDATE NO ACTION ON DELETE CASCADE ,
ADD task_id_parent INT;
CREATE FUNCTION tasks_tree_ai( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
SECURITY DEFINER
AS $tasks_tree_ai$
BEGIN
INSERT INTO logical_task_containers ( task_id )
VALUES ( NEW.task_id );
INSERT INTO tasks_tree( task_id_parent , task_id_child , tt_depth )
VALUES ( NEW.task_id , NEW.task_id , 0 );
INSERT INTO tasks_tree( task_id_parent , task_id_child , tt_depth )
SELECT x.task_id_parent, NEW.task_id, x.tt_depth + 1
FROM tasks_tree x WHERE x.task_id_child = NEW.task_id_parent;
RETURN NEW;
END;
$tasks_tree_ai$;
REVOKE EXECUTE
ON FUNCTION tasks_tree_ai( )
FROM PUBLIC;
CREATE TRIGGER tasks_tree_ai
AFTER INSERT ON tasks
FOR EACH ROW EXECUTE PROCEDURE tasks_tree_ai( );
CREATE FUNCTION tasks_tree_bu( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
SECURITY DEFINER
AS $tasks_tree_bu$
BEGIN
PERFORM 1 FROM tasks_tree
WHERE ( task_id_parent , task_id_child ) = ( NEW.task_id , NEW.task_id_parent );
IF FOUND THEN
RAISE EXCEPTION 'Update blocked, it would create a loop.';
END IF;
RETURN NEW;
END;
$tasks_tree_bu$;
REVOKE EXECUTE
ON FUNCTION tasks_tree_bu( )
FROM PUBLIC;
CREATE TRIGGER tasks_tree_bu
BEFORE UPDATE OF task_id_parent ON tasks
FOR EACH ROW EXECUTE PROCEDURE tasks_tree_bu( );
CREATE FUNCTION tasks_tree_au( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
SECURITY DEFINER
AS $tasks_tree_au$
BEGIN
-- Remove existing lineage for the updated object and its children
IF OLD.task_id_parent IS NOT NULL THEN
DELETE FROM tasks_tree AS te2
USING tasks_tree te1
WHERE te2.task_id_child = te1.task_id_child
AND te1.task_id_parent = NEW.task_id
AND te2.tt_depth > te1.tt_depth;
END IF;
-- Create new lineage
IF NEW.task_id_parent IS NOT NULL THEN
INSERT INTO tasks_tree ( task_id_parent , task_id_child , tt_depth )
SELECT te1.task_id_parent , te2.task_id_child , te1.tt_depth + te2.tt_depth + 1
FROM tasks_tree te1 , tasks_tree te2
WHERE te1.task_id_child = NEW.task_id_parent
AND te2.task_id_parent = NEW.task_id;
UPDATE tasks t1
SET item_id = t2.item_id
FROM tasks t2
WHERE t1.task_id = NEW.task_id
AND t2.task_id = NEW.task_id_parent;
END IF;
RETURN NEW;
END;
$tasks_tree_au$;
REVOKE EXECUTE
ON FUNCTION tasks_tree_au( )
FROM PUBLIC;
CREATE TRIGGER tasks_tree_au
AFTER UPDATE OF task_id_parent ON tasks
FOR EACH ROW EXECUTE PROCEDURE tasks_tree_au( );
CREATE FUNCTION tasks_item_au( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
SECURITY DEFINER
AS $tasks_item_au$
BEGIN
UPDATE tasks
SET item_id = NEW.item_id
WHERE task_id_parent = NEW.task_id;
RETURN NEW;
END;
$tasks_item_au$;
REVOKE EXECUTE
ON FUNCTION tasks_item_au( )
FROM PUBLIC;
CREATE TRIGGER tasks_item_au
AFTER UPDATE OF item_id ON tasks
FOR EACH ROW EXECUTE PROCEDURE tasks_item_au( );
DROP INDEX i_tasks_title;
INSERT INTO tasks_tree
SELECT task_id, task_id , 0
FROM tasks;
UPDATE tasks t
SET task_id_parent = tc.task_id
FROM task_containers tc
WHERE tc.tc_id = t.tc_id;
UPDATE tasks t
SET item_id = tc.item_id
FROM task_containers tc
WHERE tc.tc_id = t.tc_id AND tc.item_id IS NOT NULL;
ALTER TABLE tasks
ALTER item_id SET NOT NULL;
CREATE UNIQUE INDEX i_tasks_title_toplevel
ON tasks ( item_id , task_title )
WHERE task_id_parent IS NULL;
CREATE UNIQUE INDEX i_tasks_title_subtask
ON tasks ( task_id_parent , task_title )
WHERE task_id_parent IS NULL;
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
_logical_container INT;
BEGIN
SELECT INTO _logical_container ltc_id
FROM logical_task_containers
WHERE task_id IS NULL;
INSERT INTO tasks ( item_id , ltc_id , task_title , task_description , task_priority , user_id )
VALUES ( t_item , _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;
DROP FUNCTION 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
_item INT;
_logical_container INT;
BEGIN
SELECT INTO _item item_id
FROM tasks t
LEFT OUTER JOIN completed_tasks ct USING ( task_id )
WHERE t.task_id = t_parent AND ct.task_id IS NULL
FOR UPDATE OF t;
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 ( task_id_parent , item_id , ltc_id , task_title , task_description , task_priority , user_id )
VALUES ( t_parent , _item , _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_single_view t
WHERE task_id = t_id AND badness = 0;
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;
PERFORM 1 FROM items
WHERE item_id = p_id
FOR UPDATE;
IF NOT FOUND THEN
RETURN 2;
END IF;
IF t_assignee = 0 THEN
t_assignee := NULL;
END IF;
UPDATE tasks SET item_id = p_id , 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;
DROP FUNCTION 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
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_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.item_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 item_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;
DROP FUNCTION 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 item_id FROM tasks
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 item_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_deps_view
AS SELECT t.task_id , COUNT( td ) AS deps_total ,
COUNT( NULLIF( td IS NOT NULL AND dct IS NULL , FALSE ) ) AS deps_unsatisfied
FROM tasks t
LEFT OUTER JOIN task_dependencies td
USING ( task_id )
LEFT OUTER JOIN completed_tasks dct
ON dct.task_id = td.task_id_depends
GROUP BY t.task_id;
CREATE VIEW tasks_tdeps_view
AS SELECT t.task_id , COUNT( DISTINCT task_id_copyof ) AS tdeps_total ,
COUNT( DISTINCT ( CASE
WHEN tdn.task_id_copyof IS NOT NULL AND ct.task_id IS NULL
THEN tdn.task_id_copyof
ELSE NULL
END ) ) AS tdeps_unsatisfied
FROM tasks t
LEFT OUTER JOIN taskdep_nodes tdn
ON NOT tdn.tnode_reverse AND tdn.task_id = t.task_id
AND tdn.task_id_copyof <> tdn.task_id
LEFT OUTER JOIN completed_tasks ct
ON ct.task_id = tdn.task_id_copyof
GROUP BY t.task_id;
CREATE VIEW tasks_ideps_view
AS SELECT task_id_child AS task_id ,
SUM( deps_total ) AS ideps_total ,
SUM( deps_unsatisfied ) AS ideps_unsatisfied ,
SUM( tdeps_total ) AS tideps_total ,
SUM( tdeps_unsatisfied ) AS tideps_unsatisfied
FROM tasks_tree tt
INNER JOIN tasks_deps_view td
ON td.task_id = tt.task_id_parent
INNER JOIN tasks_tdeps_view ttd
ON ttd.task_id = tt.task_id_parent
GROUP BY task_id_child;
CREATE VIEW tasks_sdeps_view
AS SELECT t.task_id AS task_id ,
COUNT( st ) AS sdeps_total ,
COUNT( NULLIF( st.task_id IS NOT NULL AND sct.task_id IS NULL , FALSE ) ) AS sdeps_unsatisfied
FROM tasks t
LEFT OUTER JOIN tasks st
ON st.task_id_parent = t.task_id
LEFT OUTER JOIN completed_tasks sct
ON sct.task_id = st.task_id
GROUP BY t.task_id;
DROP VIEW tasks_single_view;
CREATE VIEW tasks_single_view
AS SELECT t.task_id AS id, t.task_title AS title, t.item_id AS item , t.task_id_parent 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 ,
( _inherited.ideps_unsatisfied + _direct.deps_unsatisfied + _subs.sdeps_unsatisfied ) AS badness
FROM tasks t
INNER JOIN tasks_deps_view _direct
USING ( task_id )
INNER JOIN tasks_tdeps_view _transitive
USING ( task_id )
INNER JOIN tasks_ideps_view _inherited
USING ( task_id )
INNER JOIN tasks_sdeps_view _subs
USING ( task_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;
DROP VIEW tasks_list;
CREATE VIEW tasks_list
AS SELECT t.task_id AS id, t.item_id AS item , t.task_id_parent 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 ,
_direct.deps_total AS total_direct_dependencies ,
_direct.deps_unsatisfied AS unsatisfied_direct_dependencies ,
_transitive.tdeps_total AS total_transitive_dependencies ,
_transitive.tdeps_unsatisfied AS unsatisfied_transitive_dependencies ,
_subs.sdeps_total AS total_subtasks ,
_subs.sdeps_unsatisfied AS incomplete_subtasks ,
( CASE
WHEN _direct.deps_total <> 0 THEN
0
ELSE
_inherited.ideps_total
END ) AS total_inherited_dependencies ,
( CASE
WHEN _direct.deps_total <> 0 THEN
0
ELSE
_inherited.ideps_unsatisfied
END ) AS unsatisfied_inherited_dependencies ,
( _inherited.ideps_unsatisfied + _direct.deps_unsatisfied + _subs.sdeps_unsatisfied ) AS badness
FROM tasks t
INNER JOIN tasks_deps_view _direct
USING ( task_id )
INNER JOIN tasks_tdeps_view _transitive
USING ( task_id )
INNER JOIN tasks_ideps_view _inherited
USING ( task_id )
INNER JOIN tasks_sdeps_view _subs
USING ( task_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;
GRANT SELECT ON tasks_list TO :webapp_user;
ALTER TABLE tasks
DROP COLUMN tc_id;
DROP TABLE task_containers;
COMMIT;

View file

@ -175,10 +175,10 @@ class DAO_Items
}
$query = $this->query(
'SELECT p.item_id , p.item_name , p.item_description , COUNT(*) AS t_count '
'SELECT p.item_id , p.item_name , p.item_description , COUNT(*) AS t_count_all , '
. 'COUNT( NULLIF( t.task_id_parent IS NULL , FALSE ) ) AS t_count '
. 'FROM items p '
. 'INNER JOIN task_containers USING ( item_id ) '
. 'INNER JOIN tasks t USING( tc_id ) '
. 'INNER JOIN tasks t USING( item_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' );
@ -193,6 +193,7 @@ class DAO_Items
$this->loaded[ $entry->item_id ] = $object;
}
$object->activeTasks = $entry->t_count;
$object->activeTasksTotal = $entry->t_count_all;
}
$this->activeTasksCounted = true;

View file

@ -27,15 +27,14 @@ class DAO_Tasks
. 'priority '
. 'ELSE '
. '-1 '
. 'END ) DESC , total_missing_dependencies ASC NULLS FIRST , added_at DESC' )->execute( );
. 'END ) DESC , badness , added_at DESC' )->execute( );
}
public function getAllActiveTasks( )
{
return $this->query(
'SELECT * FROM tasks_list '
. 'WHERE completed_at IS NULL AND missing_dependencies IS NULL '
. 'AND missing_subtasks IS NULL '
. 'WHERE completed_at IS NULL AND badness = 0 '
. 'ORDER BY priority DESC , added_at DESC' )->execute( );
}
@ -43,9 +42,8 @@ class DAO_Tasks
{
return $this->query(
'SELECT * FROM tasks_list '
. '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( );
. 'WHERE badness <> 0 '
. 'ORDER BY priority DESC , badness , added_at DESC' )->execute( );
}
@ -53,13 +51,13 @@ class DAO_Tasks
{
return $this->query(
'SELECT * FROM tasks_list '
. 'WHERE item = $1 '
. 'WHERE item = $1 AND parent_task IS NULL '
. 'ORDER BY ( CASE '
. 'WHEN completed_at IS NULL THEN '
. 'priority '
. 'ELSE '
. '-1 '
. 'END ) DESC , total_missing_dependencies ASC NULLS FIRST , added_at DESC'
. 'END ) DESC , badness , added_at DESC'
)->execute( $item->id );
}
@ -69,7 +67,7 @@ class DAO_Tasks
return $this->query(
'SELECT * FROM tasks_list '
. 'WHERE assigned_to_id = $1 '
. 'ORDER BY priority DESC , missing_dependencies ASC NULLS FIRST , added_at DESC'
. 'ORDER BY priority DESC , badness , added_at DESC'
)->execute( $user->user_id );
}
@ -113,48 +111,67 @@ class DAO_Tasks
. 'priority '
. 'ELSE '
. '-1 '
. 'END ) DESC , missing_dependencies ASC NULLS FIRST , added_at DESC'
. 'END ) DESC , badness , 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 , tc.item_id AS item , '
'SELECT t.task_id AS id , t.task_title AS title , t.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 '
. 'tl.badness AS missing_dependencies '
. 'FROM task_dependencies td '
. 'INNER JOIN tasks t ON t.task_id = td.task_id_depends '
. '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 , tc.item_id AS item , '
'SELECT t.task_id AS id , t.task_title AS title , t.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 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 , tc.item_id AS item , '
'SELECT t.task_id AS id , t.task_title AS title , t.item_id AS item , '
. 'i.item_name AS item_name '
. 'FROM tasks_possible_dependencies( $1 ) t '
. '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 );
$task->lineage = null;
return $task;
}
public function getLineage( $task )
{
if ( ! in_array( 'lineage' , get_object_vars( $task ) ) || $task->lineage === null ) {
$result = $this->query(
'SELECT task_id , task_title '
. 'FROM tasks_tree tt '
. 'INNER JOIN tasks '
. 'ON task_id = tt.task_id_parent '
. 'WHERE task_id_child = $1 AND tt_depth > 0 '
. 'ORDER BY tt_depth DESC'
)->execute( $task->id );
$task->lineage = array( );
foreach ( $result as $row ) {
array_push( $task->lineage , array( $row->task_id , $row->task_title ) );
}
}
return $task->lineage;
}
public function canDelete( $task )
{
if ( $task->completed_by !== null ) {
@ -169,17 +186,7 @@ class DAO_Tasks
public function canFinish( $task )
{
assert( $task->completed_at == null );
foreach ( $task->dependencies as $dependency ) {
if ( $dependency->completed != 't' ) {
return false;
}
}
foreach ( $task->subtasks as $subtask ) {
if ( $subtask->completed_at === null ) {
return false;
}
}
return true;
return ( $task->badness == 0 );
}

View file

@ -11,7 +11,8 @@ class Data_Item
public $depth;
public $lineage;
public $activeTasks;
public $activeTasks = 0;
public $activeTasksTotal = 0;
public $inactiveTasks;
public function __construct( $id , $name )

View file

@ -48,9 +48,12 @@ class View_ItemsTree
->appendElement( HTML::make( 'a' )
->setAttribute( 'href' , $this->base . '/items/view?id=' . $item->id )
->appendText( $item->name ) ) )
->appendElement( HTML::make( 'td' )
->appendElement( $tasks = HTML::make( 'td' )
->setAttribute( 'class' , 'align-right' )
->appendRaw( (int) $item->activeTasks ) ) );
->appendRaw( $item->activeTasks ) ) );
if ( $item->activeTasksTotal != $item->activeTasks ) {
$tasks->appendText( " ({$item->activeTasksTotal})" );
}
foreach ( $children as $child ) {
$this->renderItem( $table , $child );

View file

@ -98,16 +98,16 @@ class Ctrl_TaskDetails
$bTitle = "Active task";
}
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 );
$items = Loader::DAO( 'items' );
$tasks = Loader::DAO( 'tasks' );
$items->getLineage( $this->task->item = $items->get( $this->task->item ) );
if ( $this->task->parent_task !== null ) {
$this->task->parent_task = $tasks->get( $this->task->parent_task );
}
$box = Loader::View( 'box' , $bTitle , Loader::View( 'task_details' , $this->task ) );
$tasks = Loader::DAO( 'tasks' );
if ( $this->task->completed_by === null ) {
$box->addButton( BoxButton::create( 'Edit task' , 'tasks/edit?id=' . $this->task->id )
->setClass( 'icon edit' ) );
@ -138,7 +138,7 @@ class Ctrl_TaskDetails
$timestamp = strtotime( $this->task->completed_at );
}
if ( Loader::DAO( 'tasks' )->canDelete( $this->task ) ) {
if ( $tasks->canDelete( $this->task ) ) {
$box->addButton( BoxButton::create( 'Delete' , 'tasks/delete?id=' . $this->task->id )
->setClass( 'icon delete' ) );
}

View file

@ -287,9 +287,9 @@ class Ctrl_EditTaskForm
->addField( Loader::Create( 'Field' , 'id' , 'hidden' )
->setDefaultValue( $task->id ) )
->addField( Loader::Create( 'Field' , 'nested' , 'hidden' )
->setDefaultValue( $task->item === null ? 1 : 0 ) );
->setDefaultValue( $task->parent_task === null ? 0 : 1 ) );
if ( $task->item !== null ) {
if ( $task->parent_task === null ) {
$form->addField( $this->createItemSelector( )
->setDefaultValue( $task->item ) );
}
@ -457,7 +457,7 @@ class Ctrl_DependencyAddForm
$form = Loader::Create( 'Form' , 'Add dependency' , 'add-dep' )
->addField( Loader::Create( 'Field' , 'to' , 'hidden' )
->setDefaultValue( $id ) );
$this->addDependencySelector( $form , $task->possibleDependencies , $task->item !== null );
$this->addDependencySelector( $form , $task->possibleDependencies , $task->parent_task === null );
return $form->setURL( 'tasks/view?id=' . $id )
->addController( Loader::Ctrl( 'dependency_add' ) )
->controller( );

View file

@ -72,12 +72,15 @@ class View_TasksList
if ( $task->completed_by !== null ) {
$this->generateCompletedTask( $cell , $classes , $task );
} else {
if ( $task->missing_dependencies !== null ) {
if ( $task->unsatisfied_direct_dependencies > 0 ) {
$this->generateMissingDependencies( $cell , $classes , $task );
}
if ( $task->missing_subtasks !== null ) {
if ( $task->incomplete_subtasks > 0 ) {
$this->generateMissingSubtasks( $cell , $classes , $task );
}
if ( $task->unsatisfied_inherited_dependencies > 0 ) {
$this->generateMissingInherited( $cell , $classes , $task );
}
if ( $task->assigned_to !== null ) {
$this->generateAssignedTask( $cell , $classes , $task );
}
@ -98,9 +101,8 @@ class View_TasksList
return;
}
if ( $task->item !== null ) {
$this->addItem( $cell , $task );
} else {
$this->addItem( $cell , $task );
if ( $task->parent_task !== null ) {
$this->addParentTask( $cell , $task );
}
}
@ -128,13 +130,21 @@ class View_TasksList
protected function addParentTask( &$cell , $task )
{
$parent = $this->dao->get( $task->parent_task );
$parents = $this->dao->getLineage( $task );
$contents = array( );
foreach ( $parents as $parent ) {
list( $id , $title ) = $parent;
if ( ! empty( $contents ) ) {
array_push( $contents , ' &raquo; ' );
}
array_push( $contents , HTML::make( 'a' )
->setAttribute( 'href' , $this->base . '/tasks/view?id=' . $id )
->appendText( $title ) );
}
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 ) ) );
->append( $contents ) );
}
protected function generateMissingDependencies( &$cell , &$classes , $task )
@ -143,15 +153,15 @@ class View_TasksList
return;
}
if ( $task->missing_dependencies > 1 ) {
if ( $task->unsatisfied_direct_dependencies > 1 ) {
$end = 'ies';
} else {
$end = 'y';
}
array_push( $cell ,
$md = HTML::make( 'dd' )->appendText( "{$task->missing_dependencies} missing dependenc$end" ) );
if ( $task->total_missing_dependencies != $task->missing_dependencies ) {
$md->appendText( " ({$task->total_missing_dependencies} when counting transitive dependencies)" );
$md = HTML::make( 'dd' )->appendText( "{$task->unsatisfied_direct_dependencies} missing dependenc$end" ) );
if ( $task->unsatisfied_direct_dependencies != $task->unsatisfied_transitive_dependencies ) {
$md->appendText( " ({$task->unsatisfied_transitive_dependencies} when counting transitive dependencies)" );
}
array_push( $classes , 'missing-deps' );
@ -163,13 +173,30 @@ class View_TasksList
return;
}
if ( $task->missing_subtasks > 1 ) {
if ( $task->incomplete_subtasks > 1 ) {
$end = 's';
} else {
$end = '';
}
array_push( $cell ,
$md = HTML::make( 'dd' )->appendText( "{$task->missing_subtasks} incomplete sub-task$end" ) );
array_push( $cell , HTML::make( 'dd' )->appendText(
"{$task->incomplete_subtasks} incomplete sub-task$end (out of {$task->total_subtasks})" ) );
array_push( $classes , 'missing-deps' );
}
protected function generateMissingInherited( &$cell , &$classes , $task )
{
if ( ! array_key_exists( 'deps' , $this->features ) ) {
return;
}
if ( $task->unsatisfied_inherited_dependencies > 1 ) {
$end = 'ies';
} else {
$end = 'y';
}
array_push( $cell , HTML::make( 'dd' )->appendText(
"{$task->unsatisfied_inherited_dependencies} unsatisfied dependenc$end in parent task(s)" ) );
array_push( $classes , 'missing-deps' );
}
@ -213,21 +240,28 @@ class View_TaskDetails
public function render( )
{
$list = HTML::make( 'dl' )
->setAttribute( 'class' , 'tasks' );
->setAttribute( 'class' , 'tasks' )
->appendElement( HTML::make( 'dt' )
->appendText( 'On item:' ) )
->appendElement( HTML::make( 'dd' )
->append( $this->formatPlaceLineage( $this->task->item ) ) );
if ( $this->task->item !== null ) {
$list->appendElement( HTML::make( 'dt' )
->appendText( 'On item:' ) )
->appendElement( HTML::make( 'dd' )
->append( $this->formatPlaceLineage( $this->task->item ) ) );
} else {
if ( $this->task->parent_task !== null ) {
$parents = Loader::DAO( 'tasks' )->getLineage( $this->task );
$contents = array( );
foreach ( $parents as $parent ) {
list( $id , $title ) = $parent;
if ( ! empty( $contents ) ) {
array_push( $contents , ' &raquo; ' );
}
array_push( $contents , HTML::make( 'a' )
->setAttribute( 'href' , $this->base . '/tasks/view?id=' . $id )
->appendText( $title ) );
}
$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 ) ) );
->append( $contents ) );
}
if ( $this->task->description != '' ) {