Skip to Main Content
  • Questions
  • Case sensitive search in case insensitive database

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, Pablo.

Asked: November 19, 2015 - 11:14 am UTC

Last updated: February 25, 2020 - 8:41 am UTC

Version: 10R2

Viewed 1000+ times

You Asked

Hi,

I'm using a database that is mostly case insensitive, using this login trigger:

create trigger milenio_central_logon after logon on milenio_central.schema
begin
execute immediate 'alter session set NLS_COMP=LINGUISTIC';
execute immediate 'alter session set NLS_SORT=XSPANISH_AI';
execute immediate 'alter session set NLS_LENGTH_SEMANTICS=CHAR';
end;


and also by making all all text-based indexes case insensitive:

create index ix_usuarios_selector on com_usuarios(nlssort(selector,'NLS_SORT=XSPANISH_AI'));


This is working great for all queries except for a single table, for which we need to do a case sensitive select.

I wonder what are my options to temporaly disable case insensitivity for this select?

Regards,

Pablo.

and Connor said...

Is there any reason you cant issue 'alter session' commands to reinstate case sensitivity back to before running the query ?

The index will then be an issue (ie, the optimizer wont choose it most probably).

In that case, you could add predicates to the queries so that you keep the index use but also enforce case-sensitivity.

eg


SQL> drop table T purge;

Table dropped.

SQL>
SQL> create table T as select * from dba_Objects;

Table created.

SQL>
SQL> create index IX on T ( nlssort(object_name,'NLS_SORT=BINARY_CI'));

Index created.

SQL>
SQL> begin
  2  execute immediate 'alter session set NLS_COMP=LINGUISTIC';
  3  execute immediate 'alter session set NLS_SORT=BINARY_CI';
  4  execute immediate 'alter session set NLS_LENGTH_SEMANTICS=CHAR';
  5  end;
  6  /

PL/SQL procedure successfully completed.

SQL>
SQL> set autotrace on explain
SQL>
SQL> select count(owner)
  2  from T
  3  where object_name = 'ABC';

COUNT(OWNER)
------------
           1


Execution Plan
----------------------------------------------------------
Plan hash value: 2143077847

---------------------------------------------------------------------------------------------
| Id  | Operation                            | Name | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                     |      |     1 |   115 |   194   (0)| 00:00:01 |
|   1 |  SORT AGGREGATE                      |      |     1 |   115 |            |          |
|   2 |   TABLE ACCESS BY INDEX ROWID BATCHED| T    |   913 |   102K|   194   (0)| 00:00:01 |
|*  3 |    INDEX RANGE SCAN                  | IX   |   365 |       |     3   (0)| 00:00:01 |
---------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access(NLSSORT("OBJECT_NAME",'nls_sort=''BINARY_CI''')=HEXTORAW('61626300'))

SQL>
SQL> select count(owner)
  2  from T
  3  where object_name = 'abc';

COUNT(OWNER)
------------
           1


Execution Plan
----------------------------------------------------------
Plan hash value: 2143077847

---------------------------------------------------------------------------------------------
| Id  | Operation                            | Name | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                     |      |     1 |   115 |   194   (0)| 00:00:01 |
|   1 |  SORT AGGREGATE                      |      |     1 |   115 |            |          |
|   2 |   TABLE ACCESS BY INDEX ROWID BATCHED| T    |   913 |   102K|   194   (0)| 00:00:01 |
|*  3 |    INDEX RANGE SCAN                  | IX   |   365 |       |     3   (0)| 00:00:01 |
---------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access(NLSSORT("OBJECT_NAME",'nls_sort=''BINARY_CI''')=HEXTORAW('61626300'))

SQL>
SQL> select count(owner)
  2  from T
  3  where object_name = 'abc'
  4  and ora_hash(object_name) = ora_hash('abc');

COUNT(OWNER)
------------
           0


Execution Plan
----------------------------------------------------------
Plan hash value: 2143077847

---------------------------------------------------------------------------------------------
| Id  | Operation                            | Name | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                     |      |     1 |   115 |   194   (0)| 00:00:01 |
|   1 |  SORT AGGREGATE                      |      |     1 |   115 |            |          |
|*  2 |   TABLE ACCESS BY INDEX ROWID BATCHED| T    |     9 |  1035 |   194   (0)| 00:00:01 |
|*  3 |    INDEX RANGE SCAN                  | IX   |   365 |       |     3   (0)| 00:00:01 |
---------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - filter(ORA_HASH("OBJECT_NAME")=1194017796)
   3 - access(NLSSORT("OBJECT_NAME",'nls_sort=''BINARY_CI''')=HEXTORAW('61626300'))

SQL>
SQL>







Rating

  (1 rating)

Is this answer out of date? If it is, please let us know via a Comment

Comments

Is there another option

Duncan Gardner, February 25, 2020 - 6:49 am UTC

Is there an alternative to setting session parameters (which means you need to query existing settings and restore them)?
A way of getting a SELECT statement to ignore NLS_COMP session setting, or to use NLS_COMP=BINARY?
Connor McDonald
February 25, 2020 - 8:41 am UTC

Not really, because NLS settings control more than just the *execution* but how we fetch the results and return them to you etc. They are truly a change to the *session*.

More to Explore

PL/SQL demos

Check out more PL/SQL tutorials on our LiveSQL tool.

PL/SQL docs

PL/SQL reference manual from the Oracle documentation library