Why is my query not working as expected?

  • So, I am writing a view and I want it to be an indexed view. The first query I wrote is:

    SELECT P.policy_internal_id,

    RTRIM(P.contract_main_id)

    + CASE P.contract_sub_id

    WHEN '00' THEN ''

    ELSE P.contract_sub_id END

    + CASE

    WHEN SQ.value_num IS NULL THEN ''

    ELSE '-' + CONVERT(VARCHAR(9), CONVERT(INT, SQ.value_num)) END

    [rpt_policy_contract]

    FROM dbo.POLICY P

    LEFT OUTER JOIN (

    SELECT PAN.policy_internal_id, PAN.value_num

    FROM dbo.POLICY P2

    JOIN dbo.POLICY_ATTRIBUTES_NUM PAN ON

    P2.policy_internal_id = PAN.policy_internal_id

    JOIN dbo.PRODUCT_ATTRIBUTES PA ON

    P2.product_id = PA.product_id

    AND PAN.prod_attr_id = PA.prod_attr_id

    JOIN dbo.PRODUCT_POSSIBLE_ATTRIBUTES PPA ON

    PA.prod_poss_attr_id = PPA.prod_poss_attr_id

    WHERE PPA.prod_attr_logical_key = 'NB_RENEWAL' ) SQ ON

    P.policy_internal_id = SQ.policy_internal_id

    This query works, it returns 1 record for each record in the POLICY table. Unfortunately, I want to index this view, so I can't use a subquery. This lead me to try a new query.

    SELECT P.policy_internal_id,

    RTRIM(P.contract_main_id)

    + CASE P.contract_sub_id

    WHEN '00' THEN ''

    ELSE P.contract_sub_id END

    + CASE

    WHEN PAN.value_num IS NULL THEN ''

    ELSE '-' + CONVERT(VARCHAR(9), CONVERT(INT, PAN.value_num)) END

    [rpt_policy_contract]

    FROM dbo.POLICY P

    LEFT OUTER JOIN dbo.POLICY_ATTRIBUTES_NUM PAN ON

    P.policy_internal_id = PAN.policy_internal_id

    JOIN dbo.PRODUCT_ATTRIBUTES PA ON

    PAN.prod_attr_id = PA.prod_attr_id

    JOIN dbo.PRODUCT_POSSIBLE_ATTRIBUTES PPA ON

    PA.prod_poss_attr_id = PPA.prod_poss_attr_id

    AND PPA.prod_attr_logical_key = 'NB_RENEWAL'

    This query is behaving as though I am using join rather than left outer join. It does not return at least 1 record per record in the policy table. Does anyone have any thoughts on this? I do not understand why the left outer join is not working. I only join the POLICY table with the POLICY_ATTRIBUTES_NUM table and that join is a left outer join. Therefore, I think it should return a record for each record in the POLICY table. Also, since there is no where clause, that can't be eliminating the records either. Any thoughts?

  • SQL Server is turning the OJ into an IJ because of the inner-joined "trail". You can get around it by changing the position of the ON clauses like this:

    SELECT P.policy_internal_id,

    RTRIM(P.contract_main_id)

    + CASE P.contract_sub_id

    WHEN '00' THEN ''

    ELSE P.contract_sub_id END

    + CASE

    WHEN PAN.value_num IS NULL THEN ''

    ELSE '-' + CONVERT(VARCHAR(9), CONVERT(INT, PAN.value_num)) END

    [rpt_policy_contract]

    FROM dbo.POLICY P

    LEFT OUTER JOIN dbo.POLICY_ATTRIBUTES_NUM PAN

    inner JOIN dbo.PRODUCT_ATTRIBUTES PA

    inner JOIN dbo.PRODUCT_POSSIBLE_ATTRIBUTES PPA

    ON PA.prod_poss_attr_id = PPA.prod_poss_attr_id AND PPA.prod_attr_logical_key = 'NB_RENEWAL'

    ON PAN.prod_attr_id = PA.prod_attr_id

    ON P.policy_internal_id = PAN.policy_internal_id

    The real question is...why do you want an indexed view? Is it because this query isn't performing as you might expect it to?

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • Yea, it is not performing so well. I wanted to at least give it a try and see how it affects the performance. I don't know if the cost of updating the index will be worth the benefit, but I know one way to find out, test it. I am also considering a TVF with cross apply, but I think the view will be better for performance (even without the index). I'd be happen to hear your thoughts on it.

    PS Thanks for the code, I didn't even know that you could put the on clauses at the end like that. You learn something new every day.

  • Can you post the actual execution plan, Kevin? As a .sqlplan attachment. It's the source of information for anyone wanting to optimise a query. There are plenty of folks around here willing - keen even - to have a look and offer you suggestions.

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

Viewing 4 posts - 1 through 3 (of 3 total)

You must be logged in to reply to this topic. Login to reply