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


Strange behaviour


Strange behaviour

Author
Message
schleep
schleep
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2639 Visits: 1405
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.



schleep
schleep
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2639 Visits: 1405
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?



ChrisM@Work
ChrisM@Work
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: 40152 Visits: 20000
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
ChrisM@Work
ChrisM@Work
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: 40152 Visits: 20000
-- 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
schleep
schleep
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2639 Visits: 1405
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!



ChrisM@Work
ChrisM@Work
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: 40152 Visits: 20000
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
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