Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

Slow Script Expand / Collapse
Author
Message
Posted Tuesday, October 1, 2013 8:14 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Sunday, January 19, 2014 6:08 PM
Points: 10, Visits: 60
Hello. I ran the following script that too 3 hours 25 minutes to insert about 40,000 rows. Is there any logic that I can put into this to speed it up? Thank you!

insert into T3
select T2.COL1, T2.COL2, T1.COL1, T1.COL2, T1.COL3
from T1
join T2 on T1.COL4 = T2.COL3
where T2.COL4 != 'data1'
and T1.COL1 is not NULL
and T1.COL5 is not NULL
and T1.COL6 = 'data2'
and CAST (T2.COL1 as VARCHAR)+'-'+CAST(T2.COL2 as VARCHAR)+'-'+CAST(T1.COL1 as VARCHAR)+'-'+CAST(T1.COL2 as VARCHAR) not in
(select CAST(COL1 as VARCHAR)+'-'+CAST(COL2 as VARCHAR)+'-'+CAST(COL3 as VARCHAR)+'-'+CAST(COL4 as VARCHAR) from T3)
Post #1500443
Posted Tuesday, October 1, 2013 8:51 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: 2 days ago @ 5:11 AM
Points: 94, Visits: 328
there are many causes for performance. but it's good to post little bit more details about this.
Like, do you have created index on some column if yes which type, do you use somewhere have transaction where this tables is used,

i don't know, try this
select T2.COL1, T2.COL2, T1.COL1, T1.COL2, T1.COL3,
CAST(T2.COL1 as VARCHAR)+'-'+CAST(T2.COL2 as VARCHAR)+'-'+CAST(T1.COL1 as VARCHAR)+'-'+CAST(T1.COL2 as VARCHAR) tmpColumn into #temp
from T1 (nolock) join T2 (nolock) on T1.COL4 = T2.COL3
where T2.COL4 != 'data1'
and T1.COL1 is not NULL
and T1.COL5 is not NULL
and T1.COL6 = 'data2'

insert into T3
select * from #temp where tmpColumn not in
(select CAST(COL1 as VARCHAR)+'-'+CAST(COL2 as VARCHAR)+'-'+CAST(COL3 as VARCHAR)+'-'+CAST(COL4 as VARCHAR) from T3)
Post #1500456
Posted Tuesday, October 1, 2013 8:51 AM


Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Today @ 2:08 PM
Points: 576, Visits: 869
There isn't a lot to go on here. If you could share some more information like: How large are the tables in question (both size and number of rows)? Are there indexes that cover this query? What does the Execution Plan show? Did this used to run fast and now it is slow? Is this an ad-hoc query or part of a stored procedure? etc.





Microsoft Certified Master - SQL Server 2008
Follow me on twitter: @keith_tate

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1500457
Posted Tuesday, October 1, 2013 8:54 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Saturday, July 26, 2014 8:10 PM
Points: 2,826, Visits: 8,463
And some examples of actual data in the tables, along with the CREATE TABLE code..


Post #1500461
Posted Tuesday, October 1, 2013 8:55 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 2:05 PM
Points: 13,137, Visits: 11,975
easy_goer (10/1/2013)
Hello. I ran the following script that too 3 hours 25 minutes to insert about 40,000 rows. Is there any logic that I can put into this to speed it up? Thank you!

insert into T3
select T2.COL1, T2.COL2, T1.COL1, T1.COL2, T1.COL3
from T1
join T2 on T1.COL4 = T2.COL3
where T2.COL4 != 'data1'
and T1.COL1 is not NULL
and T1.COL5 is not NULL
and T1.COL6 = 'data2'
and CAST (T2.COL1 as VARCHAR)+'-'+CAST(T2.COL2 as VARCHAR)+'-'+CAST(T1.COL1 as VARCHAR)+'-'+CAST(T1.COL2 as VARCHAR) not in
(select CAST(COL1 as VARCHAR)+'-'+CAST(COL2 as VARCHAR)+'-'+CAST(COL3 as VARCHAR)+'-'+CAST(COL4 as VARCHAR) from T3)


We can't really help performance issues on theoretical tables. I can say that your performance issues are all based in your where clause. You have lots of nonSARGable predicates here.

!= will force a full scan.

Also you cast all these columns to varchar. You didn't specify a length so it will use the default length. Do you know the default length for varchar? Me neither, that is why you should always specify the length.

If you want some real assistance with the performance issues you should take a look at this article.

http://www.sqlservercentral.com/articles/SQLServerCentral/66909/


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1500462
Posted Tuesday, October 1, 2013 8:56 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 9:21 AM
Points: 7,133, Visits: 13,520
This I reckon is the correct way to write your query:
select T2.COL1, T2.COL2, T1.COL1, T1.COL2, T1.COL3
from T1
join T2
on T1.COL4 = T2.COL3
where T2.COL4 != 'data1'
and T1.COL1 is not NULL
and T1.COL5 is not NULL
and T1.COL6 = 'data2'
AND NOT EXISTS (SELECT 1 FROM T3
WHERE T3.COL1 = T2.COL1
AND T3.COL2 = T2.COL2
AND T3.COL3 = T1.COL1
AND T3.COL4 = T1.COL2)

Check the results against the SELECT part of your original.


“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
Post #1500463
Posted Wednesday, October 2, 2013 10:13 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Sunday, January 19, 2014 6:08 PM
Points: 10, Visits: 60
Worked like a charm. Thanks for the assistance!
Post #1500978
Posted Saturday, October 5, 2013 7:46 PM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Saturday, July 26, 2014 8:10 PM
Points: 2,826, Visits: 8,463
Chris, is this the equivalent of a LEFT JOIN based on 4 columns ?

AND NOT EXISTS (SELECT 1 FROM T3 
WHERE T3.COL1 = T2.COL1
AND T3.COL2 = T2.COL2
AND T3.COL3 = T1.COL1
AND T3.COL4 = T1.COL2)




Post #1501884
Posted Saturday, October 5, 2013 8:00 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 1:35 PM
Points: 36,788, Visits: 31,246
homebrew01 (10/5/2013)
Chris, is this the equivalent of a LEFT JOIN based on 4 columns ?

AND NOT EXISTS (SELECT 1 FROM T3 
WHERE T3.COL1 = T2.COL1
AND T3.COL2 = T2.COL2
AND T3.COL3 = T1.COL1
AND T3.COL4 = T1.COL2)



Yeh... but faster.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1501888
Posted Sunday, October 6, 2013 6:50 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Saturday, July 26, 2014 8:10 PM
Points: 2,826, Visits: 8,463
ChrisM@Work (10/1/2013)
This I reckon is the correct way to write your query:
select T2.COL1, T2.COL2, T1.COL1, T1.COL2, T1.COL3
from T1
join T2
on T1.COL4 = T2.COL3
where T2.COL4 != 'data1'
and T1.COL1 is not NULL
and T1.COL5 is not NULL
and T1.COL6 = 'data2'
AND NOT EXISTS (SELECT 1 FROM T3
WHERE T3.COL1 = T2.COL1
AND T3.COL2 = T2.COL2
AND T3.COL3 = T1.COL1
AND T3.COL4 = T1.COL2)

Check the results against the SELECT part of your original.


So in this case, it will select from T1 and T2, only if not in T3 ?

What if you want to include non-matches against T3 ? Would you add to the WHERE clause ?

and T3.COL1 is NULL 
and T3.COL2 is NULL
and T3.COL3 is NULL
and T3.COL4 is NULL




Post #1501913
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse