March 9, 2018 at 12:01 am
Below is a sample of what I am trying to accomplish..
@Year AS SMALLINT = NULL,
@Month AS SMALLINT = NULL,
@type AS VARCHAR(5) = NULL,
@debug bit = 0,
@Phone_Mask AS NVARCHAR(50) = NULL,
@flag AS bit
March 9, 2018 at 12:43 am
Whole point of creating a dynamic query is to avoid this kind of scenario. So instead of creating a dynamic query with IF ELSE you should be implementing this flag base logic inside your SP and generate a single dynamic query.
March 9, 2018 at 11:07 am
Try this on for size:CREATE PROCEDURE dbo.YourStoredProc (
@Year AS smallint = NULL,
@Month AS smallint = NULL,
@type AS varchar(5) = NULL,
@debug AS bit = 0,
@Phone_Mask AS nvarchar(50) = NULL,
@flag AS bit
)
AS
BEGIN
SET NOCOUNT ON;
DECLARE @sql AS nvarchar(max) = N'
SELECT EXP_Table.Phone_No,
Acct_Table.code,
Acct_Table.cancel,
EXP_Table.pay,
Acct_Table.Year,
Acct_Table.Month,
FROM EXP_Table
INNER JOIN Acct_Table
ON EXP_Table.EXP_TableAccountsPK = Acct_Table.EXP_TableAccountsFK
WHERE 1 = 1
AND Acct_Table.cancel = 1' +
CASE
WHEN @Year IS NOT NULL THEN N'
AND Acct_Table.Year = ' + CONVERT(char(4), @Year)
ELSE N''
END +
CASE
WHEN @Month IS NOT NULL THEN N'
AND Acct_Table.AjCycle = ' + CONVERT(varchar(2), @month)
ELSE N''
END +
CASE
WHEN @Phone_Mask IS NOT NULL THEN N'
AND (EXP_Table.Phone_No LIKE ''' + @Phone_Mask + N'%'')'
ELSE N''
END +
CASE @type
WHEN '1' THEN N'
AND Acct_Table.code IN (4110, 4015)'
WHEN '2' THEN N'
AND Acct_Table.code IN (4120, 4125)'
WHEN '3' THEN N'
AND Acct_Table.code IN (4130, 4135, 4210, 4215, 4230, 4235, 4240, 4245)'
ELSE N''
END +
CASE @flag
WHEN 0 THEN N'
AND EXP_Table.pay = 0;'
WHEN 1 THEN N'
AND EXP_Table.pay IN (0, 1);'
ELSE N';'
END;
IF @debug = 1
BEGIN
PRINT @sql;
END;
EXEC sp_executesql @sql;
END;
GO
Steve (aka sgmunson) 🙂 🙂 🙂
Rent Servers for Income (picks and shovels strategy)
March 9, 2018 at 1:43 pm
twin.devil - Friday, March 9, 2018 12:43 AMWhole point of creating a dynamic query is to avoid this kind of scenario. So instead of creating a dynamic query with IF ELSE you should be implementing this flag base logic inside your SP and generate a single dynamic query.
Not quite true. Please see the following article.
https://www.sqlinthewild.co.za/index.php/2009/03/19/catch-all-queries/
--Jeff Moden
Change is inevitable... Change for the better is not.
March 10, 2018 at 10:41 pm
Steve,
Thank you very much for your reply, it work great... Really appreciate it...
,
March 12, 2018 at 4:24 am
Jeff Moden - Friday, March 9, 2018 1:43 PMtwin.devil - Friday, March 9, 2018 12:43 AMWhole point of creating a dynamic query is to avoid this kind of scenario. So instead of creating a dynamic query with IF ELSE you should be implementing this flag base logic inside your SP and generate a single dynamic query.Not quite true. Please see the following article.
https://www.sqlinthewild.co.za/index.php/2009/03/19/catch-all-queries/
Jeff, I know this method and this article and i haven't said anything against it either. My comments was solely against the below output of the dynamic query shared by Op's.
------- Below is part of the IF ELSE I am trying to do in Dynamic SQL above -------------------------------------------------------------------------------------IF @flag =0 AND @type = 1
SELECT...... WHERE Acct_Table.Month = @Month
AND Acct_Table.Year = @Year
AND Acct_Table.Code IN (4110,4015)
AND (EXP_Table.Phone_No LIKE @Phone_Mask)
AND Acct_Table.Cancel = 1
AND EXP_Table.pay = 0Else IF @flag = 1 AND @type = 2
SELECT ....... WHERE Acct_Table.Month = @Month
AND Acct_Table.Year = @Year
AND Acct_Table.Code IN (4120,4125)
AND (EXP_Table.Phone_No LIKE @Phone_Mask)
AND Acct_Table.Cancel = 1
AND (EXP_Table.pay = 0 OR EXP_Table.pay = 1)
So instead of applying IF ELSE inside the dynamic query, SP should contain this logic.
March 12, 2018 at 7:53 am
twin.devil - Monday, March 12, 2018 4:24 AMJeff Moden - Friday, March 9, 2018 1:43 PMtwin.devil - Friday, March 9, 2018 12:43 AMWhole point of creating a dynamic query is to avoid this kind of scenario. So instead of creating a dynamic query with IF ELSE you should be implementing this flag base logic inside your SP and generate a single dynamic query.Not quite true. Please see the following article.
https://www.sqlinthewild.co.za/index.php/2009/03/19/catch-all-queries/Jeff, I know this method and this article and i haven't said anything against it either. My comments was solely against the below output of the dynamic query shared by Op's.
------- Below is part of the IF ELSE I am trying to do in Dynamic SQL above -------------------------------------------------------------------------------------IF @flag =0 AND @type = 1
SELECT...... WHERE Acct_Table.Month = @Month
AND Acct_Table.Year = @Year
AND Acct_Table.Code IN (4110,4015)
AND (EXP_Table.Phone_No LIKE @Phone_Mask)
AND Acct_Table.Cancel = 1
AND EXP_Table.pay = 0Else IF @flag = 1 AND @type = 2
SELECT ....... WHERE Acct_Table.Month = @Month
AND Acct_Table.Year = @Year
AND Acct_Table.Code IN (4120,4125)
AND (EXP_Table.Phone_No LIKE @Phone_Mask)
AND Acct_Table.Cancel = 1
AND (EXP_Table.pay = 0 OR EXP_Table.pay = 1)So instead of applying IF ELSE inside the dynamic query, SP should contain this logic.
Ah... got it. Thanks for the feedback. And, yes... I agree. No IF/ELSE in the dynamic SQL itself.
--Jeff Moden
Change is inevitable... Change for the better is not.
March 12, 2018 at 8:23 am
Jeff Moden - Monday, March 12, 2018 7:53 AMtwin.devil - Monday, March 12, 2018 4:24 AMJeff Moden - Friday, March 9, 2018 1:43 PMtwin.devil - Friday, March 9, 2018 12:43 AMWhole point of creating a dynamic query is to avoid this kind of scenario. So instead of creating a dynamic query with IF ELSE you should be implementing this flag base logic inside your SP and generate a single dynamic query.Not quite true. Please see the following article.
https://www.sqlinthewild.co.za/index.php/2009/03/19/catch-all-queries/Jeff, I know this method and this article and i haven't said anything against it either. My comments was solely against the below output of the dynamic query shared by Op's.
------- Below is part of the IF ELSE I am trying to do in Dynamic SQL above -------------------------------------------------------------------------------------IF @flag =0 AND @type = 1
SELECT...... WHERE Acct_Table.Month = @Month
AND Acct_Table.Year = @Year
AND Acct_Table.Code IN (4110,4015)
AND (EXP_Table.Phone_No LIKE @Phone_Mask)
AND Acct_Table.Cancel = 1
AND EXP_Table.pay = 0Else IF @flag = 1 AND @type = 2
SELECT ....... WHERE Acct_Table.Month = @Month
AND Acct_Table.Year = @Year
AND Acct_Table.Code IN (4120,4125)
AND (EXP_Table.Phone_No LIKE @Phone_Mask)
AND Acct_Table.Cancel = 1
AND (EXP_Table.pay = 0 OR EXP_Table.pay = 1)So instead of applying IF ELSE inside the dynamic query, SP should contain this logic.
Ah... got it. Thanks for the feedback. And, yes... I agree. No IF/ELSE in the dynamic SQL itself.
Thanks for your feedback 🙂
March 12, 2018 at 11:20 am
Thank you all for your reply's, and comments, as a rookie I am learning a lot from the exchanges between you experts, especially the do's and don't when creating Dynamic SQL..
I Really appreciate all the feedbacks.
March 12, 2018 at 11:55 am
SELECT EXP_Table.Phone_No,
Acct_Table.code,
Acct_Table.cancel,
EXP_Table.pay,
Acct_Table.Year,
Acct_Table.Month,
FROM EXP_Table
INNER JOIN Acct_Table
ON EXP_Table.EXP_TableAccountsPK = Acct_Table.EXP_TableAccountsFK
WHERE
(@Year is null or Acct_Table.Year = @Year)
AND (@Month is null or Acct_Table.AjCycle = @Month)
AND (@Phone_Mask is null or EXP_Table.Phone_No LIKE @Phone_Mask + N'%')
AND (
@Type is null
OR (@Type = 1 and Acct_Table.code IN (4110, 4015))
OR (@Type = 2 and Acct_Table.code IN (4120, 4125))
OR (@Type = 3 and Acct_Table.code IN (4130, 4135, 4210, 4215, 4230, 4235, 4240, 4245))
)
AND (
@Flag is null
OR (@flag = 0 and EXP_Table.pay = 0)
OR (@flag = 1 and EXP_Table.pay IN (0, 1))
)
I don't understand why you would want to go through all the complexity of making a dynamic SQL statement for this?
March 12, 2018 at 1:50 pm
Then you should probably read the article linked in Jeff Moden's earlier post about catch-all-queries. While this type of statement may be easier for the developer to write, there is no good way for the database engine to produce an optimized execution plan that would work for all those different scenarios.
March 12, 2018 at 9:07 pm
Isn't that what query hints are for?
"Optimize for" usually helps a lot in these situations. Dynamic sql would still be my last choice to handle performance problems.
https://msdn.microsoft.com/en-us/library/ms181714(v=sql.110).aspx
March 13, 2018 at 9:17 am
oughtsix - Monday, March 12, 2018 11:55 AMI would not do this with dynamic sql. I would just use a straight up sql statement.
SELECT EXP_Table.Phone_No,
Acct_Table.code,
Acct_Table.cancel,
EXP_Table.pay,
Acct_Table.Year,
Acct_Table.Month,
FROM EXP_Table
INNER JOIN Acct_Table
ON EXP_Table.EXP_TableAccountsPK = Acct_Table.EXP_TableAccountsFK
WHERE
(@Year is null or Acct_Table.Year = @Year)
AND (@Month is null or Acct_Table.AjCycle = @Month)
AND (@Phone_Mask is null or EXP_Table.Phone_No LIKE @Phone_Mask + N'%')
AND (
@Type is null
OR (@Type = 1 and Acct_Table.code IN (4110, 4015))
OR (@Type = 2 and Acct_Table.code IN (4120, 4125))
OR (@Type = 3 and Acct_Table.code IN (4130, 4135, 4210, 4215, 4230, 4235, 4240, 4245))
)
AND (
@Flag is null
OR (@flag = 0 and EXP_Table.pay = 0)
OR (@flag = 1 and EXP_Table.pay IN (0, 1))
)I don't understand why you would want to go through all the complexity of making a dynamic SQL statement for this?
Because performance can suffer horribly with catch-all queries...
Steve (aka sgmunson) 🙂 🙂 🙂
Rent Servers for Income (picks and shovels strategy)
March 13, 2018 at 9:29 am
...and right on cue, Gail writes an updated article about catch-all-queries and her latest thoughts on it:
https://www.sqlinthewild.co.za/index.php/2018/03/13/revisiting-catch-all-queries/
March 13, 2018 at 2:39 pm
Chris Harshman - Tuesday, March 13, 2018 9:29 AM...and right on cue, Gail writes an updated article about catch-all-queries and her latest thoughts on it:
https://www.sqlinthewild.co.za/index.php/2018/03/13/revisiting-catch-all-queries/
I like her approach of using query hints... specifically RECOMPILE much better than resorting to dynamic SQL. My understanding of her article is that she now also prefers the RECOMPILE query hint over dynamic SQL... if I understood the article correctly?
Viewing 15 posts - 1 through 14 (of 14 total)
You must be logged in to reply to this topic. Login to reply