473,406 Members | 2,698 Online
Bytes | Software Development & Data Engineering Community
Post Job

Home Posts Topics Members FAQ

Join Bytes to post your question to a community of 473,406 software developers and data experts.

IF ELSE with WHERE, AND, OR

What would be the correct way of writing a sql select state with where
clause while also using IF ELSE. I am using T-SQL and I cannot get it
to work. I probably have the syntax wrong.

I want to be able to have different where/and/or clauses in the sql
dependant on what value was passed into the @SearchTerm parameter in
this stored procedure.

Can I use CASE statements in the WHERE section? Or is that strickly for
SELECT statements?

Code as follows:

================================================== ==============

CREATE PROCEDURE spTicketReport
(
@SearchTerm varchar(100) = NULL
)
AS
BEGIN
SELECT TOP 100 PERCENT Tickets.TicketID, Tickets.TicketNumber AS
TicketNumber, Haulers.Name AS Hauler, Leases.LeaseID AS LeaseID,
Leases.LeaseName AS Lease, Shippers.Name AS
Shipper, Tickets.FeeTox, Tickets.FeeWashout, Tickets.FeeDisposal,
Tickets.Yards, Tickets.Barrels,
Tickets.FluidSolidRatio, DATEPART(yyyy, Tickets.DateAdded) AS [Year]
FROM Tickets INNER JOIN
Leases ON Tickets.LeaseID = Leases.LeaseID INNER
JOIN
Haulers ON Tickets.HaulerID = Haulers.HaulerID
INNER JOIN
Shippers ON Tickets.ShipperID =
Shippers.ShipperID
WHERE TicketNumber LIKE '%' + @SearchTerm + '%' OR Haulers.Name LIKE
'%' + @SearchTerm + '%' OR Shippers.Name LIKE '%' + @SearchTerm + '%'
OR Leases.LeaseName LIKE '%' + @SearchTerm + '%'
ORDER BY TicketNumber, Shipper, Hauler

================================================== ==============

Thanks in advance!

Jason Cochran
Rethink Technologies, L.L.C.
www.rethinkllc.com

Jul 28 '05 #1
7 26478
(jc******@rethinkllc.com) writes:
What would be the correct way of writing a sql select state with where
clause while also using IF ELSE. I am using T-SQL and I cannot get it
to work. I probably have the syntax wrong.

I want to be able to have different where/and/or clauses in the sql
dependant on what value was passed into the @SearchTerm parameter in
this stored procedure.

Can I use CASE statements in the WHERE section? Or is that strickly for
SELECT statements?


You cannot use CASE statements, because there are none in T-SQL. But
you can use CASE expressions in a WHERE clause:

WHERE CASE WHEN @SearchTerm LIKE <a ticket number>
THEN TicketNumber LIKE '%' + @SearchTerm + '%'
WHEN @SearchTerm LIKE <a haluers name>
THEN Haulers.Name
ELSE Leases.LeaseName
END LIKE '%' + @SearchTerm + '%'

--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for SQL Server SP3 at
http://www.microsoft.com/sql/techinf...2000/books.asp
Jul 28 '05 #2
This is a good piece of information, however it can be achieved by the
other way as well...
By using parantheses and boolean operators (AND, OR, NOT) properly.

Something like this:

WHERE ( @SearchTerm LIKE <a ticket number> AND TicketNumber LIKE '%'
+ @SearchTerm + '%' )
OR
( @SearchTerm LIKE <a haluers name> AND Haulers.Name LIKE '%' +
@SearchTerm + '%' )
OR
( Leases.LeaseName LIKE '%' + @SearchTerm + '%' )

Jul 29 '05 #3
Hi Erland,
Very informative answer , but from performance point of view we should
not be using Like

Most DBMSs will use an index for a LIKE pattern if it starts with a
real character but will avoid an index for a LIKE pattern that starts
with a wildcard (either % or _). The only DBMSs that never use indexes
for LIKE are Pick and mSQL (on TEXT fields). For example, if the search
condition is:
.... WHERE column1 LIKE 'C_F%'
DBMSs will resolve it by finding all index keys that start with C and
then filtering those that contain F in the third position. In other
words, you don't need to transform this search condition:
Here '%' is being used at the beginning so I think using charindex will
do fine job (Please correct it if wrong)

Where charindex
( @SearchTerm,
(
CASE
WHEN charindex(@SearchTerm, a ticket number )>0 THEN TicketNumber

WHEN charindex(@SearchTerm,a haluers name) > 0 THEN Haulers.Name

ELSE Leases.LeaseName
END
)
)>0

