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 123»»»

Select statement of view stays 5 hours to return results...... Expand / Collapse
Author
Message
Posted Friday, January 7, 2011 4:46 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, August 26, 2015 5:12 AM
Points: 186, Visits: 850
Hello,

We've got created the following view (1.), in a database that have no more then 350Mb but the result of the select statement (2.) stays among 5 hours to return results

I'm completely lost and i really dont understand what part of the code i must change
Sorry!!! Can you help me or can you give me any idea so that i can change the code of this "crazy view".....

Happy new year
Thanks and regards,
JMSM

1.
------------- Create View Code ------------------
use [DBName]
GO
create view [dbo].[VwNAME] as
select [ID]
,[Login]
,FLPExp
,FLKHw
,PUACnt
,FLWRArt
,FLWRBPst
,FLWDnlds
,case when FLPExp = 1 and FLKHw = 1 and PUACnt > 1 then 100
when FLPExp = 1 and FLKHw = 1 and FLWRArt = 1 then 75
when FLPExp = 1 and FLKHw = 1 and FLWDnlds = 1 then 50
when FLPExp = 1 and FLKHw = 1 then 25
else 0
end 'PercentPrf'
from (
select
a.id as 'ID',
a.ACCName as 'Login',
case when count(distinct b.title)>0 then 1 else 0 end FLPExp,
case when count(distinct f.idknowhow)>0 then 1 else 0 end FLKHw,
count(distinct d.id)+count(distinct e.IDArtcl) PUACnt,
case when (count(distinct g.id) + count(distinct h.id))>0 then 1 else 0 end FLWRArt,
case when count(distinct i.id)>0 then 1 else 0 end FLWRBPst,
case when count(distinct j.CntDnlds)>0 then 1 else 0 end FLWDnlds
from Athr a
left join PstExp b on a.id = b.idAthr
left join Artcl d
on a.id = d.idAthrSubMtr
and d.status = 2 -- Aproved
left join (select e1.id, e2.idAthr, e2.IDArtcl
from Artcl e1,
ArtclcoAthr e2
where e1.id = e2.IDArtcl
and e1.status = 2) e -- CO Artcls
on a.id = e.idAthr
left join Athrknowhow f on a.id = f.idAthr
left join Artcl g -- Artcls less 30 days
on a.id = g.idAthrSubMtr
and datediff(d, g.PblDte, getdate()) < 30
and g.Status = 2
left join (select h1.id, h2.idAthr
from Artcl h1,
ArtclcoAthr h2
where h1.id = h2.IDArtcl
and datediff(d, h1.PblDte, getdate()) < 30
and h1.status = 2) h -- CO Artcls less 30 days
on a.id = h.idAthr
left join UsgWkiBlg i -- Posts less then 30 days
on a.id = i.idAthr
and i.ShPntTypSWeb = 1
and datediff(d, i.LstMdfation, getdate()) < 30
left join UsgeAthrArtcl j -- downloads
on a.id = j.idAthr
where a.locked = 0
group by a.id, a.ACCName ) a
go

---------------- End View Code ------------------

2.
---------------- Select Statement ---------------
SELECT [ID]
,[Login]
,FLPExp
,FLKHw
,PUACnt
,FLWRArt
,FLWRBPst
,FLWDnlds
,[PercentPrf]
FROM [DBName]. [dbo].[VwNAME]
GO
------------ End Select Statement ---------------
Post #1044797
Posted Sunday, January 9, 2011 6:35 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 12:42 PM
Points: 14,614, Visits: 12,678
It's hard to make something up from your create view statement as it doesn't have a proper lay-out, which makes it hard to read.

At first glance I see you have a lot of joins, including outer joins, with functions in the where clause. You should try to avoid functions in the where clause, as indexes will probably not be used. Also, the many COUNT DISTINCT aggregates can also slow things down.

If possible and necessary, replace the "on-the-fly" calculated columns from the where clauses with real persisted computed columns.
You should probably also check out if there are any indexes and if there are, if they are useful.




How to post forum questions.
Need an answer? No, you need a question.
What’s the deal with Excel & SSIS?

Member of LinkedIn. My blog at SQLKover.

MCSA SQL Server 2012 - MCSE Business Intelligence
Post #1044979
Posted Sunday, January 9, 2011 7:06 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, August 26, 2015 5:12 AM
Points: 186, Visits: 850
Thanks a lot Koen.

I'll do the right checks and i'll tell you the solution.

Once more thanks.
Regards,
JMSM
Post #1044983
Posted Sunday, January 9, 2011 7:26 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Monday, July 13, 2015 10:29 AM
Points: 6,897, Visits: 13,551
There are several approaches you can use:
Most important:
instead of applying a function to your columns rewrite it as SARGable arguments:
datediff(d, i.LstMdfation, getdate()) < 30
-- would be
i.LstMdfation>dateadd(dd, -30, getdate())

