[open-ils-commits] r18462 - in trunk/Open-ILS/src/sql/Pg: . upgrade (miker)

svn at svn.open-ils.org svn at svn.open-ils.org
Mon Oct 25 14:01:29 EDT 2010


Author: miker
Date: 2010-10-25 14:01:25 -0400 (Mon, 25 Oct 2010)
New Revision: 18462

Added:
   trunk/Open-ILS/src/sql/Pg/upgrade/0445.schema.replace-connect_by.sql
Modified:
   trunk/Open-ILS/src/sql/Pg/002.schema.config.sql
   trunk/Open-ILS/src/sql/Pg/020.schema.functions.sql
Log:
In 2.0+ we require PG 8.4+ which means we have WITH RECURSIVE support, so use that instead of tablefunc connect_by.

Modified: trunk/Open-ILS/src/sql/Pg/002.schema.config.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/002.schema.config.sql	2010-10-25 16:26:39 UTC (rev 18461)
+++ trunk/Open-ILS/src/sql/Pg/002.schema.config.sql	2010-10-25 18:01:25 UTC (rev 18462)
@@ -70,7 +70,7 @@
     install_date    TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
 );
 
-INSERT INTO config.upgrade_log (version) VALUES ('0444'); -- gmc
+INSERT INTO config.upgrade_log (version) VALUES ('0445'); -- miker
 
 CREATE TABLE config.bib_source (
 	id		SERIAL	PRIMARY KEY,

Modified: trunk/Open-ILS/src/sql/Pg/020.schema.functions.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/020.schema.functions.sql	2010-10-25 16:26:39 UTC (rev 18461)
+++ trunk/Open-ILS/src/sql/Pg/020.schema.functions.sql	2010-10-25 18:01:25 UTC (rev 18462)
@@ -156,37 +156,85 @@
 	END;
 $$ language 'plpgsql';
 
+CREATE OR REPLACE FUNCTION actor.org_unit_descendants( INT, INT ) RETURNS SETOF actor.org_unit AS $$
+    WITH RECURSIVE descendant_depth AS (
+        SELECT  ou.id,
+                ou.parent_ou,
+                out.depth
+          FROM  actor.org_unit ou
+                JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+                JOIN anscestor_depth ad ON (ad.id = ou.id)
+          WHERE ad.depth = $2
+            UNION ALL
+        SELECT  ou.id,
+                ou.parent_ou,
+                out.depth
+          FROM  actor.org_unit ou
+                JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+                JOIN descendant_depth ot ON (ot.id = ou.parent_ou)
+    ), anscestor_depth AS (
+        SELECT  ou.id,
+                ou.parent_ou,
+                out.depth
+          FROM  actor.org_unit ou
+                JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+          WHERE ou.id = $1
+            UNION ALL
+        SELECT  ou.id,
+                ou.parent_ou,
+                out.depth
+          FROM  actor.org_unit ou
+                JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+                JOIN anscestor_depth ot ON (ot.parent_ou = ou.id)
+    ) SELECT ou.* FROM actor.org_unit ou JOIN descendant_depth USING (id);
+$$ LANGUAGE SQL;
 
-CREATE OR REPLACE FUNCTION actor.org_unit_descendants ( INT ) RETURNS SETOF actor.org_unit AS $$
-	SELECT	a.*
-	  FROM	connectby('actor.org_unit'::text,'id'::text,'parent_ou'::text,'name'::text,$1::text,100,'.'::text)
-	  		AS t(keyid text, parent_keyid text, level int, branch text,pos int)
-		JOIN actor.org_unit a ON a.id::text = t.keyid::text
-	  ORDER BY  CASE WHEN a.parent_ou IS NULL THEN 0 ELSE 1 END, a.name;
-$$ LANGUAGE SQL STABLE;
+CREATE OR REPLACE FUNCTION actor.org_unit_descendants( INT ) RETURNS SETOF actor.org_unit AS $$
+    WITH RECURSIVE descendant_depth AS (
+        SELECT  ou.id,
+                ou.parent_ou,
+                out.depth
+          FROM  actor.org_unit ou
+                JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+          WHERE ou.id = $1
+            UNION ALL
+        SELECT  ou.id,
+                ou.parent_ou,
+                out.depth
+          FROM  actor.org_unit ou
+                JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+                JOIN descendant_depth ot ON (ot.id = ou.parent_ou)
+    ), anscestor_depth AS (
+        SELECT  ou.id,
+                ou.parent_ou,
+                out.depth
+          FROM  actor.org_unit ou
+                JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+          WHERE ou.id = $1
+            UNION ALL
+        SELECT  ou.id,
+                ou.parent_ou,
+                out.depth
+          FROM  actor.org_unit ou
+                JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+                JOIN anscestor_depth ot ON (ot.parent_ou = ou.id)
+    ) SELECT ou.* FROM actor.org_unit ou JOIN descendant_depth USING (id);
+$$ LANGUAGE SQL;
 
-CREATE OR REPLACE FUNCTION actor.org_unit_ancestors ( INT ) RETURNS SETOF actor.org_unit AS $$
-	SELECT	a.*
-	  FROM	connectby('actor.org_unit'::text,'parent_ou'::text,'id'::text,'name'::text,$1::text,100,'.'::text)
-	  		AS t(keyid text, parent_keyid text, level int, branch text,pos int)
-		JOIN actor.org_unit a ON a.id::text = t.keyid::text
-        JOIN actor.org_unit_type tp ON tp.id = a.ou_type 
-        ORDER BY tp.depth, a.name;
-$$ LANGUAGE SQL STABLE;
+CREATE OR REPLACE FUNCTION actor.org_unit_ancestors( INT ) RETURNS SETOF actor.org_unit AS $$
+    WITH RECURSIVE anscestor_depth AS (
+        SELECT  ou.id,
+                ou.parent_ou
+          FROM  actor.org_unit ou
+          WHERE ou.id = $1
+            UNION ALL
+        SELECT  ou.id,
+                ou.parent_ou
+          FROM  actor.org_unit ou
+                JOIN anscestor_depth ot ON (ot.parent_ou = ou.id)
+    ) SELECT ou.* FROM actor.org_unit ou JOIN anscestor_depth USING (id);
+$$ LANGUAGE SQL;
 
-CREATE OR REPLACE FUNCTION actor.org_unit_descendants ( INT,INT ) RETURNS SETOF actor.org_unit AS $$
-	SELECT	a.*
-	  FROM	connectby('actor.org_unit'::text,'id'::text,'parent_ou'::text,'name'::text,
-	  			(SELECT	x.id
-				   FROM	actor.org_unit_ancestors($1) x
-				   	JOIN actor.org_unit_type y ON x.ou_type = y.id
-				  WHERE	y.depth = $2)::text
-		,100,'.'::text)
-	  		AS t(keyid text, parent_keyid text, level int, branch text,pos int)
-		JOIN actor.org_unit a ON a.id::text = t.keyid::text
-	  ORDER BY  CASE WHEN a.parent_ou IS NULL THEN 0 ELSE 1 END, a.name;
-$$ LANGUAGE SQL STABLE;
-
 CREATE OR REPLACE FUNCTION actor.org_unit_ancestor_at_depth ( INT,INT ) RETURNS actor.org_unit AS $$
 	SELECT	a.*
 	  FROM	actor.org_unit a

Added: trunk/Open-ILS/src/sql/Pg/upgrade/0445.schema.replace-connect_by.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/upgrade/0445.schema.replace-connect_by.sql	                        (rev 0)
+++ trunk/Open-ILS/src/sql/Pg/upgrade/0445.schema.replace-connect_by.sql	2010-10-25 18:01:25 UTC (rev 18462)
@@ -0,0 +1,85 @@
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0445'); -- miker
+
+CREATE OR REPLACE FUNCTION actor.org_unit_descendants( INT, INT ) RETURNS SETOF actor.org_unit AS $$
+    WITH RECURSIVE descendant_depth AS (
+        SELECT  ou.id,
+                ou.parent_ou,
+                out.depth
+          FROM  actor.org_unit ou
+                JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+                JOIN anscestor_depth ad ON (ad.id = ou.id)
+          WHERE ad.depth = $2
+            UNION ALL
+        SELECT  ou.id,
+                ou.parent_ou,
+                out.depth
+          FROM  actor.org_unit ou
+                JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+                JOIN descendant_depth ot ON (ot.id = ou.parent_ou)
+    ), anscestor_depth AS (
+        SELECT  ou.id,
+                ou.parent_ou,
+                out.depth
+          FROM  actor.org_unit ou
+                JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+          WHERE ou.id = $1
+            UNION ALL
+        SELECT  ou.id,
+                ou.parent_ou,
+                out.depth
+          FROM  actor.org_unit ou
+                JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+                JOIN anscestor_depth ot ON (ot.parent_ou = ou.id)
+    ) SELECT ou.* FROM actor.org_unit ou JOIN descendant_depth USING (id);
+$$ LANGUAGE SQL;
+
+CREATE OR REPLACE FUNCTION actor.org_unit_descendants( INT ) RETURNS SETOF actor.org_unit AS $$
+    WITH RECURSIVE descendant_depth AS (
+        SELECT  ou.id,
+                ou.parent_ou,
+                out.depth
+          FROM  actor.org_unit ou
+                JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+          WHERE ou.id = $1
+            UNION ALL
+        SELECT  ou.id,
+                ou.parent_ou,
+                out.depth
+          FROM  actor.org_unit ou
+                JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+                JOIN descendant_depth ot ON (ot.id = ou.parent_ou)
+    ), anscestor_depth AS (
+        SELECT  ou.id,
+                ou.parent_ou,
+                out.depth
+          FROM  actor.org_unit ou
+                JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+          WHERE ou.id = $1
+            UNION ALL
+        SELECT  ou.id,
+                ou.parent_ou,
+                out.depth
+          FROM  actor.org_unit ou
+                JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+                JOIN anscestor_depth ot ON (ot.parent_ou = ou.id)
+    ) SELECT ou.* FROM actor.org_unit ou JOIN descendant_depth USING (id);
+$$ LANGUAGE SQL;
+
+CREATE OR REPLACE FUNCTION actor.org_unit_ancestors( INT ) RETURNS SETOF actor.org_unit AS $$
+    WITH RECURSIVE anscestor_depth AS (
+        SELECT  ou.id,
+                ou.parent_ou
+          FROM  actor.org_unit ou
+          WHERE ou.id = $1
+            UNION ALL
+        SELECT  ou.id,
+                ou.parent_ou
+          FROM  actor.org_unit ou
+                JOIN anscestor_depth ot ON (ot.parent_ou = ou.id)
+    ) SELECT ou.* FROM actor.org_unit ou JOIN anscestor_depth USING (id);
+$$ LANGUAGE SQL;
+
+COMMIT;
+



More information about the open-ils-commits mailing list