select * from v$nls_valid_values where parameter='SORT';
--
-- Territory
--
select to_char(sysdate, 'd') from dual;
T
-
3
alter session set nls_territory=RUSSIA;
Session altered.
select to_char(sysdate, 'd') from dual;
T
-
2
--
-- Be careful, for varchar columns optimizer will not use index for sorting
--
13:45:19 SQL> select value from nls_session_parameters where parameter = 'NLS_SORT';
VALUE
----------------------------------------
RUSSIAN
13:46:54 SQL> select * from id order by id;
Elapsed: 00:00:00.01
Execution Plan
----------------------------------------------------------
Plan hash value: 1459189690
-----------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes |TempSpc| Cost (%CPU)| Time |
-----------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 10145 | 14M| | 3196 (1)| 00:00:39 |
| 1 | SORT ORDER BY | | 10145 | 14M| 31M| 3196 (1)| 00:00:39 |
| 2 | TABLE ACCESS FULL| ID | 10145 | 14M| | 6 (0)| 00:00:01 |
-----------------------------------------------------------------------------------
13:47:24 SQL> alter session set nls_sort=binary;
Session altered.
Elapsed: 00:00:00.01
13:47:31 SQL> select * from id order by id;
Elapsed: 00:00:00.00
Execution Plan
----------------------------------------------------------
Plan hash value: 4052251165
--------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 10145 | 14M| 19 (0)| 00:00:01 |
| 1 | INDEX FULL SCAN | SYS_C006460 | 10145 | 14M| 19 (0)| 00:00:01 |
--------------------------------------------------------------------------------
--
-- You can create linguistic index but in this case table will be accessed too
--
14:49:47 SQL> alter session set nls_sort=russian;
Session altered.
Elapsed: 00:00:00.01
14:50:49 SQL> select value from nls_session_parameters where parameter = 'NLS_SORT';
VALUE
----------------------------------------
RUSSIAN
1 row selected.
Elapsed: 00:00:00.01
14:51:16 SQL> set autotrace traceonly exp
14:51:31 SQL> select * from id order by id;
Elapsed: 00:00:00.01
Execution Plan
----------------------------------------------------------
Plan hash value: 3088927961
--------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 10145 | 14M| 954 (0)| 00:00:12 |
| 1 | TABLE ACCESS BY INDEX ROWID| ID | 10145 | 14M| 954 (0)| 00:00:12 |
| 2 | INDEX FULL SCAN | ID_IDX | 10145 | | 16 (0)| 00:00:01 |
--------------------------------------------------------------------------------------
Note
-----
- dynamic sampling used for this statement
This site contains information, scripts and instructions related to Oracle database and other technologies. Please use sqlplus and test my scripts on test environment before actual use on production. All relevant comments are welcome.
Страницы
- Main
- Veritas cluster
- AIX
- Solaris
- Linux
- Performance scripts
- RAC
- TNS
- Init parameters
- Dataguard
- ASM
- Unix tips
- VxVM
- Linux HA (hearbeat)
- Oracle internals
- Metalink (useful notes)
- Security
- OGG Oracle Golden Gate
- HTML/JavaScript in sqlplus
- Automatic TSPITR 11.2.0.3 (dropped user)
- 12.1
- SQL Performance Analyzer
- Backup/Recovery
- Alert log
вторник, 25 января 2011 г.
понедельник, 24 января 2011 г.
Dev: Find string in table
--
-- Sometimes it is needed to find column/rowid in table with value from screen of web --application etc. That procedure helps to do that, example:
--09:09:43 SQL> create table test as select * from dba_objects;
--...
--09:10:53 SQL> /
--Enter value for table_name: test
--Enter value for string: DBA_OBJECTS
--GENERATED
--OBJECT_NAME
--rowid: AAAMvZAABAAAPk+AAj in SYS.TEST <<-- finding only first occurence
-- Should not be used as is for partitioned tables
--
set serveroutput on
declare
procedure find_string_in_table(val varchar2)
is
v_where Varchar2(32767);
type rc is ref cursor;
c rc;
v_rowid rowid;
begin
for r in (
select
t.owner||'.'||t.table_name table_name, t.column_name
from
dba_tab_cols t
where t.table_name = upper(trim('&table_name'))
and t.data_type like '%CHAR%'
order by t.column_name) loop
dbms_output.put_line(r.column_name);
v_where := ' where ' || r.column_name || ' like ''%' || val || '%''';
open c for 'select rowid from ' || r.table_name || ' ' || v_where;
fetch c into v_rowid;
loop
fetch c into v_rowid;
exit when c%notfound;
dbms_output.put_line(' rowid: ' || v_rowid || ' in ' || r.table_name);
return;
end loop;
end loop;
end;
begin
find_string_in_table('&string');
end;
/
-- Sometimes it is needed to find column/rowid in table with value from screen of web --application etc. That procedure helps to do that, example:
--09:09:43 SQL> create table test as select * from dba_objects;
--...
--09:10:53 SQL> /
--Enter value for table_name: test
--Enter value for string: DBA_OBJECTS
--GENERATED
--OBJECT_NAME
--rowid: AAAMvZAABAAAPk+AAj in SYS.TEST <<-- finding only first occurence
-- Should not be used as is for partitioned tables
--
set serveroutput on
declare
procedure find_string_in_table(val varchar2)
is
v_where Varchar2(32767);
type rc is ref cursor;
c rc;
v_rowid rowid;
begin
for r in (
select
t.owner||'.'||t.table_name table_name, t.column_name
from
dba_tab_cols t
where t.table_name = upper(trim('&table_name'))
and t.data_type like '%CHAR%'
order by t.column_name) loop
dbms_output.put_line(r.column_name);
v_where := ' where ' || r.column_name || ' like ''%' || val || '%''';
open c for 'select rowid from ' || r.table_name || ' ' || v_where;
fetch c into v_rowid;
loop
fetch c into v_rowid;
exit when c%notfound;
dbms_output.put_line(' rowid: ' || v_rowid || ' in ' || r.table_name);
return;
end loop;
end loop;
end;
begin
find_string_in_table('&string');
end;
/
Подписаться на:
Сообщения (Atom)
Update BLOB
set define off DECLARE vb1 CLOB := 'long text'; vb2 CLOB := 'long text'; vb3 CLOB := ...
-
set define off DECLARE vb1 CLOB := 'long text'; vb2 CLOB := 'long text'; vb3 CLOB := ...
-
RMAN> sql "alter database datafile '/u01/app/oracle/oradata/orcl/test_1.dbf' off line"; using target database contro...
-
-- After media failure 03:03:25 150 4294967295 SYS@orcl> select * from t_t where object_name = 'test'; select * from t_t where ob...