With warm regards
Jatinder

Jul 29 '05 #4
I appreciate everyones help on this.

What if I wanted to add another parameter named @AccountID. AccountID
is used to track who created the ticket. @AccountID would be set to
NULL just like @SearchTerm is. I wanted to be able to check to see if
either was passed in. Sometimes both will be; other times it will be
either/or.

============ PSEUDO CODE ===================

WHERE TicketID != 0

IF NOT @SearchTerm IS NULL THEN
AND (TicketNumber LIKE '%' + @SearchTerm + '%' OR Haulers.Name
LIKE '%' + @SearchTerm + '%' OR Shippers.Name LIKE '%' + @SearchTerm +
'%' OR Leases.LeaseName LIKE '%' + @SearchTerm + '%' )
END IF
IF NOT @AccountID IS NULL THEN
AND AccountID = @AccountID
END IF

ORDER BY TicketNumber, Shipper, Hauler

============ END PSEUDO CODE ===================

Jul 29 '05 #5
(jc******@rethinkllc.com) writes:
I appreciate everyones help on this.

What if I wanted to add another parameter named @AccountID. AccountID
is used to track who created the ticket. @AccountID would be set to
NULL just like @SearchTerm is. I wanted to be able to check to see if
either was passed in. Sometimes both will be; other times it will be
either/or.
...
IF NOT @AccountID IS NULL THEN
AND AccountID = @AccountID
END IF


AND (AccountID = @AccountID OR @AccountID IS NULL)

However, beware that if you want any index on AccuontID to be use, you
better split this up and have two different SELECT statements.

For a much longer discussion on a problem which you have not really
reached, but seem to be on your way to, I have an article on my web
site that you can save for a rainy day:
http://www.sommarskog.se/dyn-search.html.
--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for SQL Server SP3 at
http://www.microsoft.com/sql/techinf...2000/books.asp
Jul 29 '05 #6
Looking at that article you mentioned; under if statements, the code
below is mentioned. It just seems like a very nasty way of doing
things. I could do it this way BUT I just think there should be a much
cleaner way of doing it. If I had to change/remove/add a column in the
select statement, I would have 3 other places to do it in. The WHERE
statement should be the only thing that is different. I shouldnt have
to have the same select statement 3 times.

IF @orderid IS NOT NULL
BEGIN
SELECT ...
WHERE o.OrderID = @orderid
AND od.OrderID = @orderid
AND (od.UnitPrice >= @minprice OR @minprice IS NULL)
AND (od.UnitPrice <= @maxprice OR @maxprice IS NULL)
AND (od.ProductID = @prodid OR @prodid IS NULL)
AND (p.ProductName LIKE @prodname + '%' OR @prodname IS NULL)
ORDER BY o.OrderID
END
ELSE IF @custid IS NOT NULL
BEGIN
SELECT ...
WHERE (o.OrderDate >= @fromdate OR @fromdate IS NULL)
AND (o.OrderDate <= @todate OR @todate IS NULL)
AND (od.UnitPrice >= @minprice OR @minprice IS NULL)
AND (od.UnitPrice <= @maxprice OR @maxprice IS NULL)
AND c.CustomerID = @custid
AND o.CustomerID = @custid
AND (od.ProductID = @prodid OR @prodid IS NULL)
AND (p.ProductName LIKE @prodname + '%' OR @prodname IS NULL)
ORDER BY o.OrderID
END
ELSE
BEGIN
SELECT ...
WHERE (o.OrderDate >= @fromdate OR @fromdate IS NULL)
AND (o.OrderDate <= @todate OR @todate IS NULL)
AND (od.UnitPrice >= @minprice OR @minprice IS NULL)
AND (od.UnitPrice <= @maxprice OR @maxprice IS NULL)
AND (c.CompanyName LIKE @custname + '%' OR @custname IS NULL)
AND (c.City = @city OR @city IS NULL)
AND (c.Region = @region OR @region IS NULL)
AND (c.Country = @country OR @country IS NULL)
AND (od.ProductID = @prodid OR @prodid IS NULL)
AND (p.ProductName LIKE @prodname + '%' OR @prodname IS NULL)
ORDER BY o.OrderID
END

Jul 29 '05 #7
jc******@rethinkllc.com (jc******@rethinkllc.com) writes:
Looking at that article you mentioned; under if statements, the code
below is mentioned. It just seems like a very nasty way of doing
things.
This is indeed not a method that scales well in terms of maintenance
when you have many different conditions, and I also note this in the
article.
I could do it this way BUT I just think there should be a much
cleaner way of doing it. If I had to change/remove/add a column in the
select statement, I would have 3 other places to do it in. The WHERE
statement should be the only thing that is different. I shouldnt have
to have the same select statement 3 times.


