Home » SQL & PL/SQL » SQL & PL/SQL » Optional parameter in Where clause (11g, Windows)
|
|
Re: Optional parameter in Where clause [message #687340 is a reply to message #687339] |
Sat, 25 February 2023 09:25   |
Solomon Yakobson
Messages: 3305 Registered: January 2010 Location: Connecticut, USA
|
Senior Member |
|
|
Michel,
None of it will work:
SQL> variable p1 varchar2(20)
SQL> variable p2 varchar2(20)
SQL> -- This should return all rows where state is Texas, but it doesn't
SQL> exec :p1 := 'Texas'
PL/SQL procedure successfully completed.
SQL> with customers as (
2 select 'Texas' state,'San Antonio' city from dual union all
3 select 'Texas',null from dual
4 )
5 select *
6 from customers
7 where state = :p1
8 and city = nvl(:p2,' ')
9 /
no rows selected
SQL> -- This should return rows where state is Texas and city is San Antonio, but it doesn't
SQL> exec :p2 := 'San Antonio'
PL/SQL procedure successfully completed.
SQL> with customers as (
2 select 'Texas' state,'San Antonio' city from dual union all
3 select 'Texas',null from dual
4 )
5 select *
6 from customers
7 where :p1 = 'Texas'
8 and lnnvl(city != :p2)
9 /
STATE CITY
----- -----------
Texas San Antonio
Texas
SQL> -- This should return no rows since there is no city New York in state of Texas, but it doesn't
SQL> exec :p2 := 'New York'
PL/SQL procedure successfully completed.
SQL> with customers as (
2 select 'Texas' state,'San Antonio' city from dual union all
3 select 'Texas',null from dual
4 )
5 select *
6 from customers
7 where :p1 = 'Texas'
8 and lnnvl(city != :p2)
9 /
STATE CITY
----- -----------
Texas
SQL>
One solution would be:
SQL> variable p1 varchar2(20)
SQL> variable p2 varchar2(20)
SQL> -- This returns all rows where state is Texas
SQL> exec :p1 := 'Texas'
PL/SQL procedure successfully completed.
SQL> with customers as (
2 select 'Texas' state,'San Antonio' city from dual union all
3 select 'Texas',null from dual
4 )
5 select *
6 from customers
7 where state = :p1
8 and (
9 city = :p2
10 or
11 :p2 is null
12 )
13 /
STATE CITY
----- -----------
Texas San Antonio
Texas
SQL> -- This returns rows where state is Texas and city is San Antonio
SQL> exec :p2 := 'San Antonio'
PL/SQL procedure successfully completed.
SQL> with customers as (
2 select 'Texas' state,'San Antonio' city from dual union all
3 select 'Texas',null from dual
4 )
5 select *
6 from customers
7 where :p1 = 'Texas'
8 and (
9 city = :p2
10 or
11 :p2 is null
12 )
13 /
STATE CITY
----- -----------
Texas San Antonio
SQL> -- This should return no rows since there is no city New York in state of Texas
SQL> exec :p2 := 'New York'
PL/SQL procedure successfully completed.
SQL> with customers as (
2 select 'Texas' state,'San Antonio' city from dual union all
3 select 'Texas',null from dual
4 )
5 select *
6 from customers
7 where :p1 = 'Texas'
8 and (
9 city = :p2
10 or
11 :p2 is null
12 )
13 /
no rows selected
SQL>
SY.
[Updated on: Sat, 25 February 2023 09:28] Report message to a moderator
|
|
|
|
Goto Forum:
Current Time: Thu Jun 05 23:41:44 CDT 2025
|