Need help desperately on query optimization

  • Hi there,

    I'd a query causing a performance problem on server. The data sets are huge. Any suggestions on optimizing will be highly appreciated.

    SELECT COUNT(UQ102.[Patient_ID])

    FROM

    (

    SELECT me.[Patient_ID]

    FROM [PROJECT].[dbo].[MEASURE] me

    JOIN

    (

    SELECT p.[Patient_ID], max(m.[MEASUREMENT_DATETIME]) AS lateMeasure

    FROM [PROJECT].[dbo].[PATIENT] p

    FULL JOIN

    [PROJECT].[dbo].[CONSULTATIONS] c

    ON p.[Patient_ID] = c.[Patient_ID]

    FULL JOIN

    [PROJECT].[dbo].[MEASURE] m

    ON p.[Patient_ID] = m.[Patient_ID]

    WHERE [VISIT_DATE] >= '2010-02-07'

    AND (m.[TYPE] = 'SYSTOLIC' OR m.[TYPE] = 'SYSLIE' OR m.[TYPE] = 'SYSSTAND')

    GROUP BY p.[Patient_ID]

    HAVING COUNT(DISTINCT [VISIT_DATE]) >= 3

    ) AS lateTime

    ON me.[Patient_ID] = lateTime.[Patient_ID]

    WHERE me.[MEASUREMENT_DATETIME] = lateTime.[lateMeasure]

    AND (me.[TYPE] = 'SYSTOLIC' OR me.[TYPE] = 'SYSLIE' OR me.[TYPE] = 'SYSSTAND')

    AND me.[MEASUREMENT] <> '' AND ISNUMERIC(me.[MEASUREMENT]) = 1

    AND me.[MEASUREMENT] <> '0' AND SUBSTRING(me.[MEASUREMENT], 1, 1) <> '0'

    AND SUBSTRING(me.[MEASUREMENT], 1, 3) >= '100' AND SUBSTRING(me.[MEASUREMENT], 1, 3) < '250'

    AND SUBSTRING(me.[MEASUREMENT], 2, 1) <> '.'

    GROUP BY me.[Patient_ID]

    UNION

    SELECT me.[Patient_ID]

    FROM [PROJECT].[dbo].[MEASURE] me

    JOIN

    (

    SELECT p.[Patient_ID], max(m.[MEASUREMENT_DATETIME]) AS lateMeasure

    FROM [PROJECT].[dbo].[PATIENT] p

    FULL JOIN

    [PROJECT].[dbo].[CONSULTATIONS] c

    ON p.[Patient_ID] = c.[Patient_ID]

    FULL JOIN

    [PROJECT].[dbo].[MEASURE] m

    ON p.[Patient_ID] = m.[Patient_ID]

    WHERE [VISIT_DATE] >= '2010-02-07'

    AND (m.[TYPE] = 'SYSTOLIC' OR m.[TYPE] = 'SYSLIE' OR m.[TYPE] = 'SYSSTAND')

    GROUP BY p.[Patient_ID]

    HAVING COUNT(DISTINCT [VISIT_DATE]) >= 3

    ) AS lateTime

    ON me.[Patient_ID] = lateTime.[Patient_ID]

    WHERE me.[MEASUREMENT_DATETIME] = lateTime.[lateMeasure]

    AND (me.[TYPE] = 'SYSTOLIC' OR me.[TYPE] = 'SYSLIE' OR me.[TYPE] = 'SYSSTAND')

    AND me.[MEASUREMENT] <> '' AND ISNUMERIC(me.[MEASUREMENT]) = 1

    AND me.[MEASUREMENT] BETWEEN '0' AND '999'

    AND SUBSTRING(me.[MEASUREMENT], 1, 2) > '70'

    AND SUBSTRING(me.[MEASUREMENT], 2, 1) <> '.'

    GROUP BY me.[Patient_ID]

    ) UQ102

  • Post the DDL for the tables, including their keys and indexes. Also, please post the execution plan.

    [font="Times New Roman"]-- RBarryYoung[/font], [font="Times New Roman"] (302)375-0451[/font] blog: MovingSQL.com, Twitter: @RBarryYoung[font="Arial Black"]
    Proactive Performance Solutions, Inc.
    [/font]
    [font="Verdana"] "Performance is our middle name."[/font]

  • Thanks much Barry. Not sure how to post the DDL for the table. I'm not the owner, creator or administrator. Anyway I'm attaching the screen shot for those three tables Patient_v1/Consultations/Measure. So that you can see the indices clearly. There are no keys of them.

    Also attached the execution plan.

    From my end, the error message is always:

    "Could not allocate space for object '<temporary system object: 422219562090496>' in database 'tempdb' because the 'PRIMARY' filegroup is full. Create disk space by deleting unneeded files, dropping objects in the filegroup, adding additional files to the filegroup, or setting autogrowth on for existing files in the filegroup."

    At server end, the tempdb fills up all the disc space; and the sql uses up all the CPU.

    One quick question for you: What should an DBA or the IT person having access to the db server do to clean up the situation without restarting the server? Both of us are not experienced in this kind of case.

    Very grateful for any advice.

    Best,

    Helen

  • OK, several things:

    1. The query that you posted is not the same as the one that was used in the query plan. Leaving aside the name changes (which we expect), there is an additional WHERE..AND clause on the two halves of the UNION, testing for [..Site] = '..'. Which one of these two versions is correct?

    2. Why are you using FULL OUTER JOINS? They are a very uncommon construct, and the content of your interior WHERE clauses is reducing them to INNER and LEFT OUTER joins anyway.

    3. The two interior subqueries "(SELECT ... ) As lateTime" appear to be the same within the parenthesis. Can you confirm if that is correct?

    4. The Query Plan is only the estimated query plan, not the actual one. You probably cannot get the actuals if the query does not complete, so instead, could you please execute just the [lateTime] subquery and tell us how many rows it returns?

    [font="Times New Roman"]-- RBarryYoung[/font], [font="Times New Roman"] (302)375-0451[/font] blog: MovingSQL.com, Twitter: @RBarryYoung[font="Arial Black"]
    Proactive Performance Solutions, Inc.
    [/font]
    [font="Verdana"] "Performance is our middle name."[/font]

  • Also, the sreenshot is telling us anything useful, just the index names, which isn't a lot of help. You can get the DDL for the tables by scripting them. just right-click on the table in management studio and pick Script Table As CREATE..

    [font="Times New Roman"]-- RBarryYoung[/font], [font="Times New Roman"] (302)375-0451[/font] blog: MovingSQL.com, Twitter: @RBarryYoung[font="Arial Black"]
    Proactive Performance Solutions, Inc.
    [/font]
    [font="Verdana"] "Performance is our middle name."[/font]

  • Preliminarily, here's the Query I would start with:

    ;WITH

    cteMeasure As

    (

    SELECT m.[Patient_ID], m.[MEASUREMENT_DATETIME]

    FROM [PROJECT].[dbo].[MEASURE] m

    WHERE m.[TYPE] IN('SYSTOLIC', 'SYSLIE', 'SYSSTAND')

    )

    , lateTime As

    (

    SELECT p.[Patient_ID], max(m.[MEASUREMENT_DATETIME]) AS lateMeasure

    FROM [PROJECT].[dbo].[PATIENT] p

    INNER JOIN [PROJECT].[dbo].[CONSULTATIONS] c ON p.[Patient_ID] = c.[Patient_ID]

    INNER JOIN cteMeasure m ON p.[Patient_ID] = m.[Patient_ID]

    WHERE [VISIT_DATE] >= '2010-02-07'

    AND m.[g_Site] = 'NSW_xxx_MC'

    GROUP BY p.[Patient_ID]

    HAVING COUNT(DISTINCT [VISIT_DATE]) >= 3

    )

    SELECT COUNT(UQ102.[Patient_ID])

    FROM

    (

    SELECT me.[Patient_ID]

    FROM cteMeasure me

    JOIN lateTime

    ON me.[Patient_ID] = lateTime.[Patient_ID]

    AND me.[MEASUREMENT_DATETIME] = lateTime.[lateMeasure]

    WHERE me.[MEASUREMENT] <> '' AND ISNUMERIC(me.[MEASUREMENT]) = 1

    AND ( ( me.[MEASUREMENT] <> '0'

    AND SUBSTRING(me.[MEASUREMENT], 1, 1) <> '0'

    AND SUBSTRING(me.[MEASUREMENT], 1, 3) >= '100' AND SUBSTRING(me.[MEASUREMENT], 1, 3) < '250'

    AND SUBSTRING(me.[MEASUREMENT], 2, 1) <> '.'

    )

    OR ( me.[MEASUREMENT] BETWEEN '0' AND '999'

    AND SUBSTRING(me.[MEASUREMENT], 1, 2) > '70'

    AND SUBSTRING(me.[MEASUREMENT], 2, 1) <> '.'

    )

    )

    GROUP BY me.[Patient_ID]

    ) UQ102

    It should be logically the same, so it may just produce the same query plan, but it has been simplified/reduced syntactically, so it's worht trying and seeing.

    [font="Times New Roman"]-- RBarryYoung[/font], [font="Times New Roman"] (302)375-0451[/font] blog: MovingSQL.com, Twitter: @RBarryYoung[font="Arial Black"]
    Proactive Performance Solutions, Inc.
    [/font]
    [font="Verdana"] "Performance is our middle name."[/font]

  • Thanks so much. Basically you guessed all. And I tried your code; rewrite mine according to your suggestions. Now it works very well without the tempdb problem after a couple of tests. You did save me! Additionally yours is much more readable and easier to reuse. All my best to you!!

  • Glad that worked for you. (Kind of surprised too. I really thought that it would take more than that)

    [font="Times New Roman"]-- RBarryYoung[/font], [font="Times New Roman"] (302)375-0451[/font] blog: MovingSQL.com, Twitter: @RBarryYoung[font="Arial Black"]
    Proactive Performance Solutions, Inc.
    [/font]
    [font="Verdana"] "Performance is our middle name."[/font]

Viewing 8 posts - 1 through 7 (of 7 total)

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