玄铁剑

成功的途径:抄,创造,研究,发明...
posts - 128, comments - 42, trackbacks - 0, articles - 174

导航

<2007年9月>
2627282930311
2345678
9101112131415
16171819202122
23242526272829
30123456

常用链接

留言簿(5)

随笔分类

随笔档案

文章分类

收藏夹

AJAX

asp.net網絡鏈接

Delphi Link

IronPython

Microsoft

Other Blogs

OtherSite

SliverLight

Test

免费asp.net控件

其它链接

搜索

  •  

积分与排名

  • 积分 - 217462
  • 排名 - 26

最新评论

阅读排行榜

评论排行榜

Row to Column Function

Posted on 2007-09-01 17:08 玄铁剑 阅读(465) 评论(0)  编辑 收藏 引用 所属分类: oracle
The objective of this function is to transpose rows to columns.

 

This RowToCol function is built with invoker-rights AUTHID CURRENT_USER. The function works on tables/views of the user who invokes the function, not on the owner of this function.

RowToCol takes two parameters:

1. SQL Statement: You can pass any valid SQL statement to this function.
2. Delimiter: You can pass any character as a delimiter. Default value is `,?

Examples on how to use RowToCol Function:

Example 1: Where rows to be converted to a column string come from different table.


SELECT a.deptno, a.dname, a.loc,
rowtocol('SELECT DISTINCT job FROM emp WHERE deptno = ' ||a.deptno) as jobs
FROM dept a;

 

Example 2: Where the content in the WHERE clause is characters, put it in Sting format.

Notice, the main query and the passing query source is same table (EMP). So, use DISTINCT clause in the main query.


SELECT DISTINCT a.job
,rowtocol('SELECT ename FROM emp WHERE job = ' || '''' || a.job || '''' || ' ORDER BY ename')
AS Employees
FROM emp a;

 

Code Listing:


CREATE OR REPLACE
FUNCTION rowtocol( p_slct IN VARCHAR2,
p_dlmtr IN VARCHAR2 DEFAULT ',' ) RETURN VARCHAR2
AUTHID CURRENT_USER AS
/*

 

1) Column should be character type.
2) If it is non-character type, column has to be converted into character type.
3) If the returned rows should in a specified order, put that ORDER BY CLASS in the SELECT statement argument.
4) If the SQL statement happened to return duplicate values, and if you don't want that to happen, put DISTINCT in the SELECT statement argument.


TYPE c_refcur IS REF CURSOR;
lc_str VARCHAR2(4000);
lc_colval VARCHAR2(4000);
c_dummy c_refcur;
l number;
BEGIN
OPEN c_dummy FOR p_slct;
LOOP
FETCH c_dummy INTO lc_colval;
EXIT WHEN c_dummy%NOTFOUND;
lc_str := lc_str || p_dlmtr || lc_colval;
END LOOP;
CLOSE c_dummy;
RETURN SUBSTR(lc_str,2);
/*
EXCEPTION
WHEN OTHERS THEN
lc_str := SQLERRM;
IF c_dummy%ISOPEN THEN
CLOSE c_dummy;
END IF;
RETURN lc_str;
*/
END;
/
只有注册用户登录后才能发表评论。