SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Help required for performance tuning a view


Help required for performance tuning a view

Author
Message
mike.dinnis
mike.dinnis
SSC-Enthusiastic
SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)

Group: General Forum Members
Points: 145 Visits: 252
Hello,
I've inherited a database from a co-worker and have now got to a stage with it where I'm trying to resolve some performance issues. One particular view seems to be causing a bottleneck for a number of processes and I would appreciate some help or advice on how to make it more efficient.

The view in question looks at a multiple tables, but I've identified that the problem lies with one particular section which I reproduce below:

SELECT CASE
WHEN jt.emp_num IS NOT NULL
THEN jt.emp_num
ELSE
(SELECT TOP 1 jtx.emp_num
FROM jobtran jtx(NOLOCK)
WHERE jtx.job = jt.job
AND jtx.suffix = jt.suffix
AND jtx.oper_num >= jt.oper_num
AND jtx.emp_num IS NOT NULL
AND jtx.trans_num < jt.trans_num
ORDER BY jtx.oper_num, jtx.trans_num DESC)
END AS 'emp_num'

FROM jobtran jt (NOLOCK)

WHERE jt.trans_class = 'J'
AND ISNULL(jt.posted,0) = 1



As you can see, the aim of this is to use the emp_num for a record should it exist otherwise try to find the emp_num from a later oper_num for the same job. The sub query is apparently where the problem is at. The execution plan says that the Top N Sort operation is costing 96% of the batch, so I guess this is the problem but how do I make it more efficient?

The dbo.jobtran table is large (2.5 million rows) and this is probably the root of the issue, but I hope there is a more efficient way to identify the appropriate emp_num as this currently takes 53 seconds to complete.

I've attached the execution plan for this statement and the dbo.jobtran definition in the hope that someone can offer some advice on speeding this puppy up.

If you require more detail then please let me know.

Thanks,

Mike
Attachments
jobtran_Execution_Plan.sqlplan (8 views, 20.00 KB)
jobtran_Definition.txt (11 views, 9.00 KB)
ChrisM@Work
ChrisM@Work
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39118 Visits: 19990
The main query filters on trans_class and posted, the subquery doesn't, which would make using ROW_NUMBER quite tricky.
I'd go for a new (covering) index to support the subquery, something like
job, suffix, oper_num, trans_num DESC INCLUDE emp_num.

“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
Exploring Recursive CTEs by Example Dwain Camps
mike.dinnis
mike.dinnis
SSC-Enthusiastic
SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)

Group: General Forum Members
Points: 145 Visits: 252
Adding the suggested index does half the time.
Presumably an index was suggested as there is no other obvious way to achieve the same result with greater efficiency?
ChrisM@Work
ChrisM@Work
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39118 Visits: 19990
Can you post the actual plan please Mike? There may well be scope for improving the index.

“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
Exploring Recursive CTEs by Example Dwain Camps
mike.dinnis
mike.dinnis
SSC-Enthusiastic
SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)

Group: General Forum Members
Points: 145 Visits: 252
Not sure which actual plan you wanted (pre or post) so I've attached both.
Attachments
ChrisM@Work
ChrisM@Work
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39118 Visits: 19990
What other columns do you need from this table?

“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
Exploring Recursive CTEs by Example Dwain Camps
mike.dinnis
mike.dinnis
SSC-Enthusiastic
SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)

Group: General Forum Members
Points: 145 Visits: 252
The main query (from which this was the identified 'slow' bit) uses; emp_num, trans_type, a_hrs, qty_moved, wc and CreateDate in the returned fields; job, suffix, wc, oper_num and trans_num in the JOINs and trans_class, posted in the WHERE clause.

If it would be helpful I can return the whole statement, I was trying to focus on the 'slow' bit in my initial post.
ChrisM@Work
ChrisM@Work
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39118 Visits: 19990
mike.dinnis (8/12/2013)
The main query (from which this was the identified 'slow' bit) uses; emp_num, trans_type, a_hrs, qty_moved, wc and CreateDate in the returned fields; job, suffix, wc, oper_num and trans_num in the JOINs and trans_class, posted in the WHERE clause.

If it would be helpful I can return the whole statement, I was trying to focus on the 'slow' bit in my initial post.


It's worth a look.

It may well be worth investigating ROW_NUMBER because a large proportion of the output rows have a value from the subquery and you're having to scan the whole table (clustered index) in any case. If there’s a suitable index to get around the sort usually required by ROW_NUMBER then you could be on to a winner. It would be a whole lot easier for us if you could mock up some sample data. A single set based on job & suffix would do.



“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
Exploring Recursive CTEs by Example Dwain Camps
mike.dinnis
mike.dinnis
SSC-Enthusiastic
SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)

Group: General Forum Members
Points: 145 Visits: 252
Here's the full statement:


