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

Strange behaviour Expand / Collapse
Author
Message
Posted Tuesday, July 8, 2014 9:56 AM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Today @ 8:21 AM
Points: 428, Visits: 940
FWIW, Thinking it might have been generating an n x 1 CROSS JOIN, I moved the JOIN dbo.lookup out of the select statement in the function, since it wasn't actually JOINing the other tables. This had no effect.


Post #1590424
Posted Wednesday, July 9, 2014 5:38 AM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Today @ 8:21 AM
Points: 428, Visits: 940
So it turns out that in the 2 failing scenarios, the function is going through the full table before applying the WHERE clause, and failing on a row where first name or last name is null.

In the working scenarios, the WHERE clause is applied first, and only one row is acted on.

So am I to conclude that order does matter in the FROM clause?



Post #1590683
Posted Thursday, July 10, 2014 4:41 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 9:33 AM
Points: 7,178, Visits: 13,630
schleep (7/9/2014)
So it turns out that in the 2 failing scenarios, the function is going through the full table before applying the WHERE clause, and failing on a row where first name or last name is null.

In the working scenarios, the WHERE clause is applied first, and only one row is acted on.

So am I to conclude that order does matter in the FROM clause?

The execution plans for the working queries and the non-working queries are obviously different. You can't really jump to any conclusions without examining them.


“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 #1591072
Posted Thursday, July 10, 2014 5:17 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 9:33 AM
Points: 7,178, Visits: 13,630
-- You might want to configure that function as an iTVF for performance:
CREATE FUNCTION [dbo].[iTVF_CallbackService_ufn_GetCallerData]
(
@nCaller_NoArg INTEGER,
@cCallerLangArg CHAR(1)
)

RETURNS TABLE
AS
RETURN (

SELECT
[Caller_No] = @nCaller_NoArg,
[Clientname] = RTRIM(LTRIM(c.First_Name)) + ' ' + RTRIM(LTRIM(c.Last_Name)),
[ClientLanguage] = CASE
WHEN @cCallerLangArg = 'F'
THEN UPPER(RTRIM(LTRIM(l.Descript_f)))
ELSE UPPER(RTRIM(LTRIM(l.Descript)))
END,
[ClientOrganization] = ISNULL(RTRIM(LTRIM(c.Organization)), ''),
[ClientAddressLine1] = ISNULL(RTRIM(LTRIM(c.Street)), ''),

[ClientAddressLine2] = ISNULL(RTRIM(LTRIM(c.City)) + ', ' + CASE
WHEN @cCallerLangArg = 'F'
THEN UPPER(RTRIM(LTRIM(c.ps_prov_code))) -- c.ps_prov_code_f???
ELSE UPPER(RTRIM(LTRIM(c.ps_prov_code)))
END + ' ' +
RTRIM(LTRIM(CASE
WHEN c.Postcode LIKE '[A-Z][0-9][A-Z][0-9][A-Z][0-9]'
THEN LEFT(c.PostCode, 3) + ' ' + RIGHT(c.PostCode, 3)
ELSE c.PostCode
END)), ''),

[ClientAddressLine3] = ISNULL(CASE
WHEN @cCallerLangArg = 'F'
THEN UPPER(RTRIM(LTRIM(s_country_name_f)))
ELSE UPPER(RTRIM(LTRIM(s_country_name)))
END, ''),

[ClientTelephone1] = ISNULL(RTRIM(LTRIM(c.Telephone)), ''),
[ClientTelephone1Ext] = ISNULL(RTRIM(LTRIM(c.Extension)), ''),
[ClientTelephone2] = ISNULL(RTRIM(LTRIM(c.Night_Phone)), ''),
[ClientTelephone2Ext] = '',
[ClientEmail] = ISNULL(RTRIM(LTRIM(c.s_Email)), '')

FROM dbo.[Caller] c
CROSS JOIN dbo.[Lookup] l

LEFT OUTER JOIN dbo.Province p
ON p.ps_Prov_Code = c.ps_Prov_Code

LEFT OUTER JOIN dbo.Country ct
ON ct.ps_country_code = c.Country

WHERE c.Caller_No = @nCaller_NoArg
AND l.lookup_ch = @cCallerLangArg
AND l.Item_name = 'Language'

)



“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 #1591084
Posted Thursday, July 10, 2014 7:35 AM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Today @ 8:21 AM
Points: 428, Visits: 940
Hi Chris,

Yep, that was my conclusion too. However, since query fails, I couldn't see the execution plan. Unless there's a way?

And, the iTVF would probably neatly obviate the original NULL value problem, too!

Thanks!




Post #1591148
Posted Thursday, July 10, 2014 7:38 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 9:33 AM
Points: 7,178, Visits: 13,630
The query was failing because one or more columns in the original multi-statement table-valued function were non-nullable. It's unlikely that changing the nullability of those columns would change the plan.

“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 #1591153
« Prev Topic | Next Topic »

Add to briefcase ««12

Permissions Expand / Collapse