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


How to improve a aquery


How to improve a aquery

Author
Message
Nubiam.stewart
Nubiam.stewart
Forum Newbie
Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)

Group: General Forum Members
Points: 8 Visits: 43
Good morning,
I am writing a query thaht bring data from 7 tables.
In the first statge the data is stored in table variables.
Then I use 7 join to produce the data that I want to see.
The query takes 1 minute and 50 second to brin 22 records.
Could you please advise me how I can improve the performance of this query?
Thanks a lot,
Nubia
Mr. Kapsicum
Mr. Kapsicum
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1163 Visits: 1028
need table structure and some sample data.
and Most. Imp. Your Query...!!! :-)
Steve Hall
Steve Hall
SSCrazy
SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)

Group: General Forum Members
Points: 2825 Visits: 11566
The best way to get help with this is to include the code in question along with the definitions of the tables and some test data. Without those we're just guessing.

Have a look at the following article on how to post data that will help us to help you:
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/

Steve Hall
Linkedin
Blog Site
Nubiam.stewart
Nubiam.stewart
Forum Newbie
Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)

Group: General Forum Members
Points: 8 Visits: 43
Hello guys,

Thanks you for your reply. This is the definition of the sp. The data is taken from a ingress db. Unfotonately I don't have acces to the tables.

CREATE PROCEDURE [dbo].[usp_RPT_HSG_PropertyRepairsHistoryTSL]
(
@PropertyReferenceNumber NVARCHAR (max),
@StartDate DATETIME,
@EndDate DATETIME,
@GetCHRepType NVARCHAR (20)


)
AS
BEGIN

SET NOCOUNT ON

-- ===================================================
-- Execute no-lock expression at named linked servers
-- ===================================================
EXECUTE ('set lockmode session where readlock=nolock') AT INGRES2
DECLARE @PropertyRepairsHistory Table
(
Jobnumber INT
, PropertyReference NVARCHAR (max)
, JobTitle nvarchar (60)
, Priority nvarchar (20)
, JobType nvarchar (20)
, Contractorcode nvarchar (4)
, Contractor nvarchar (30)
, BilledValue MONEY
, ValuePaid MONEY
, StageHistDate DATE
, JobType2 NVARCHAR (20)


)

INSERT INTO @PropertyRepairsHistory