Well, it depends with you mean with cleaner. You can do all in one
single static SQL statement, and from the perspective of maintenance
and functionality you would be fine. However, SQL programming is also
a lot about performance. If your table has 100 million rows, you don't
want a table scan to happen on an interactive query.

For this reason, one sometimes has to duplicate code in a way that
conflicts with the best practices you've learnt when working with
traditional languages.
--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for SQL Server SP3 at
http://www.microsoft.com/sql/techinf...2000/books.asp
Jul 29 '05 #8

This thread has been closed and replies have been disabled. Please start a new discussion.

Similar topics

11
by: dmbkiwi | last post by:
I am new to this group, and relatively new to python programming, however, have encountered a problem I just cannot solve through reading the documentation, and searching this group on google. I...
23
by: Invalid User | last post by:
While trying to print a none empty list, I accidentaly put an "else" statement with a "for" instead of "if". Here is what I had: if ( len(mylist)> 0) : for x,y in mylist: print x,y else:...
6
by: Christian Seberino | last post by:
I am looking at the ELSE home page and trying to figure out if I should invest the time to learn about the ELSE minor mode for Emacs. Is there any programmer out there using ELSE that is getting...
27
by: Ron Adam | last post by:
There seems to be a fair amount of discussion concerning flow control enhancements lately. with, do and dowhile, case, etc... So here's my flow control suggestion. ;-) It occurred to me (a...
2
by: phaser2001 | last post by:
Hi all, I have the below user-defined function on mssql 2000 and I can't work out why i'm getting the following error: ----- Server: Msg 156, Level 15, State 1, Procedure...
5
by: WindAndWaves | last post by:
Hi Team The function below searches all the tables in a database. However, if subsearch = true then it searches all the objects listed in a recordset (which are all table names). I thought to...
8
by: Jim Michaels | last post by:
C:\prj\quiz\withusers>php tareports.php PHP Parse error: syntax error, unexpected T_ELSE in C:\prj\quiz\withusers\tareports.php on line 205 this is the section of code. if (isset($row4)) {...
2
by: juan-manuel.behrendt | last post by:
Hello together, I wrote a script for the engineering software abaqus/CAE. It worked well until I implemented a selection in order to variate the variable "lGwU" through an if elif, else...
2
by: pradeep.thekkottil | last post by:
I'm setting up an auction website using PHP and MySQL. There in the section where logged in members can put up new auction in a form, I want to run a form validation where I used if else statements...
1
by: Jeffy | last post by:
I'm trying to create an if/else case in a stored procedure where if te record is not found, it returns blank values, and if it is found I get the real values. But when I try to execute the SP update...
0
by: Charles Arthur | last post by:
How do i turn on java script on a villaon, callus and itel keypad mobile phone
0
BarryA
by: BarryA | last post by:
What are the essential steps and strategies outlined in the Data Structures and Algorithms (DSA) roadmap for aspiring data scientists? How can individuals effectively utilize this roadmap to progress...
1
by: nemocccc | last post by:
hello, everyone, I want to develop a software for my android phone for daily needs, any suggestions?
1
by: Sonnysonu | last post by:
This is the data of csv file 1 2 3 1 2 3 1 2 3 1 2 3 2 3 2 3 3 the lengths should be different i have to store the data by column-wise with in the specific length. suppose the i have to...
0
by: Hystou | last post by:
There are some requirements for setting up RAID: 1. The motherboard and BIOS support RAID configuration. 2. The motherboard has 2 or more available SATA protocol SSD/HDD slots (including MSATA, M.2...
0
by: Hystou | last post by:
Most computers default to English, but sometimes we require a different language, especially when relocating. Forgot to request a specific language before your computer shipped? No problem! You can...
0
Oralloy
by: Oralloy | last post by:
Hello folks, I am unable to find appropriate documentation on the type promotion of bit-fields when using the generalised comparison operator "<=>". The problem is that using the GNU compilers,...
0
tracyyun
by: tracyyun | last post by:
Dear forum friends, With the development of smart home technology, a variety of wireless communication protocols have appeared on the market, such as Zigbee, Z-Wave, Wi-Fi, Bluetooth, etc. Each...
0
isladogs
by: isladogs | last post by:
The next Access Europe User Group meeting will be on Wednesday 1 May 2024 starting at 18:00 UK time (6PM UTC+1) and finishing by 19:30 (7.30PM). In this session, we are pleased to welcome a new...

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.