Comments on: Oracle Data Cartridge – Extending the Database https://technology.amis.nl/2004/07/06/oracle-data-cartridge-extending-the-database/ Friends of Oracle and Java Mon, 27 Apr 2015 11:47:05 +0000 hourly 1 http://wordpress.org/?v=4.2.1 By: AMIS Technology blog » Blog Archive » Quick Query to report on Entities and Attributes in Oracle Designer https://technology.amis.nl/2004/07/06/oracle-data-cartridge-extending-the-database/#comment-214 Fri, 17 Feb 2006 07:38:29 +0000 /?p=34#comment-214 […]  Furthermore, it is not ideal we need this rather specialized function in the first place. We could use a user defined aggregation function – see our blog article Oracle Data Cartridge – Extending the Database. In an Oracle 10g database, we should be able to leverage the COLLECT aggregator (see for example Oracle-Base on String Aggregation techniques). The COLLECT can be used to aggregate multiple records into a single Collection type. For example to aggregate Strings we would use an Oracle Type, defined like this:CREATE OR REPLACE TYPE STRING_TABLE AS TABLE OF VARCHAR2(4000)/ We can the rewrite the query, using COLLECT and this new type definition: The output is not yet ideally formatted: the Entity Description is returned as a STRING_TABLE. We would now like to turn the STRING_TABLE into a concattenated string. For this, we need another PL/SQL Function. So what have we gained you might ask? Well, it is totally different function: a very generic one that does not do any database access and can be reused in many situations. This function looks like: And the over all query is now: […]

]]>
By: Lucas Jellema https://technology.amis.nl/2004/07/06/oracle-data-cartridge-extending-the-database/#comment-213 Tue, 06 Jul 2004 12:47:22 +0000 /?p=34#comment-213 To get rid of the user defined aggregate function:
1) drop type
2) drop function

for example:

drop type AmisDateAvgImpl;
drop function AmisDateAvg;

]]>
By: Lucas Jellema https://technology.amis.nl/2004/07/06/oracle-data-cartridge-extending-the-database/#comment-212 Tue, 06 Jul 2004 12:45:45 +0000 /?p=34#comment-212 Another example of using the Oracle Data Cartridge:

Select the sum of a VARCHAR2 column, resulting in a comma-separated list of the individual values in this column.


select Amisvarchar2Sum(ename) from emp

AMISVARCHAR2SUM(ENAME)
--------------------------------------------------------------------------------
SMITH,ALLEN,WARD,JONES,MARTIN,BLAKE,CLARkson,SCOTT,KING,TURNER,ADAMS,JAMES,FORD,
MILLER,you


select d.dname
, count(d.dname)
, Amisvarchar2Sum(e.ename)
from dept d , emp e
where e.deptno = d.deptno
group by d.dname

DNAME COUNT(D.DNAME)
-------------- --------------
AMISVARCHAR2SUM(E.ENAME)
--------------------------------------------------
ACCOUNTING 2
CLARkson,MILLER

RESEARCH 5
SMITH,ADAMS,JONES,FORD,SCOTT

SALES 6
ALLEN,TURNER,BLAKE,WARD,MARTIN,JAMES

This aggregate was implemented as follows:

create type AmisVarchar2SumImpl as object
(
sumvarchar2s varchar2(32000),
static function ODCIAggregateInitialize(sctx IN OUT AmisVarchar2SumImpl)
return number,
member function ODCIAggregateIterate(self IN OUT AmisVarchar2SumImpl,
value IN varchar2) return number,
member function ODCIAggregateTerminate(self IN AmisVarchar2SumImpl,
returnValue OUT varchar2, flags IN number) return number,
member function ODCIAggregateMerge(self IN OUT AmisVarchar2SumImpl,
ctx2 IN AmisVarchar2SumImpl) return number
);

create or replace type body AmisVarchar2SumImpl is
static function ODCIAggregateInitialize(sctx IN OUT AmisVarchar2SumImpl)
return number is
begin
sctx := AmisVarchar2SumImpl(”);
return ODCIConst.Success;
end;

member function ODCIAggregateIterate(self IN OUT AmisVarchar2SumImpl, value IN varchar2) return number is
begin

self.sumvarchar2s := self.sumvarchar2s||’,’||value;
return ODCIConst.Success;
end;

member function ODCIAggregateTerminate(self IN AmisVarchar2SumImpl, returnValue OUT varchar2, flags IN number) return number is
begin
returnValue := substr(self.sumvarchar2s,2);
return ODCIConst.Success;
end;

member function ODCIAggregateMerge(self IN OUT AmisVarchar2SumImpl, ctx2 IN AmisVarchar2SumImpl) return number is
begin
self.sumvarchar2s := self.sumvarchar2s||ctx2.sumvarchar2s;
return ODCIConst.Success;
end;
end;
/

CREATE or replace FUNCTION Amisvarchar2SUm (input varchar2) RETURN varchar2
PARALLEL_ENABLE AGGREGATE USING AmisVarchar2SumImpl;
/

]]>