Initial import of tasks application

This initial import is a heavily modified version of the code I had
here, as Arse was modified for other purposes in the meantime and the
application no longer worked with it.

In addition:
 * I did not import the user management part yet,
 * task dependencies are supported in-base, but there is no interface
for that yet.
This commit is contained in:
Emmanuel BENOîT 2012-02-05 18:37:25 +01:00
commit 9677ad4dd3
36 changed files with 3919 additions and 0 deletions

View file

@ -0,0 +1,2 @@
\set webapp_user test
\set db_name test

133
database/create-tables.sql Normal file
View file

@ -0,0 +1,133 @@
-- Sequences
CREATE SEQUENCE items_item_id_seq INCREMENT 1
MINVALUE 1 MAXVALUE 9223372036854775807
START 1 CACHE 1;
GRANT SELECT,UPDATE ON items_item_id_seq TO :webapp_user;
CREATE SEQUENCE users_user_id_seq INCREMENT 1
MINVALUE 1 MAXVALUE 9223372036854775807
START 1 CACHE 1;
GRANT SELECT,UPDATE ON users_user_id_seq TO :webapp_user;
CREATE SEQUENCE tasks_task_id_seq INCREMENT 1
MINVALUE 1 MAXVALUE 9223372036854775807
START 1 CACHE 1;
GRANT SELECT,UPDATE ON tasks_task_id_seq TO :webapp_user;
CREATE SEQUENCE notes_note_id_seq INCREMENT 1
MINVALUE 1 MAXVALUE 9223372036854775807
START 1 CACHE 1;
GRANT SELECT,UPDATE ON notes_note_id_seq TO :webapp_user;
CREATE SEQUENCE task_dependencies_taskdep_id_seq INCREMENT 1
MINVALUE 1 MAXVALUE 9223372036854775807
START 1 CACHE 1;
-- Tables
-- Table items
CREATE TABLE items (
item_id INT NOT NULL DEFAULT NEXTVAL('items_item_id_seq'::TEXT),
item_name VARCHAR(128) NOT NULL,
item_id_parent INT,
item_ordering INT NOT NULL,
PRIMARY KEY(item_id)
);
CREATE UNIQUE INDEX i_items_unicity ON items (item_name,item_id_parent);
CREATE UNIQUE INDEX i_items_ordering ON items (item_ordering);
-- Make sure top-level items are unique
CREATE UNIQUE INDEX i_items_top_unicity
ON items ( item_name )
WHERE item_id_parent IS NULL;
ALTER TABLE items ADD FOREIGN KEY (item_id_parent)
REFERENCES items(item_id) ON UPDATE NO ACTION ON DELETE CASCADE;
GRANT SELECT,INSERT,UPDATE,DELETE ON items TO :webapp_user;
-- Table users
CREATE TABLE users (
user_id INT NOT NULL DEFAULT NEXTVAL('users_user_id_seq'::TEXT),
user_email VARCHAR(256) NOT NULL,
user_salt CHAR(8) NOT NULL,
user_iterations INT NOT NULL,
user_hash CHAR(40) NOT NULL,
PRIMARY KEY(user_id)
);
CREATE UNIQUE INDEX i_users_user_email ON users (LOWER(user_email));
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,
PRIMARY KEY(task_id)
);
CREATE UNIQUE INDEX i_tasks_item_id_task_title ON tasks (item_id,task_title);
GRANT SELECT,INSERT,UPDATE,DELETE ON tasks TO :webapp_user;
-- Table items_tree
CREATE TABLE items_tree (
item_id_parent INT NOT NULL REFERENCES items(item_id) ON UPDATE NO ACTION ON DELETE CASCADE,
item_id_child INT NOT NULL REFERENCES items(item_id) ON UPDATE NO ACTION ON DELETE CASCADE,
pt_depth INT NOT NULL,
PRIMARY KEY(item_id_parent,item_id_child)
);
GRANT SELECT ON items_tree TO :webapp_user;
-- Table completed_tasks
CREATE TABLE completed_tasks (
task_id INT NOT NULL REFERENCES tasks(task_id) ON UPDATE NO ACTION ON DELETE CASCADE,
completed_task_time TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT now(),
user_id INT NOT NULL REFERENCES users(user_id) ON UPDATE NO ACTION ON DELETE CASCADE,
PRIMARY KEY(task_id)
);
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,
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);
GRANT SELECT,INSERT,DELETE ON task_dependencies TO :webapp_user;
-- Table notes
CREATE TABLE notes (
note_id INT NOT NULL DEFAULT NEXTVAL('notes_note_id_seq'::TEXT),
task_id INT NOT NULL REFERENCES tasks(task_id) ON UPDATE NO ACTION ON DELETE CASCADE,
user_id INT NOT NULL REFERENCES users(user_id) ON UPDATE NO ACTION ON DELETE CASCADE,
note_added TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT now(),
note_text TEXT NOT NULL,
PRIMARY KEY(note_id)
);
GRANT SELECT,INSERT,UPDATE,DELETE ON notes TO :webapp_user;