Another option that usually helps is preaggregation.
Find the table that would be reduced the most by your where conditions and populate that table as an indexed temp table and use this table in your query.

Furthermore, you're calling Artcl at least four times. Maybe the query itself can be rewritten to be much more efficient.

And finally, there might be a missing index issue, too. Check the execution plan for best index usage.




Lutz
A pessimist is an optimist with experience.

How to get fast answers to your question
How to post performance related questions
Links for Tally Table , Cross Tabs and Dynamic Cross Tabs , Delimited Split Function
Post #1044987
Posted Sunday, January 9, 2011 9:00 AM


SSCoach

SSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoach

Group: General Forum Members
Last Login: Today @ 12:49 PM
Points: 15,768, Visits: 30,006
I agree with what everyone else has said. I think they've caught the obvious stuff. Now, to keep going, can you post the execution plan from the query, preferably after you fix the functions that are preventing index use. That can help to figure out if you have good indexes in place and they're getting used properly.

----------------------------------------------------
"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
Post #1044997
Posted Sunday, January 9, 2011 9:10 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, August 26, 2015 5:12 AM
Points: 186, Visits: 850
Thanks a lot LutzM.
I'll change the function as u tell me.
Regards,
JMSM
Post #1044999
Posted Sunday, January 9, 2011 6:07 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Monday, July 13, 2015 10:29 AM
Points: 6,897, Visits: 13,551
JMSM (1/9/2011)
Thanks a lot LutzM.
I'll change the function as u tell me.
Regards,
JMSM


The function issue is not the only problem (might not even be the most relevant one).
So, please follow Grants advice and post the actual execution plan.

And don't worry too much about Celko's post... If you'd take the time trying to read and understand what his real intention is, you'd probably have rewritten your code by then anyway...

Beside he really knows SQL stuff (at least what rumour tells) he's got that "special" online personality. The bottom line: He doesn't like the way you name your columns, tables, and views. Doesn't change performance at all, but would help readability and maintainability, I admitt. But that's not the major concern here, I guess....

He's right about the DISTINCT issue though...




Lutz
A pessimist is an optimist with experience.

How to get fast answers to your question
How to post performance related questions
Links for Tally Table , Cross Tabs and Dynamic Cross Tabs , Delimited Split Function
Post #1045083
Posted Monday, January 10, 2011 7:40 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, August 26, 2015 5:12 AM
Points: 186, Visits: 850
Hello again,

I've attached the execution plan and the code of both views, the oldest and the new one.
I've change yet the column names, and the tablename on both views.

Thanks and regards,
JMSM


  Post Attachments 
Exec-Plan-AuthorProfilePerc.NEW.sqlplan (45 views, 332.67 KB)
AuthorProfilePerc.NEW.txt (18 views, 2.90 KB)
AuthorProfilePerc.OLD.txt (6 views, 2.72 KB)
Post #1045304
Posted Monday, January 10, 2011 8:04 AM


SSCoach

SSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoach

Group: General Forum Members
Last Login: Today @ 12:49 PM
Points: 15,768, Visits: 30,006
JMSM (1/10/2011)
Hello again,

I've attached the execution plan and the code of both views, the oldest and the new one.
I've change yet the column names, and the tablename on both views.

Thanks and regards,
JMSM


There's just a ton of things going on here. First off, all those DISTINCT operations, they're killing your performance. You need to reevaluate if you really need them, and if so, I'd suggest building a materialized view with this data already aggregated (DISTINCT is an aggregation operation).

It also looks like you're missing indexes all over the place. Just picking one out
left join pastexperience b on a.id = b.idauthor

This results in a merge join on just a few records. From what I can see, I'd try an index on the PastExperience table on the column IdAuthor and probably would add the Title column to the INCLUDE list.

There are probably lots of other opportunities for indexes. On a guess, you don't have any indexes on your foriegn keys do you?

That's my 2 cents worth. I'm sure others will pick up on more.


----------------------------------------------------
"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
Post #1045327
Posted Monday, January 10, 2011 9:45 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Thursday, March 12, 2015 6:11 PM
Points: 5,467, Visits: 7,659
Grant Fritchey (1/10/2011)

This results in a merge join on just a few records. From what I can see, I'd try an index on the PastExperience table on the column IdAuthor and probably would add the Title column to the INCLUDE list.


Grant,

I'm suddenly worried that once again a core item to my understanding is invalid. Merge Joins are supposed to be the fastest. It's the "card-shuffle" join, one pass on both sides of the data and bam, done. Why would you go out of your way to avoid that?



- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
Post #1045409
« Prev Topic | Next Topic »

Add to briefcase 123»»»

Permissions Expand / Collapse