Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Help in creating T-SQL where clause


Help in creating T-SQL where clause

Author
Message
PradeepVallabh
PradeepVallabh
Valued Member
Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)

Group: General Forum Members
Points: 55 Visits: 526
My front end aspx web page has a form with some text boxes, dropdown, radiobuttons, Datagrid and searchbutton. I need to populate Datagrid based upon the result set from searchbutton click event....Now the problem is not all the textboxes, dropdown's and radiobutton are required fields...Query for the searchbutton click event depends upon the search parameters provided by the user...

I am trying to figure out where condition for the query, but my query is becoming more and more complex as i have to check everytime whether each and every search parameter exists and write sql accordingly

PS: I have 8 different parameters for the form and only 2 parameters are required fields

Is there any better way of handling this issue?
Kevin.roberts25
Kevin.roberts25
Forum Newbie
Forum Newbie (6 reputation)Forum Newbie (6 reputation)Forum Newbie (6 reputation)Forum Newbie (6 reputation)Forum Newbie (6 reputation)Forum Newbie (6 reputation)Forum Newbie (6 reputation)Forum Newbie (6 reputation)

Group: General Forum Members
Points: 6 Visits: 12
Try this which I got from code project, its a great way to do a query from a form with multiple parameters


Create Procedure sp_EmployeeSelect_Coalesce
@EmployeeName NVarchar(100),
@Department NVarchar(50),
@Designation NVarchar(50),
@StartDate DateTime,
@EndDate DateTime,
@Salary Decimal(10,2)

AS
Set NoCount ON

Select * From tblEmployees
where EmployeeName = Coalesce(@EmployeeName, EmployeeName) AND
Department = Coalesce(@Department, Department ) AND
Designation = Coalesce(@Designation, Designation) AND
JoiningDate >= Coalesce(@StartDate, JoiningDate) AND
JoiningDate <= Coalesce(@EndDate, JoiningDate) AND
Salary >= Coalesce(@Salary, Salary)

If @@ERROR <> 0 GoTo ErrorHandler
Set NoCount OFF
Return(0)

ErrorHandler:
Return(@@ERROR)
GO


Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)

Group: General Forum Members
Points: 45051 Visits: 39900
Kevin.roberts25 (2/19/2013)
Try this which I got from code project, its a great way to do a query from a form with multiple parameters


Create Procedure sp_EmployeeSelect_Coalesce
@EmployeeName NVarchar(100),
@Department NVarchar(50),
@Designation NVarchar(50),
@StartDate DateTime,
@EndDate DateTime,
@Salary Decimal(10,2)

AS
Set NoCount ON

Select * From tblEmployees
where EmployeeName = Coalesce(@EmployeeName, EmployeeName) AND
Department = Coalesce(@Department, Department ) AND
Designation = Coalesce(@Designation, Designation) AND
JoiningDate >= Coalesce(@StartDate, JoiningDate) AND
JoiningDate <= Coalesce(@EndDate, JoiningDate) AND
Salary >= Coalesce(@Salary, Salary)

If @@ERROR <> 0 GoTo ErrorHandler
Set NoCount OFF
Return(0)

ErrorHandler:
Return(@@ERROR)
GO



Kevin,

First, I know this isn't your fault and I'm not slamming you. You found what you think is a good article or post.

Have you got a link for that reference? I ask because I'd like to go there and set those folks straight on how bad this form of "Catch All" query can be since INDEX SCANS are virtually the only thing guaranteed to happen here.

The correct way to do this is with properly written, SQL-Injection-proof code. Please see the following article on one method for how easily this is accomplished.
http://sqlinthewild.co.za/index.php/2009/03/19/catch-all-queries/

Also, the use of GOTO has fallen out of favor with most people. TRY/CATCH seems to be the way to go now for most things.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Kevin.roberts25
Kevin.roberts25
Forum Newbie
Forum Newbie (6 reputation)Forum Newbie (6 reputation)Forum Newbie (6 reputation)Forum Newbie (6 reputation)Forum Newbie (6 reputation)Forum Newbie (6 reputation)Forum Newbie (6 reputation)Forum Newbie (6 reputation)

Group: General Forum Members
Points: 6 Visits: 12
sure here's the link, I dont use the whole thing I just found the use of the Coalesce statement interesting as i normally use where (columnName is null) or ( columnName =@columnName )

Code project Article Link
PradeepVallabh
PradeepVallabh
Valued Member
Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)Valued Member (55 reputation)

Group: General Forum Members
Points: 55 Visits: 526
Coalesce is something which doesn't give me the desired results....All i am trying to do is, if the parameter is not passed from UI i need to remove the parameter from where clause of sql Stored procedure ....

I guess probably the only way to handle this is to separate out the query and where clause(in Stored procedure) and use sp_executesql finally(which i hate doing it as i have to check everytime where the parameter is not null)

Anyother suggestions or thoughts???
brad.mason5
brad.mason5
SSCommitted
SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)

Group: General Forum Members
Points: 1521 Visits: 2008
I attended a training by Itzik Ben Gan and we found that this technique worked the best for our data set.

-- Stored Procedure GetOrders,
-- Using Dynamic SQL
ALTER PROC dbo.GetOrders
@orderid AS INT = NULL,
@custid AS INT = NULL,
@empid AS INT = NULL,
@orderdate AS DATETIME = NULL
AS

DECLARE @sql AS NVARCHAR(1000);

SET @sql =
N'SELECT orderid, custid, empid, orderdate, filler /* 27702431-107C-478C-8157-6DFCECC148DD */'
+ N' FROM dbo.Orders'
+ N' WHERE 1 = 1'
+ CASE WHEN @orderid IS NOT NULL THEN
N' AND orderid = @oid' ELSE N'' END
+ CASE WHEN @custid IS NOT NULL THEN
N' AND custid = @cid' ELSE N'' END
+ CASE WHEN @empid IS NOT NULL THEN
N' AND empid = @eid' ELSE N'' END
+ CASE WHEN @orderdate IS NOT NULL THEN
N' AND orderdate = @dt' ELSE N'' END;

EXEC sp_executesql
@stmt = @sql,
@params = N'@oid AS INT, @cid AS INT, @eid AS INT, @dt AS DATETIME',
@oid = @orderid,
@cid = @custid,
@eid = @empid,
@dt = @orderdate;
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