View file

@ -0,0 +1,276 @@
--
-- Re-order items
-- * first create a temporary table containing text paths
-- * use that temporary table to re-order the main table
--
CREATE OR REPLACE FUNCTION reorder_items( )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
i_id INT;
i_parent INT;
i_ordering INT;
i_path TEXT;
BEGIN
-- Create and fill temporary table
CREATE TEMPORARY TABLE items_ordering (
item_id INT NOT NULL PRIMARY KEY ,
item_ordering_path TEXT NOT NULL
) ON COMMIT DROP;
FOR i_id , i_parent , i_ordering IN
SELECT p.item_id , p.item_id_parent , p.item_ordering
FROM items p
INNER JOIN items_tree pt
ON pt.item_id_child = p.item_id
GROUP BY p.item_id , p.item_id_parent , p.item_ordering
ORDER BY MAX( pt.pt_depth )
LOOP
IF i_parent IS NULL THEN
i_path := '';
ELSE
SELECT INTO i_path item_ordering_path || '/' FROM items_ordering WHERE item_id = i_parent;
END IF;
i_path := i_path || to_char( i_ordering , '000000000000' );
INSERT INTO items_ordering VALUES ( i_id , i_path );
END LOOP;
-- Move all rows out of the way
UPDATE items SET item_ordering = item_ordering + (
SELECT 1 + 2 * max( item_ordering ) FROM items );
-- Re-order items
UPDATE items p1 SET item_ordering = 2 * p2.rn
FROM ( SELECT item_id , row_number() OVER( ORDER BY item_ordering_path ) AS rn FROM items_ordering ) p2
WHERE p1.item_id = p2.item_id;
END;
$$ LANGUAGE plpgsql;
-- Insert a item before another
CREATE OR REPLACE FUNCTION insert_item_before( i_name TEXT , i_before INT )
RETURNS INT
STRICT VOLATILE
SECURITY DEFINER
AS $insert_item_before$
DECLARE
i_ordering INT;
i_parent INT;
BEGIN
PERFORM 1 FROM items FOR UPDATE;
SELECT INTO i_ordering , i_parent item_ordering - 1 , item_id_parent
FROM items
WHERE item_id = i_before;
IF NOT FOUND THEN
RETURN 2;
END IF;
BEGIN
INSERT INTO items ( item_name , item_id_parent , item_ordering )
VALUES ( i_name , i_parent , i_ordering );
EXCEPTION
WHEN unique_violation THEN
RETURN 1;
END;
PERFORM reorder_items( );
RETURN 0;
END;
$insert_item_before$ LANGUAGE plpgsql;
-- Insert item as the last child of another
CREATE OR REPLACE FUNCTION insert_item_under( i_name TEXT , i_parent INT )
RETURNS INT
STRICT VOLATILE
SECURITY DEFINER
AS $insert_item_under$
DECLARE
i_ordering INT;
BEGIN
PERFORM 1 FROM items FOR UPDATE;
SELECT INTO i_ordering max( item_ordering ) + 1 FROM items;
BEGIN
INSERT INTO items ( item_name , item_id_parent , item_ordering )
VALUES ( i_name , i_parent , i_ordering );
EXCEPTION
WHEN unique_violation THEN
RETURN 1;
WHEN foreign_key_violation THEN
RETURN 2;
END;
PERFORM reorder_items( );
RETURN 0;
END;
$insert_item_under$ LANGUAGE plpgsql;
-- Add a item as the last root element
CREATE OR REPLACE FUNCTION insert_item_last( i_name TEXT )
RETURNS INT
STRICT VOLATILE
SECURITY DEFINER
AS $insert_item_last$
DECLARE
i_ordering INT;
BEGIN
PERFORM 1 FROM items FOR UPDATE;
SELECT INTO i_ordering max( item_ordering ) + 1 FROM items;
IF i_ordering IS NULL THEN
i_ordering := 0;
END IF;
BEGIN
INSERT INTO items ( item_name , item_ordering )
VALUES ( i_name , i_ordering );
EXCEPTION
WHEN unique_violation THEN
RETURN 1;
END;
PERFORM reorder_items( );
RETURN 0;
END;
$insert_item_last$ LANGUAGE plpgsql;
-- Rename a item
CREATE OR REPLACE FUNCTION rename_item( i_id INT , i_name TEXT )
RETURNS INT
STRICT VOLATILE
SECURITY DEFINER
AS $rename_item$
BEGIN
UPDATE items SET item_name = $2 WHERE item_id = $1;
RETURN 0;
EXCEPTION
WHEN unique_violation THEN
RETURN 1;
END
$rename_item$ LANGUAGE plpgsql;
-- Move a item before another
CREATE OR REPLACE FUNCTION move_item_before( i_id INT , i_before INT )
RETURNS INT
STRICT VOLATILE
SECURITY DEFINER
AS $move_item_before$
DECLARE
i_ordering INT;
i_parent INT;
BEGIN
PERFORM 1 FROM items FOR UPDATE;
IF i_before = i_id THEN
RETURN 1;
ELSE
SELECT INTO i_ordering , i_parent item_ordering - 1 , item_id_parent
FROM items
WHERE item_id = i_before;
IF NOT FOUND THEN
RETURN 2;
END IF;
END IF;
BEGIN
UPDATE items SET item_ordering = i_ordering , item_id_parent = i_parent
WHERE item_id = i_id;
EXCEPTION
WHEN unique_violation THEN
RETURN 1;
END;
PERFORM reorder_items( );
RETURN 0;
END;
$move_item_before$ LANGUAGE plpgsql;
-- Move a item at the end of another's children
CREATE OR REPLACE FUNCTION move_item_under( i_id INT , i_parent INT )
RETURNS INT
STRICT VOLATILE
SECURITY DEFINER
AS $move_item_under$
DECLARE
i_ordering INT;
BEGIN
PERFORM 1 FROM items FOR UPDATE;
IF i_parent = i_id THEN
RETURN 1;
ELSE
SELECT INTO i_ordering MAX( item_ordering ) + 1
FROM items
WHERE item_id_parent = i_parent;
IF i_ordering IS NULL THEN
i_ordering := 1;
END IF;
END IF;
BEGIN
UPDATE items SET item_ordering = i_ordering , item_id_parent = i_parent
WHERE item_id = i_id;
EXCEPTION
WHEN unique_violation THEN
RETURN 1;
WHEN foreign_key_violation THEN
RETURN 2;
END;
PERFORM reorder_items( );
RETURN 0;
END;
$move_item_under$ LANGUAGE plpgsql;
-- Move a item to the end of the tree
CREATE OR REPLACE FUNCTION move_item_last( i_id INT )
RETURNS INT
STRICT VOLATILE
SECURITY DEFINER
AS $move_item_last$
DECLARE
i_ordering INT;
BEGIN
PERFORM 1 FROM items FOR UPDATE;
SELECT INTO i_ordering MAX( item_ordering ) + 1
FROM items;
IF i_ordering IS NULL THEN
i_ordering := 0;
END IF;
BEGIN
UPDATE items SET item_ordering = i_ordering , item_id_parent = NULL
WHERE item_id = i_id;
EXCEPTION
WHEN unique_violation THEN
RETURN 1;
END;
PERFORM reorder_items( );
RETURN 0;
END;
$move_item_last$ LANGUAGE plpgsql;
-- Delete a item, moving all children to the item's parent
CREATE OR REPLACE FUNCTION delete_item( i_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $delete_item$
DECLARE
i_parent INT;
BEGIN
PERFORM 1 FROM items FOR UPDATE;
DELETE FROM items WHERE item_id = i_id;
PERFORM reorder_items( );
END;
$delete_item$ LANGUAGE plpgsql;

View file

@ -0,0 +1,93 @@
--
-- Insert tree data for new rows
--
CREATE OR REPLACE FUNCTION items_tree_ai( )
RETURNS TRIGGER
SECURITY DEFINER
AS $items_tree_ai$
BEGIN
INSERT INTO items_tree( item_id_parent , item_id_child , pt_depth )
VALUES ( NEW.item_id , NEW.item_id , 0 );
INSERT INTO items_tree( item_id_parent , item_id_child , pt_depth )
SELECT x.item_id_parent, NEW.item_id, x.pt_depth + 1
FROM items_tree x WHERE x.item_id_child = NEW.item_id_parent;
RETURN NEW;
END;
$items_tree_ai$ LANGUAGE 'plpgsql';
CREATE TRIGGER items_tree_ai
AFTER INSERT ON items FOR EACH ROW
EXECUTE PROCEDURE items_tree_ai( );
--
-- Make sure the changes are OK before updating
--
CREATE OR REPLACE FUNCTION items_tree_bu( )
RETURNS TRIGGER
SECURITY DEFINER
AS $items_tree_bu$
BEGIN
IF NEW.item_id <> OLD.item_id THEN
RAISE EXCEPTION 'Changes to identifiers are forbidden.';
END IF;
IF NOT OLD.item_id_parent IS DISTINCT FROM NEW.item_id_parent THEN
RETURN NEW;
END IF;
PERFORM 1 FROM items_tree
WHERE ( item_id_parent , item_id_child ) = ( NEW.item_id , NEW.item_id_parent );
IF FOUND THEN
RAISE EXCEPTION 'Update blocked, it would create a loop.';
END IF;
RETURN NEW;
END;
$items_tree_bu$ LANGUAGE 'plpgsql';
CREATE TRIGGER items_tree_bu
BEFORE UPDATE ON items FOR EACH ROW
EXECUTE PROCEDURE items_tree_bu( );
--
-- Update tree data when a row's parent is changed
--
CREATE OR REPLACE FUNCTION items_tree_au( )
RETURNS TRIGGER
SECURITY DEFINER
AS $items_tree_au$
BEGIN
IF NOT OLD.item_id_parent IS DISTINCT FROM NEW.item_id_parent THEN
RETURN NEW;
END IF;
-- Remove existing lineage for the updated object and its children
IF OLD.item_id_parent IS NOT NULL THEN
DELETE FROM items_tree AS te2
USING items_tree te1
WHERE te2.item_id_child = te1.item_id_child
AND te1.item_id_parent = NEW.item_id
AND te2.pt_depth > te1.pt_depth;
END IF;
-- Create new lineage
IF NEW.item_id_parent IS NOT NULL THEN
INSERT INTO items_tree ( item_id_parent , item_id_child , pt_depth )
SELECT te1.item_id_parent , te2.item_id_child , te1.pt_depth + te2.pt_depth + 1
FROM items_tree te1 , items_tree te2
WHERE te1.item_id_child = NEW.item_id_parent
AND te2.item_id_parent = NEW.item_id;
END IF;
RETURN NEW;
END;
$items_tree_au$ LANGUAGE 'plpgsql';
CREATE TRIGGER items_tree_au
AFTER UPDATE ON items FOR EACH ROW
EXECUTE PROCEDURE items_tree_au( );

View file

@ -0,0 +1,302 @@
--
-- Table, indexes and foreign keys
--
CREATE TABLE taskdep_nodes(
task_id INT NOT NULL
REFERENCES tasks( task_id )
ON DELETE CASCADE ,
tnode_reverse BOOLEAN NOT NULL ,
tnode_id SERIAL NOT NULL ,
tnode_id_parent INT ,
tnode_depth INT NOT NULL ,
task_id_copyof INT NOT NULL ,
tnode_id_copyof INT ,
taskdep_id INT
REFERENCES task_dependencies( taskdep_id )
ON DELETE CASCADE ,
PRIMARY KEY( task_id , tnode_reverse , tnode_id )
);
CREATE INDEX i_tnode_reversetasks ON taskdep_nodes ( tnode_reverse , tnode_id_parent );
CREATE INDEX i_tnode_copyof ON taskdep_nodes ( task_id_copyof );
CREATE INDEX i_tnode_objdep ON taskdep_nodes ( taskdep_id );
ALTER TABLE taskdep_nodes
ADD CONSTRAINT fk_tnode_copyof
FOREIGN KEY( task_id_copyof , tnode_reverse , tnode_id_copyof )
REFERENCES taskdep_nodes( task_id , tnode_reverse , tnode_id )
ON DELETE CASCADE ,
ADD CONSTRAINT fk_tnode_parent
FOREIGN KEY( task_id , tnode_reverse , tnode_id_parent )
REFERENCES taskdep_nodes( task_id , tnode_reverse , tnode_id )
ON DELETE CASCADE;
GRANT SELECT ON taskdep_nodes TO :webapp_user;
--
-- When a task is added, the corresponding dependency tree and
-- reverse dependency tree must be created
--
CREATE OR REPLACE FUNCTION tgf_task_ai( )
RETURNS TRIGGER
STRICT VOLATILE
SECURITY DEFINER
AS $tgf_task_ai$
BEGIN
INSERT INTO taskdep_nodes ( task_id , tnode_reverse , tnode_depth , task_id_copyof )
VALUES ( NEW.task_id , FALSE , 0 , NEW.task_id );
INSERT INTO taskdep_nodes ( task_id , tnode_reverse , tnode_depth , task_id_copyof )
VALUES ( NEW.task_id , TRUE , 0 , NEW.task_id );
RETURN NEW;
END;
$tgf_task_ai$ LANGUAGE plpgsql;
CREATE TRIGGER tg_task_ai
AFTER INSERT ON tasks
FOR EACH ROW
EXECUTE PROCEDURE tgf_task_ai( );
REVOKE EXECUTE ON FUNCTION tgf_task_ai() FROM PUBLIC;
--
-- Copy the contents of a tree <src> as a child of node <node> on tree <dest>.
--
CREATE OR REPLACE FUNCTION tdtree_copy_tree(
is_reverse BOOLEAN , src_id INT , dest_id INT ,
node_id INT , depth INT , dep_id INT
)
RETURNS VOID
STRICT VOLATILE
AS $tdtree_copy_tree$
DECLARE
node RECORD;
objid INT;
BEGIN
CREATE TEMPORARY TABLE tdtree_copy_ids(
old_id INT ,
new_id INT
);
FOR node IN
SELECT * FROM taskdep_nodes nodes
WHERE task_id = src_id
AND tnode_reverse = is_reverse
ORDER BY tnode_depth ASC
LOOP
IF node.tnode_id_copyof IS NULL THEN
node.task_id_copyof := src_id;
node.tnode_id_copyof := node.tnode_id;
END IF;
IF node.tnode_id_parent IS NULL THEN
node.tnode_id_parent := node_id;
node.taskdep_id := dep_id;
ELSE
SELECT INTO node.tnode_id_parent new_id
FROM tdtree_copy_ids
WHERE old_id = node.tnode_id_parent;
END IF;
node.tnode_depth := node.tnode_depth + depth;
INSERT INTO taskdep_nodes ( task_id , tnode_reverse , tnode_id_parent ,
tnode_depth , task_id_copyof , tnode_id_copyof ,
taskdep_id )
VALUES ( dest_id , is_reverse , node.tnode_id_parent , node.tnode_depth ,
node.task_id_copyof , node.tnode_id_copyof ,
node.taskdep_id )
RETURNING tnode_id INTO objid;
INSERT INTO tdtree_copy_ids VALUES ( node.tnode_id , objid );
END LOOP;
DROP TABLE tdtree_copy_ids;
END;
$tdtree_copy_tree$ LANGUAGE plpgsql;
REVOKE EXECUTE ON FUNCTION tdtree_copy_tree( BOOLEAN , INT , INT , INT , INT , INT ) FROM PUBLIC;
--
-- Add the contents of tree <src> as a child of the root of tree <dest>.
-- Also copy <src> to copies of <dest>.
--
CREATE OR REPLACE FUNCTION tdtree_set_child( is_reverse BOOLEAN , src_id INT , dest_id INT , dep_id INT )
RETURNS VOID
STRICT VOLATILE
AS $tdtree_set_child$
DECLARE
tree_id INT;
node_id INT;
depth INT;
BEGIN
FOR tree_id , node_id , depth IN
SELECT task_id , tnode_id , tnode_depth + 1
FROM taskdep_nodes
WHERE tnode_reverse = is_reverse
AND task_id_copyof = dest_id
LOOP
PERFORM tdtree_copy_tree( is_reverse , src_id , tree_id , node_id , depth , dep_id );
END LOOP;
END;
$tdtree_set_child$ LANGUAGE plpgsql;
REVOKE EXECUTE ON FUNCTION tdtree_set_child( BOOLEAN , INT , INT , INT ) FROM PUBLIC;
--
-- When a dependency between tasks is added, the corresponding trees must
-- be updated.
--
CREATE OR REPLACE FUNCTION tgf_taskdep_ai( )
RETURNS TRIGGER
STRICT VOLATILE
SECURITY DEFINER
AS $tgf_taskdep_ai$
BEGIN
PERFORM tdtree_set_child( FALSE , NEW.task_id_depends , NEW.task_id , NEW.taskdep_id );
PERFORM tdtree_set_child( TRUE , NEW.task_id , NEW.task_id_depends , NEW.taskdep_id );
RETURN NEW;
END;
$tgf_taskdep_ai$ LANGUAGE plpgsql;
CREATE TRIGGER tg_taskdep_ai
AFTER INSERT ON task_dependencies
FOR EACH ROW
EXECUTE PROCEDURE tgf_taskdep_ai( );
REVOKE EXECUTE ON FUNCTION tgf_taskdep_ai() FROM PUBLIC;
--
-- Before inserting a dependency, we need to lock all trees that have something
-- to do with either nodes. Then we need to make sure there are no cycles and
-- that the new dependency is not redundant.
--
CREATE OR REPLACE FUNCTION tgf_taskdep_bi( )
RETURNS TRIGGER
STRICT VOLATILE
SECURITY DEFINER
AS $tgf_taskdep_bi$
BEGIN
-- Lock all trees
PERFORM 1
FROM taskdep_nodes n1
INNER JOIN taskdep_nodes n2
USING ( task_id )
WHERE n1.task_id_copyof IN ( NEW.task_id , NEW.task_id_depends )
FOR UPDATE OF n2;
-- Check for cycles
PERFORM 1 FROM taskdep_nodes
WHERE task_id = NEW.task_id
AND task_id_copyof = NEW.task_id_depends
AND tnode_reverse;
IF FOUND THEN
RAISE EXCEPTION 'Cycle detected'
USING ERRCODE = 'check_violation';
END IF;
-- Check for redundant dependencies
PERFORM 1
FROM taskdep_nodes n1
INNER JOIN task_dependencies d
ON d.task_id = n1.task_id_copyof
WHERE n1.task_id = NEW.task_id
AND n1.tnode_reverse
AND d.task_id_depends = NEW.task_id_depends;
IF FOUND THEN
RAISE EXCEPTION '% is the parent of some child of %' , NEW.task_id_depends , NEW.task_id
USING ERRCODE = 'check_violation';
END IF;
PERFORM 1
FROM task_dependencies d1
INNER JOIN taskdep_nodes n
ON n.task_id = d1.task_id_depends
WHERE d1.task_id = NEW.task_id
AND n.tnode_reverse
AND n.task_id_copyof = NEW.task_id_depends;
IF FOUND THEN
RAISE EXCEPTION '% is the child of some ancestor of %' , NEW.task_id , NEW.task_id_depends
USING ERRCODE = 'check_violation';
END IF;
PERFORM 1 FROM taskdep_nodes
WHERE task_id = NEW.task_id
AND task_id_copyof = NEW.task_id_depends
AND NOT tnode_reverse;
IF FOUND THEN
RAISE EXCEPTION '% is already an ancestor of %' , NEW.task_id_depends , NEW.task_id
USING ERRCODE = 'check_violation';
END IF;
RETURN NEW;
END;
$tgf_taskdep_bi$ LANGUAGE plpgsql;
CREATE TRIGGER tg_taskdep_bi
BEFORE INSERT ON task_dependencies
FOR EACH ROW
EXECUTE PROCEDURE tgf_taskdep_bi( );
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 )
RETURNS SETOF tasks
STRICT STABLE
AS $tasks_possible_dependencies$
SELECT * FROM tasks
WHERE 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;
--
-- Add a dependency
--
CREATE OR REPLACE FUNCTION tasks_add_dependency( t_id INT , t_dependency INT )
RETURNS INT
STRICT VOLATILE
SECURITY INVOKER
AS $tasks_add_dependency$
BEGIN
INSERT INTO task_dependencies( task_id , task_id_depends_on )
VALUES ( t_id , t_dependency );
RETURN 0;
EXCEPTION
WHEN foreign_key_violation THEN
RETURN 1;
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;

