[open-ils-commits] ***SPAM*** [GIT] Evergreen ILS branch master updated. 76686de7a0acd689466122a209b38d6db27e86fa

Evergreen Git git at git.evergreen-ils.org
Thu Jul 10 16:38:38 EDT 2014


This is an automated email from the git hooks/post-receive script. It was
generated because a ref change was pushed to the repository containing
the project "Evergreen ILS".

The branch, master has been updated
       via  76686de7a0acd689466122a209b38d6db27e86fa (commit)
       via  6f32e8f9b60bbdf8dab21bbb0c07b04f62828c83 (commit)
      from  f2bcfbf40b272c125f326bf18b5f458536f2730d (commit)

Those revisions listed above that are new to this repository have
not appeared on any other notification email; so we list those
revisions in full, below.

- Log -----------------------------------------------------------------
commit 76686de7a0acd689466122a209b38d6db27e86fa
Author: Ben Shum <bshum at biblio.org>
Date:   Thu Jul 10 16:37:00 2014 -0400

    LP#1234845: Stamping upgrade script for improved evergreen.ranked_volumes()
    
    Signed-off-by: Ben Shum <bshum at biblio.org>

diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql
index 9e5641b..69e0e7f 100644
--- a/Open-ILS/src/sql/Pg/002.schema.config.sql
+++ b/Open-ILS/src/sql/Pg/002.schema.config.sql
@@ -91,7 +91,7 @@ CREATE TRIGGER no_overlapping_deps
     BEFORE INSERT OR UPDATE ON config.db_patch_dependencies
     FOR EACH ROW EXECUTE PROCEDURE evergreen.array_overlap_check ('deprecates');
 
-INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0884', :eg_version); -- rsteed/bshum
+INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0885', :eg_version); -- depesz/dyrcona/miker/kmlussier/bshum
 
 CREATE TABLE config.bib_source (
 	id		SERIAL	PRIMARY KEY,
diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.function.ranked_volumes.sql b/Open-ILS/src/sql/Pg/upgrade/0885.function.ranked_volumes.sql
similarity index 98%
rename from Open-ILS/src/sql/Pg/upgrade/XXXX.function.ranked_volumes.sql
rename to Open-ILS/src/sql/Pg/upgrade/0885.function.ranked_volumes.sql
index 99c7594..553e45c 100644
--- a/Open-ILS/src/sql/Pg/upgrade/XXXX.function.ranked_volumes.sql
+++ b/Open-ILS/src/sql/Pg/upgrade/0885.function.ranked_volumes.sql
@@ -1,5 +1,7 @@
 BEGIN;
 
+SELECT evergreen.upgrade_deps_block_check('0885', :eg_version);
+
 CREATE OR REPLACE FUNCTION evergreen.ranked_volumes(
     bibid BIGINT[],
     ouid INT,

commit 6f32e8f9b60bbdf8dab21bbb0c07b04f62828c83
Author: hubert depesz lubaczewski <depesz at depesz.com>
Date:   Thu Oct 3 14:26:33 2013 -0400

    LP#1234845: Performance improvement to evergreen.ranked_volumes() database function.
    
    For the client I analyzed logs from production Pg instance for ~ 10
    days.
    
    During this time, the single most time consuming query (summarized time
    for all instances of the query, with different parameters) was:
    
    SELECT * FROM unapi.bre ( ... ) AS "unapi.bre";
    
    I profiled this function, and found that in my test case most of the
    time (2.04s out of 2.06s, so ~ 99%) was spent in call to
    unapi.holdings_xml() function.
    
    When I profiled this function, I found that most of the time (sorry,
    don't have the number now with me) was spent in call to
    evergreen.ranked_volumes() function.
    
    At this moment in my research something changed on the server I was
    testing on, and all subsequent times were ~ 4-5 times lower, but the
    ratios were more or less the same.
    
    Anyway - call to evergreen.ranked_volumes() showed repeatable time (with
    full caches/buffers) of ~ 380ms.
    
    I modified the function by:
    1. inlining actor.org_unit_descendants(?, ?)
    2. inlining evergreen.rank_ou(?, ?, ?)
    3. extracting depth calculation to separate call
    4. switched to plpgsql (which gives me ability to use variables)
    5. removed evergreen.rank_ou() and evergreen.rank_cp_status() from
       select clause - these are still in WINDOW definition, but they
       weren't used in the SELECT, so it's better to remove from there.
    6. in passing renamed arguments to avoid name clash (argument depth vs.
       field depth)
    7. in passing changed usage of $* to access parameters to using named
       parameters, for readability.
    
    New function did the same work in ~ 18ms.
    
    EDIT: Convert to SQL, keeping all of the improvements from depesz
    EDIT2: Added Signed-off-by line for depesz, see http://markmail.org/message/rv4vaarwixeswqgu
    
    Signed-off-by: Hubert depesz Lubaczewski <depesz at depesz.com>
    Signed-off-by: Jason Stephenson <jstephenson at mvlc.org>
    Signed-off-by: Mike Rylander <mrylander at gmail.com>
    Signed-off-by: Kathy Lussier <klussier at masslnc.org>
    Signed-off-by: Ben Shum <bshum at biblio.org>

diff --git a/Open-ILS/src/sql/Pg/990.schema.unapi.sql b/Open-ILS/src/sql/Pg/990.schema.unapi.sql
index 2c7c0b7..92e7fc8 100644
--- a/Open-ILS/src/sql/Pg/990.schema.unapi.sql
+++ b/Open-ILS/src/sql/Pg/990.schema.unapi.sql
@@ -72,21 +72,57 @@ CREATE OR REPLACE FUNCTION evergreen.ranked_volumes(
     soffset HSTORE DEFAULT NULL,
     pref_lib INT DEFAULT NULL,
     includes TEXT[] DEFAULT NULL::TEXT[]
-) RETURNS TABLE (id BIGINT, name TEXT, label_sortkey TEXT, rank BIGINT) AS $$
+) RETURNS TABLE(id BIGINT, name TEXT, label_sortkey TEXT, rank BIGINT) AS $$
+    WITH RECURSIVE ou_depth AS (
+        SELECT COALESCE(
+            $3,
+            (
+                SELECT depth
+                FROM actor.org_unit_type aout
+                    INNER JOIN actor.org_unit ou ON ou_type = aout.id
+                WHERE ou.id = $2
+            )
+        ) AS depth
+    ), 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),
+                ou_depth
+        WHERE ad.depth = ou_depth.depth
+            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 = $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 anscestor_depth ot ON (ot.parent_ou = ou.id)
+    ), descendants as (
+        SELECT ou.* FROM actor.org_unit ou JOIN descendant_depth USING (id)
+    )
+
     SELECT ua.id, ua.name, ua.label_sortkey, MIN(ua.rank) AS rank FROM (
         SELECT acn.id, aou.name, acn.label_sortkey,
-            evergreen.rank_ou(aou.id, $2, $6), evergreen.rank_cp_status(acp.status),
             RANK() OVER w
         FROM asset.call_number acn
             JOIN asset.copy acp ON (acn.id = acp.call_number)
-            JOIN actor.org_unit_descendants( $2, COALESCE(
-                $3, (
-                    SELECT depth
-                    FROM actor.org_unit_type aout
-                        INNER JOIN actor.org_unit ou ON ou_type = aout.id
-                    WHERE ou.id = $2
-                ), $6)
-            ) AS aou ON (acp.circ_lib = aou.id)
+            JOIN descendants AS aou ON (acp.circ_lib = aou.id)
         WHERE acn.record = ANY ($1)
             AND acn.deleted IS FALSE
             AND acp.deleted IS FALSE
@@ -98,15 +134,25 @@ CREATE OR REPLACE FUNCTION evergreen.ranked_volumes(
                 ) ELSE TRUE END
         GROUP BY acn.id, acp.status, aou.name, acn.label_sortkey, aou.id
         WINDOW w AS (
-            ORDER BY evergreen.rank_ou(aou.id, $2, $6), evergreen.rank_cp_status(acp.status)
+            ORDER BY 
+                COALESCE(
+                    CASE WHEN aou.id = $2 THEN -20000 END,
+                    CASE WHEN aou.id = $6 THEN -10000 END,
+                    (SELECT distance - 5000
+                        FROM actor.org_unit_descendants_distance($6) as x
+                        WHERE x.id = aou.id AND $6 IN (
+                            SELECT q.id FROM actor.org_unit_descendants($2) as q)),
+                    (SELECT e.distance FROM actor.org_unit_descendants_distance($2) as e WHERE e.id = aou.id),
+                    1000
+                ),
+                evergreen.rank_cp_status(acp.status)
         )
     ) AS ua
     GROUP BY ua.id, ua.name, ua.label_sortkey
     ORDER BY rank, ua.name, ua.label_sortkey
     LIMIT ($4 -> 'acn')::INT
     OFFSET ($5 -> 'acn')::INT;
-$$
-LANGUAGE SQL STABLE;
+$$ LANGUAGE SQL STABLE ROWS 10;
 
 CREATE OR REPLACE FUNCTION evergreen.ranked_volumes
     ( bibid BIGINT, ouid INT, depth INT DEFAULT NULL, slimit HSTORE DEFAULT NULL, soffset HSTORE DEFAULT NULL, pref_lib INT DEFAULT NULL, includes TEXT[] DEFAULT NULL::TEXT[] )
diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.function.ranked_volumes.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.function.ranked_volumes.sql
new file mode 100644
index 0000000..99c7594
--- /dev/null
+++ b/Open-ILS/src/sql/Pg/upgrade/XXXX.function.ranked_volumes.sql
@@ -0,0 +1,98 @@
+BEGIN;
+
+CREATE OR REPLACE FUNCTION evergreen.ranked_volumes(
+    bibid BIGINT[],
+    ouid INT,
+    depth INT DEFAULT NULL,
+    slimit HSTORE DEFAULT NULL,
+    soffset HSTORE DEFAULT NULL,
+    pref_lib INT DEFAULT NULL,
+    includes TEXT[] DEFAULT NULL::TEXT[]
+) RETURNS TABLE(id BIGINT, name TEXT, label_sortkey TEXT, rank BIGINT) AS $$
+    WITH RECURSIVE ou_depth AS (
+        SELECT COALESCE(
+            $3,
+            (
+                SELECT depth
+                FROM actor.org_unit_type aout
+                    INNER JOIN actor.org_unit ou ON ou_type = aout.id
+                WHERE ou.id = $2
+            )
+        ) AS depth
+    ), 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),
+                ou_depth
+        WHERE ad.depth = ou_depth.depth
+            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 = $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 anscestor_depth ot ON (ot.parent_ou = ou.id)
+    ), descendants as (
+        SELECT ou.* FROM actor.org_unit ou JOIN descendant_depth USING (id)
+    )
+
+    SELECT ua.id, ua.name, ua.label_sortkey, MIN(ua.rank) AS rank FROM (
+        SELECT acn.id, aou.name, acn.label_sortkey,
+            RANK() OVER w
+        FROM asset.call_number acn
+            JOIN asset.copy acp ON (acn.id = acp.call_number)
+            JOIN descendants AS aou ON (acp.circ_lib = aou.id)
+        WHERE acn.record = ANY ($1)
+            AND acn.deleted IS FALSE
+            AND acp.deleted IS FALSE
+            AND CASE WHEN ('exclude_invisible_acn' = ANY($7)) THEN
+                EXISTS (
+                    SELECT 1
+                    FROM asset.opac_visible_copies
+                    WHERE copy_id = acp.id AND record = acn.record
+                ) ELSE TRUE END
+        GROUP BY acn.id, acp.status, aou.name, acn.label_sortkey, aou.id
+        WINDOW w AS (
+            ORDER BY
+                COALESCE(
+                    CASE WHEN aou.id = $2 THEN -20000 END,
+                    CASE WHEN aou.id = $6 THEN -10000 END,
+                    (SELECT distance - 5000
+                        FROM actor.org_unit_descendants_distance($6) as x
+                        WHERE x.id = aou.id AND $6 IN (
+                            SELECT q.id FROM actor.org_unit_descendants($2) as q)),
+                    (SELECT e.distance FROM actor.org_unit_descendants_distance($2) as e WHERE e.id = aou.id),
+                    1000
+                ),
+                evergreen.rank_cp_status(acp.status)
+        )
+    ) AS ua
+    GROUP BY ua.id, ua.name, ua.label_sortkey
+    ORDER BY rank, ua.name, ua.label_sortkey
+    LIMIT ($4 -> 'acn')::INT
+    OFFSET ($5 -> 'acn')::INT;
+$$ LANGUAGE SQL STABLE ROWS 10;
+
+CREATE OR REPLACE FUNCTION evergreen.ranked_volumes
+    ( bibid BIGINT, ouid INT, depth INT DEFAULT NULL, slimit HSTORE DEFAULT NULL, soffset HSTORE DEFAULT NULL, pref_lib INT DEFAULT NULL, includes TEXT[] DEFAULT NULL::TEXT[] )
+    RETURNS TABLE (id BIGINT, name TEXT, label_sortkey TEXT, rank BIGINT)
+    AS $$ SELECT * FROM evergreen.ranked_volumes(ARRAY[$1],$2,$3,$4,$5,$6,$7) $$ LANGUAGE SQL STABLE;
+
+COMMIT;

-----------------------------------------------------------------------

Summary of changes:
 Open-ILS/src/sql/Pg/002.schema.config.sql          |    2 +-
 Open-ILS/src/sql/Pg/990.schema.unapi.sql           |   72 ++++++++++++---
 .../Pg/upgrade/0885.function.ranked_volumes.sql    |  100 ++++++++++++++++++++
 3 files changed, 160 insertions(+), 14 deletions(-)
 create mode 100644 Open-ILS/src/sql/Pg/upgrade/0885.function.ranked_volumes.sql


hooks/post-receive
-- 
Evergreen ILS


More information about the open-ils-commits mailing list