IBM Support

IT27763: SUBOPTIMAL PERFORMANCE WITH QUERIES CONTAINING OUTER JOINS AND OLAP FUNCTIONS

Subscribe to this APAR

By subscribing, you receive periodic emails alerting you to the status of the APAR, along with a link to the fix after it becomes available. You can track this item individually or track all items by product.

Notify me when this APAR changes.

Notify me when an APAR for this component changes.

 

APAR status

  • Closed as program error.

Error description

  • Suboptimal performance might be observed when running a query
    with the following characteristics:
    1. the query contains at least one outer join
    2. the row preserving side column referenced in an outer join
    predicate can be sourced down to a constant
    3. between the outer join and the constant, there is a
    sub-select containing OLAP functions
    
    Example queries:
    Query 1:
    with
    valueBox (const) as (VALUES (1))
    select * from
    (select row_number() over() as t1_1, t12, const from t1,
    valueBox) t1_value
    left join t2
    on t1_value.t12=t2.t22 and t1_value.const = t2.t21
    
    Query 2:
    with
    valueBox (const) as (VALUES (1))
    select * from
    (select row_number() over() as t1_1, t12, const from t1,
    valueBox) t1_value
    left join t2
    on t1_value.t12=t2.t22 and t1_value.const = 1
    
    work-around:
    manually rewrite the query to replace the row preserving column
    in the outer join predicate with the constant, and manually
    eliminate the outer join predicate if possible. For ex., the
    example queries can be rewritten to:
    Rewritten query 1:
    with
    valueBox (const) as (VALUES (1))
    select * from
    (select row_number() over() as t1_1, t12, const from t1,
    valueBox) t1_value
    left join t2
    on t1_value.t12=t2.t22 and 1 = t2.t21  -- manually replace
    t1_value.const with "1"
    
    Rewritten query 2:
    with
    valueBox (const) as (VALUES (1))
    select * from
    (select row_number() over() as t1_1, t12, const from t1,
    valueBox) t1_value
    left join t2
    on t1_value.t12=t2.t22  -- manually eliminate "t1_value.const =
    1" as it is an always true predicate
    

Local fix

  • Query rewrite as explained above.
    

Problem summary

  • ****************************************************************
    * USERS AFFECTED:                                              *
    * ALL                                                          *
    ****************************************************************
    * PROBLEM DESCRIPTION:                                         *
    * See Error Description                                        *
    ****************************************************************
    * RECOMMENDATION:                                              *
    * Upgrade to Db2 11.1 Mod 4 Fixpack 5 or higher                *
    ****************************************************************
    

Problem conclusion

  • First fixed in Db2 11.1 Mod 4 Fixpack 5
    

Temporary fix

Comments

APAR Information

  • APAR number

    IT27763

  • Reported component name

    DB2 FOR LUW

  • Reported component ID

    DB2FORLUW

  • Reported release

    B10

  • Status

    CLOSED PER

  • PE

    NoPE

  • HIPER

    NoHIPER

  • Special Attention

    NoSpecatt / Xsystem

  • Submitted date

    2019-01-14

  • Closed date

    2020-01-16

  • Last modified date

    2020-01-16

  • APAR is sysrouted FROM one or more of the following:

  • APAR is sysrouted TO one or more of the following:

Fix information

  • Fixed component name

    DB2 FOR LUW

  • Fixed component ID

    DB2FORLUW

Applicable component levels

  • RB10 PSN

       UP

[{"Business Unit":{"code":"BU048","label":"IBM Software"},"Product":{"code":"SSEPGG","label":"DB2 for Linux, UNIX and Windows"},"Component":"","ARM Category":[],"Platform":[{"code":"PF025","label":"Platform Independent"}],"Version":"11.1","Edition":"","Line of Business":{"code":"LOB10","label":"Data and AI"}}]

Document Information

Modified date:
16 January 2020