View file

@ -0,0 +1,78 @@
-- 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 )
RETURNS INT
STRICT VOLATILE
SECURITY INVOKER
AS $add_task$
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 );
RETURN 0;
EXCEPTION
WHEN unique_violation THEN
RETURN 1;
WHEN foreign_key_violation THEN
RETURN 2;
END;
$add_task$ LANGUAGE plpgsql;
-- Mark a task as finished
CREATE OR REPLACE FUNCTION finish_task( t_id INT , u_id INT , n_text TEXT )
RETURNS INT
STRICT VOLATILE
SECURITY INVOKER
AS $finish_task$
BEGIN
BEGIN
INSERT INTO completed_tasks ( task_id , user_id )
VALUES ( t_id , u_id );
EXCEPTION
WHEN unique_violation THEN
RETURN 1;
END;
INSERT INTO notes ( task_id , user_id , note_text )
VALUES ( t_id , u_id , n_text );
RETURN 0;
END;
$finish_task$ LANGUAGE plpgsql;
-- Restart a task
CREATE OR REPLACE FUNCTION restart_task( t_id INT , u_id INT , n_text TEXT )
RETURNS INT
STRICT VOLATILE
SECURITY INVOKER
AS $restart_task$
BEGIN
DELETE FROM completed_tasks WHERE task_id = t_id;
IF NOT FOUND THEN
RETURN 1;
END IF;
INSERT INTO notes ( task_id , user_id , note_text )
VALUES ( t_id , u_id , n_text );
RETURN 0;
END;
$restart_task$ LANGUAGE plpgsql;
-- Update a task
CREATE OR REPLACE FUNCTION update_task( t_id INT , p_id INT , t_title TEXT , t_description TEXT , t_priority INT )
RETURNS INT
STRICT VOLATILE
SECURITY INVOKER
AS $update_task$
BEGIN
UPDATE tasks SET item_id = p_id , task_title = t_title ,
task_description = t_description ,
task_priority = t_priority
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;