Select * FROM OPENQUERY (ingres2, '

SELECT repheader.repairno
, repheader.propref
, repheader.repairdesc
, priority.decode
, reptype.code
, workforce.wforcecode
, workforce.wforcename
, worderline.billval
, worderline.payval
, statehist.statedate
, reptype.decode AS JobType


FROM ((repheader INNER JOIN workorder ON repheader.repairno = workorder.repairno) inner JOIN worderline ON workorder.repairno = worderline.repairno AND workorder.repsubno = worderline.repsubno)
LEFT OUTER JOIN reptype ON reptype.code = repheader.reptypenow
LEFT OUTER JOIN priority ON priority.code = workorder.prioritycode
LEFT OUTER JOIN statehist ON statehist.repaltkey = repheader.repairno
LEFT OUTER JOIN workforce ON repheader.wforcecode = workforce.wforcecode
WHERE statehist.repstatecode = 99

')

DECLARE @Property Table
(
PropertyRef nvarchar(max)
, HouseNo NVARCHAR (4)
, AddressLine1 nvarchar (30)
, AddressLine2 nvarchar (30)
, AddressLine3 nvarchar (30)
, Postcode nvarchar (8)
, Officename nvarchar (max)
, Officecode nvarchar (max)



)
INSERT INTO @Property
Select * FROM OPENQUERY (ingres2, '

SELECT
propfixed.propref
,propfixed.houseno
, propfixed.proadd1
, propfixed.proadd2
, propfixed.proadd3
, propfixed.propstcde
,mnode.mnodename
, propfixed.mnodecode


FROM propfixed inner join mnode ON propfixed.mnodecode = mnode.code

' )
-- =======================
-- OutPut for Detail
-- =======================

SELECT *
FROM @PropertyRepairsHistory r inner join @Property P on R.PropertyReference = P.PropertyRef
WHERE r.StageHistDate BETWEEN @StartDate AND @EndDate
AND r.JobType IN (SELECT * FROM fn_CSVToTable(@GetCHRepType))
AND p.PropertyRef = @PropertyReferenceNumber

ORDER BY Jobnumber DESC

Thanks,
Nubia
Nubiam.stewart
Nubiam.stewart
Forum Newbie
Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)

Group: General Forum Members
Points: 8 Visits: 43
Hi Briandonor,

I attach you the Estimated Execution plan and the number of rows per table.

According to the execution plan the more expensive statement is:
INSERT INTO @Property
Select * FROM OPENQUERY (ingres2, '

SELECT
propfixed.propref
,propfixed.houseno
, propfixed.proadd1
, propfixed.proadd2
, propfixed.proadd3
, propfixed.propstcde
,mnode.mnodename
, propfixed.mnodecode


FROM propfixed inner join mnode ON propfixed.mnodecode = mnode.code

I don't understand why if the statement is using a join table to bring data froma look up table that only has 20 records. the propfixed table has only 88923 records. Is there any other way to bring data from a look up table?

Thanks a lot,

Nubia
Attachments
Data sample.xlsx (7 views, 11.00 KB)
EstimatedExecutionPlan1.sqlplan (16 views, 71.00 KB)
ccavaco
ccavaco
SSC Rookie
SSC Rookie (48 reputation)SSC Rookie (48 reputation)SSC Rookie (48 reputation)SSC Rookie (48 reputation)SSC Rookie (48 reputation)SSC Rookie (48 reputation)SSC Rookie (48 reputation)SSC Rookie (48 reputation)

Group: General Forum Members
Points: 48 Visits: 489
I believe you can get rid of the table variables altogether. Add the inner join used to populate the second table variable to the beginning of the first query to populate the first table variable and then add the additional "WHERE" clauses in the final query.
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16294 Visits: 19551
How long do the two remote queries take to run and how many rows are returned?

SELECT * 
FROM OPENQUERY (ingres2, '
SELECT repheader.repairno
, repheader.propref
, repheader.repairdesc
, priority.decode
, reptype.code
, workforce.wforcecode
, workforce.wforcename
, worderline.billval
, worderline.payval
, statehist.statedate
, reptype.decode AS JobType

FROM ((repheader
INNER JOIN workorder ON repheader.repairno = workorder.repairno)
inner JOIN worderline ON workorder.repairno = worderline.repairno
AND workorder.repsubno = worderline.repsubno)
LEFT OUTER JOIN reptype ON reptype.code = repheader.reptypenow
LEFT OUTER JOIN priority ON priority.code = workorder.prioritycode
LEFT OUTER JOIN statehist ON statehist.repaltkey = repheader.repairno
LEFT OUTER JOIN workforce ON repheader.wforcecode = workforce.wforcecode
WHERE statehist.repstatecode = 99')

SELECT *
FROM OPENQUERY (ingres2, '
SELECT
propfixed.propref
, propfixed.houseno
, propfixed.proadd1
, propfixed.proadd2
, propfixed.proadd3
, propfixed.propstcde
, mnode.mnodename
, propfixed.mnodecode
FROM propfixed
inner join mnode ON propfixed.mnodecode = mnode.code' )



At least one filter from your output detail section could be applied to the remote queries.

“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
Grant Fritchey
Grant Fritchey
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40050 Visits: 32653
You're pumping 20000 rows (estimated, actual could be more) into table variables, where there are no statistics. Then you're combining that with a multi-statement table valued function, which also doesn't have statistics, to filter down to 20 rows. I'm surprised it's running as fast as it actually is.

You need to filter the data sooner as was suggested to you. Loading the data into table variables is probably unnecessary, but if you must do it that way, you're better off using temporary tables so that statistics can be generated to arrive a better execution plan.

----------------------------------------------------
The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood...
Theodore Roosevelt

The Scary DBA
Author of: SQL Server Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
Steve Hall
Steve Hall
SSCrazy
SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)

Group: General Forum Members
Points: 2825 Visits: 11566
Thanks for that Grant. I saw the Table Variables but it just didn't register. "Looked But Failed To See" - it will be on my headstone one day.

Steve Hall
Linkedin
Blog Site
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16294 Visits: 19551
Are the NVARCHAR(MAX) column types necessary?
DECLARE @PropertyRepairsHistory Table
(
Jobnumber INT
, PropertyReference NVARCHAR (max) --
, JobTitle nvarchar (60)
, Priority nvarchar (20)
, JobType nvarchar (20)
, Contractorcode nvarchar (4)
, Contractor nvarchar (30)
, BilledValue MONEY
, ValuePaid MONEY
, StageHistDate DATE
, JobType2 NVARCHAR (20)
)

DECLARE @Property Table
(
PropertyRef nvarchar(max) --
, HouseNo NVARCHAR (4)
, AddressLine1 nvarchar (30)
, AddressLine2 nvarchar (30)
, AddressLine3 nvarchar (30)
, Postcode nvarchar (8)
, Officename nvarchar (max) --
, Officecode nvarchar (max) --
)



“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