1.rowid的介绍
先对rowid有个感官认识:
SQL> select rowid,t.* from scott.dept t
2 /
ROWID DEPTNO DNAME LOC
------------------ ------ -------------- -------------
AAAGDvAABAAAH1UAAA 10 ACCOUNTING NEW YORK
AAAGDvAABAAAH1UAAB 20 RESEARCH DALLAS
AAAGDvAABAAAH1UAAC 30 SALES CHICAGO
AAAGDvAABAAAH1UAAD 40 OPERATIONS BOSTON
SQL>
ROWID的格式如下:
数据对象编号 文件编号 块编号 行编号
OOOOOO FFF BBBBBB RRR
我们可以看出,从上面的rowid可以得知:
AAAGDv 是数据对象编号
AAB是相关文件编号
AAAH1U是块编号
AAA 是行编号
怎么依据这些编号得到具体的十进制的编码值呢,这是经常遇到的问题。这里需要明白rowid的是基于64位编
码的18个字符显示(数据对象编号(6) +文件编号(3) +块编号(6)+ 行编号(3)=18位),其中
A-Z <==> 00 - 25 (26)
a-z <==> 26 - 51 (26)
0-9 <==> 52 - 61 (10)
+/ <==> 62 - 63 (2)
共64位,明白这个后,就可以计算出10进制的编码值,计算公式如下:
d*(b^p)
其中:b就是基数,这里就是64,p就是从右到左,已0开始的位置数
比如:上面的例子
文件号AAB,具体的计算应该是:
1*(64^0)=1;
0*(64^1)=0;
0*(64^2)=0;
文件号就是0+0+1=1
刚才提到的是rowid的显示方式:基于64位编码的18个字符显示,其实rowid的存储方式是:10 个字节即80位
存储,其中数据对象编号需要32 位,相关文件编号需要10 位,块编号需要22,位行编号需要16 位,由此,
我们可以得出:
32bit的object number,每个数据库最多有4G个对象
10bit的file number,每个对象最多有1022个文件(2个文件预留)
22bit的block number,每个文件最多有4M个BLOCK
16bit的row number,每个BLOCK最多有64K个ROWS
2.rowid相关的有用的sql
最简单的基于rowid的显示方式得到的响应的64位编码对应值的sql:
select rowid,
substr(rowid, 1, 6) "OBJECT",
substr(rowid, 7, 3) "FILE",
substr(rowid, 10, 6) "BLOCK",
substr(rowid, 16, 3) "ROW"
from schema.tablename;
SQL> select rowid,
2 substr(rowid, 1, 6) "OBJECT",
3 substr(rowid, 7, 3) "FILE",
4 substr(rowid, 10, 6) "BLOCK",
5 substr(rowid, 16, 3) "ROW"
6 from scott.dept
7 /
ROWID OBJECT FILE BLOCK ROW
------------------ ------------ ------ ------------ ------
AAAGDvAABAAAH1UAAA AAAGDv AAB AAAH1U AAA
AAAGDvAABAAAH1UAAB AAAGDv AAB AAAH1U AAB
AAAGDvAABAAAH1UAAC AAAGDv AAB AAAH1U AAC
AAAGDvAABAAAH1UAAD AAAGDv AAB AAAH1U AAD
SQL>
通过dbms_rowid这个包,可以直接的得到具体的rowid包含的信息:
select dbms_rowid.rowid_object(rowid) object_id,
dbms_rowid.rowid_relative_fno(rowid) file_id,
dbms_rowid.rowid_block_number(rowid) block_id,
dbms_rowid.rowid_row_number(rowid) num
from schema.tablename;
SQL> select dbms_rowid.rowid_object(rowid) object_id,
2 dbms_rowid.rowid_relative_fno(rowid) file_id,
3 dbms_rowid.rowid_block_number(rowid) block_id,
4 dbms_rowid.rowid_row_number(rowid) num
5 from scott.dept
6 /
OBJECT_ID FILE_ID BLOCK_ID NUM
---------- ---------- ---------- ----------
24815 1 32084 0
24815 1 32084 1
24815 1 32084 2
24815 1 32084 3
SQL>
一些使用ROWID的函数
ROWIDTOCHAR(rowid) :将ROWID转换成STRING
CHARTOROWID('rowid_string') :将STRING转换成ROWID
下面的函数是eygle提供
create or replace function get_rowid
(l_rowid in varchar2)
return varchar2
is
ls_my_rowid varchar2(200);
rowid_type number;
object_number number;
relative_fno number;
block_number number;
row_number number;
begin
dbms_rowid.rowid_info(l_rowid,
rowid_type,
object_number,
relative_fno,
block_number,
row_number);
ls_my_rowid := 'Object# is :' || to_char(object_number) || chr(10) ||
'Relative_fno is :' || to_char(relative_fno) || chr(10) ||
'Block number is :' || to_char(block_number) || chr(10) ||
'Row number is :' || to_char(row_number);
return ls_my_rowid;
end;
应用上面的函数如下:
SQL> select get_rowid(rowid) from scott.dept;
GET_ROWID(ROWID)
--------------------------------------------------------------------------------
Object# is :24815
Relative_fno is :1
Block number is :32084
Row number is :0
Object# is :24815
Relative_fno is :1
Block number is :32084
Row number is :1
Object# is :24815
Relative_fno is :1
Block number is :32084
Row number is :2
Object# is :24815
Relative_fno is :1
Block number is :32084
Row number is :3
SQL>
来自 “ ITPUB博客 ” ,链接:http://blog.itpub.net/29987/viewspace-51697/,如需转载,请注明出处,否则将追究法律责任。