一:过程代码
Create Or Replace Procedure Format_Sql(i_Sql In Varchar2) Is
i_Cursor Integer Default Dbms_Sql.Open_Cursor();
Desc_Cols Dbms_Sql.Desc_Tab;
i_Status Integer; --执行状态
n_Colcnt Number; --列数
i_Col_Width Integer := 3; --列间距,如果觉得太小可以调大一些
n_Rowcnt Number := 0; --记录结果行数
Vc_Columnname Varchar2(4000); --列头名字
Vc_Col_Split Varchar2(4000) := '---'; --记录和列头之间的分割线
Vc_Columnvalue Varchar2(4000); --列值
Type Typ_Collength Is Table Of Number Index By Binary_Integer;
Tab_Typ_Collength Typ_Collength; --存放每一列值的最大长度
l_Results Long; --输出结果
Begin
--第一次循环获取每列值的最大长度
i_Cursor := Dbms_Sql.Open_Cursor; --打开游标;
Dbms_Sql.Parse(i_Cursor, i_Sql, Dbms_Sql.Native);
Dbms_Sql.Describe_Columns(i_Cursor, n_Colcnt, Desc_Cols);
For i In 1 .. n_Colcnt Loop
Dbms_Sql.Define_Column(i_Cursor, i, Vc_Columnvalue, 4000);
Tab_Typ_Collength(i) := Length(Desc_Cols(i).Col_Name);
End Loop;
i_Status := Dbms_Sql.Execute(i_Cursor);
Loop
Exit When Dbms_Sql.Fetch_Rows(i_Cursor) < 1;
For i In 1 .. n_Colcnt Loop
Dbms_Sql.Column_Value(i_Cursor, i, Vc_Columnvalue);
If Length(Vc_Columnvalue) > Tab_Typ_Collength(i) Then
Tab_Typ_Collength(i) := Length(Vc_Columnvalue);
End If;
End Loop;
End Loop;
Dbms_Sql.Close_Cursor(i_Cursor);
--第二次循环拼接输出结果
i_Cursor := Dbms_Sql.Open_Cursor; --打开游标;
Dbms_Sql.Parse(i_Cursor, i_Sql, Dbms_Sql.Native);
Dbms_Sql.Describe_Columns(i_Cursor, n_Colcnt, Desc_Cols);
For i In 1 .. n_Colcnt Loop
Dbms_Sql.Define_Column(i_Cursor, i, Vc_Columnvalue, 4000);
End Loop;
i_Status := Dbms_Sql.Execute(i_Cursor);
Loop
Exit When Dbms_Sql.Fetch_Rows(i_Cursor) < 1;
n_Rowcnt := n_Rowcnt + 1;
l_Results := l_Results || Rpad(n_Rowcnt, i_Col_Width + 3);
For i In 1 .. n_Colcnt Loop
Dbms_Sql.Column_Value(i_Cursor, i, Vc_Columnvalue);
l_Results := l_Results ||
Rpad(Vc_Columnvalue || ' ',
Tab_Typ_Collength(i) + i_Col_Width);
End Loop;
l_Results := l_Results || Chr(10);
End Loop;
--定义列头
Vc_Columnname := Rpad('NO', i_Col_Width + 3, ' ');
For i In 1 .. n_Colcnt Loop
Vc_Columnname := Vc_Columnname ||
Rpad(Desc_Cols(i).Col_Name,
Tab_Typ_Collength(i) + i_Col_Width,
' ');
Vc_Col_Split := Rpad(Vc_Col_Split,
Length(Vc_Col_Split) + i_Col_Width,
' ');
Vc_Col_Split := Rpad(Vc_Col_Split,
Length(Vc_Col_Split) + Tab_Typ_Collength(i),
'-');
End Loop;
Dbms_Sql.Close_Cursor(i_Cursor);
-- Vc_Columnname := Vc_Columnname || Chr(10);
--输出结果
Dbms_Output.Put_Line('Total Row: ' || n_Rowcnt);
Dbms_Output.Put_Line(Vc_Columnname);
Dbms_Output.Put_Line(Vc_Col_Split);
Dbms_Output.Put_Line(l_Results);
Exception
When Others Then
Dbms_Sql.Close_Cursor(i_Cursor);
Raise;
End;
二:测试结果
TS@PROD> set serveroutput on size 999999
TS@PROD> select sql_text,sql_id,child_number,hash_value from v$sql Where sql_text Like'select * from emp%';
SQL_TEXT
---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SQL_ID CHILD_NUMBER HASH_VALUE
------------- ------------ ----------
select * from emp
a2dk8bdn0ujx7 0 1745700775
select * from emp
a2dk8bdn0ujx7 1 1745700775
select * from emp e,dept d where e.deptno = d.deptno
4cs33ya9vumkh 0 2478657104
TS@PROD> exec Format_Sql('select sql_text,sql_id,child_number,hash_value from v$sql Where sql_text Like''select * from emp%''');
Total Row: 3
NO SQL_TEXT SQL_ID CHILD_NUMBER HASH_VALUE
--- ---------------------------------------------------- ------------- ------------ ----------
1 select * from emp a2dk8bdn0ujx7 0 1745700775
2 select * from emp a2dk8bdn0ujx7 1 1745700775
3 select * from emp e,dept d where e.deptno = d.deptno 4cs33ya9vumkh 0 2478657104
PL/SQL procedure successfully completed.
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