SELECT jt.trans_num,
CASE
WHEN jt.emp_num IS NOT NULL
THEN jt.emp_num
ELSE
(SELECT TOP 1 jtx.emp_num
FROM jobtran jtx(NOLOCK)
WHERE jtx.job = jt.job
AND jtx.suffix = jt.suffix
AND jtx.oper_num >= jt.oper_num
AND jtx.emp_num IS NOT NULL
AND jtx.trans_num < jt.trans_num
ORDER BY jtx.oper_num, jtx.trans_num DESC)
END AS 'emp_num',
CASE
WHEN jt.trans_type = 'M' AND js3.sched_drv = 'L' -- M = Move
THEN jt.a_hrs
ELSE 0
END AS 'rework_hrs',
CASE
WHEN jt.trans_type IN ('R','C') AND js3.sched_drv = 'L' -- R = Run, C = Machine
THEN jt.a_hrs
ELSE 0
END AS 'run_hrs',
CASE
WHEN jt.trans_type = 'S' AND js3.sched_drv = 'L' -- S = Setup
THEN jt.a_hrs
ELSE 0
END AS 'setup_hrs',
CASE -- All std time captured on Move*, as this is where quantity is recorded
-- where Move trans types don't exist, qty is recorded on other trans types (e.g C)
WHEN ISNULL(jt.qty_moved,0) <> 0
AND jt2.trans_num IS NULL
THEN CASE
WHEN i.cost_type = 'S' -- Standard Costed
THEN CASE
WHEN js.sched_drv = 'L' THEN js.setup_hrs + (js.run_mch_hrs * jt.qty_moved) + (js.run_lbr_hrs * jt.qty_moved)
ELSE 0
END
ELSE CASE -- Actual Costed
WHEN js2.sched_drv = 'L' THEN js2.setup_hrs + (js2.run_mch_hrs * jt.qty_moved) + (js2.run_lbr_hrs * jt.qty_moved)
ELSE 0
END
END
WHEN ISNULL(jt.qty_moved,0) <> 0
THEN CASE
WHEN i.cost_type = 'S' -- Standard Costed
THEN CASE
WHEN js.sched_drv = 'L' THEN (js.run_mch_hrs * jt.qty_moved) + (js.run_lbr_hrs * jt.qty_moved)
ELSE 0
END
ELSE CASE -- Actual Costed
WHEN js2.sched_drv = 'L' THEN (js2.run_mch_hrs * jt.qty_moved) + (js2.run_lbr_hrs * jt.qty_moved) -- Actual Costed
ELSE 0
END
END
ELSE 0
END AS 'std_hours',
trans_date,
jt.wc,
i.Uf_renItemProject AS 'project_no',
ISNULL(wc.Uf_renWCSalvage,0) AS 'salvage_wc',
jt.CreateDate

FROM jobtran jt (NOLOCK)
JOIN job j (NOLOCK)
ON j.job = jt.job
AND j.suffix = jt.suffix
JOIN item i (NOLOCK)
ON i.item = j.item
JOIN wc (NOLOCK)
ON wc.wc = jt.wc
LEFT JOIN jrt_sch js (NOLOCK)
ON js.job = i.job
AND js.suffix = 1
AND js.oper_num = jt.oper_num
LEFT JOIN jrt_sch js2 (NOLOCK)
ON js2.job = i.job
AND js2.suffix = 0
AND js2.oper_num = jt.oper_num
LEFT JOIN jrt_sch js3 (NOLOCK)
ON js3.job = jt.job
AND js3.suffix = jt.suffix
AND js3.oper_num = jt.oper_num
LEFT JOIN ( SELECT MIN(trans_num) AS 'trans_num', -- Set up time only backflushed for first booking,
job, -- so check that no previous booking exists for op.
suffix,
oper_num
FROM jobtran (NOLOCK)
GROUP BY job, suffix, oper_num) jt2
ON jt2.job = jt.job
AND jt2.suffix = jt.suffix
AND jt2.oper_num = jt.oper_num
AND jt2.trans_num < jt.trans_num

WHERE jt.trans_class = 'J'
AND ISNULL(jt.posted,0) = 1 -- Only show posted transactions


GO



The more I look at this code the more irregularities I spot. Oh, the joys of inheriting code!

I'll see what I can do about generating some sample data for the table.
ChrisM@Work
ChrisM@Work
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39118 Visits: 19990
I'd focus on the one table for now, which gives you this query:

SELECT   
jt.trans_num,
emp_num = CASE
WHEN jt.emp_num IS NOT NULL
THEN jt.emp_num
ELSE
(SELECT TOP 1
jtx.emp_num
FROM jobtran jtx(NOLOCK)
WHERE jtx.job = jt.job
AND jtx.suffix = jt.suffix
AND jtx.oper_num >= jt.oper_num
AND jtx.emp_num IS NOT NULL
AND jtx.trans_num < jt.trans_num
ORDER BY jtx.oper_num, jtx.trans_num DESC)
END

FROM jobtran jt (NOLOCK)

LEFT JOIN (
SELECT
trans_num = MIN(trans_num), -- Set up time only backflushed for first booking,
job, -- so check that no previous booking exists for op.
suffix,
oper_num
FROM jobtran (NOLOCK)
GROUP BY job, suffix, oper_num
) jt2
ON jt2.job = jt.job
AND jt2.suffix = jt.suffix
AND jt2.oper_num = jt.oper_num
AND jt2.trans_num < jt.trans_num

WHERE jt.trans_class = 'J'
AND ISNULL(jt.posted,0) = 1 -- Only show posted transactions



“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
Exploring Recursive CTEs by Example Dwain Camps
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search