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 07, 2011 4:46 PM
SSC-Enthusiastic

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

Group: General Forum Members
Last Login: Thursday, April 10, 2014 12:57 PM
Points: 186, Visits: 805
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 09, 2011 6:35 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 6:08 AM
Points: 12,212, Visits: 9,193
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 LessThanDot.

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

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

Group: General Forum Members
Last Login: Thursday, April 10, 2014 12:57 PM
Points: 186, Visits: 805
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 09, 2011 7:26 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 2:17 PM
Points: 6,957, Visits: 12,715
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 09, 2011 9:00 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 3:25 PM
Points: 14,835, Visits: 27,311
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 2012 Query Performance Tuning
SQL Server 2008 Query Performance Tuning Distilled
and
SQL Server Execution Plans

Product Evangelist for Red Gate Software
Post #1044997
Posted Sunday, January 09, 2011 9:10 AM
SSC-Enthusiastic

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

Group: General Forum Members
Last Login: Thursday, April 10, 2014 12:57 PM
Points: 186, Visits: 805
Thanks a lot LutzM.
I'll change the function as u tell me.
Regards,
JMSM
Post #1044999
Posted Sunday, January 09, 2011 5:15 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, January 15, 2013 11:11 AM
Points: 1,945, Visits: 2,782
>> We've created the following VIEW in a database that have no more then 350Mb [w00t] but the result of the SELECT statement stays among 5 hours to return results [Crazy].

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

Please post DDL, so that people do not have to guess what the keys, constraints, Declarative Referential Integrity, data types, etc. in your schema are. If you know how, follow ISO-11179 data element naming conventions and formatting rules. Temporal data should use ISO-8601 formats. Code should be in Standard SQL as much as possible and not local dialect.

Sample data is also a good idea, along with clear specifications. It is very hard to debug code when you do not let us see it. If you want to learn how to ask a question on a Newsgroup, look at: http://www.catb.org/~esr/faqs/smart-questions.html

Based on decades of experience with SQL and this sample of the code. I diagnose the problem as bad DDL. We can temporarily patch this code, but all we are doing is giving pain fillers to a terminal cancer case.

Okay, now let me say what I really want to say after taking time to re-format and trying to read the code:

<Celko rant>

This is what Phil Factor would call a “bad code smell” here, but I would use the phrase “rotting flesh” instead. The data element names are totally screwed up. “status” of what? Employment? Marriage? “title” of what?

Please tell me that the uselessly vague “id”, which seems to change from table to table is not an IDENTITY column improperly used as a key. But wait, sometimes the data element “id” is also “idathr”, which I guess would have been “athr_id” if you knew ISO-11179 rules. And what is an “athr” anyway? This is SQL and not BASIC – you can have longer names that make code maintainable.

Why, the name of Dr. Codd, did you alias the tables in alphabetic order? Ever try to maintain code like that?

EIGHT, count them eight, LEFT OUTER JOINs in one query? Three would be suspect, but this truly stinks of bad SQL DDL.

COUNT(DISTINCT) everywhere?

Did you really mean to name this nightmare “Volkswagen_Names” according to ISO-11179 rules?

The poorly named data elements like “flpexp”, “flkhw”, “flw_rart” (or is it “flwr_art” as a shorthand for “flower art”?), “flw_rbpst” and “flw_dnlds” (short for “flowing downloads”, cannot be a column since it is plural?) look like bit flags! We never use flags in SQL; that was Assembly language 30 years ago.

</Celko rant>





Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1045079
Posted Sunday, January 09, 2011 6:07 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 2:17 PM
Points: 6,957, Visits: 12,715
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 Sunday, January 09, 2011 6:57 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, January 15, 2013 11:11 AM
Points: 1,945, Visits: 2,782
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 rumor 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 admit. But that's not the major concern here, I guess....

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


Hey! show some respect for Gargoyles! Eight books and a decade on the SQL committee are more than a rumor

In the long run, the over-use of CASE to get tells us that they ought to be a single data element with proper encoding schemes.

I love Phil Factor for importing the term "code smell" for what I was calling "symptoms" of bad code. There is a lot of bad smell here.


Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1045087
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: Thursday, April 10, 2014 12:57 PM
Points: 186, Visits: 805
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
« Prev Topic | Next Topic »

Add to briefcase 123»»»

Permissions Expand / Collapse