versions 11.2.0.2.0 / 10.2.0.4.0
It's a
long time, no see since my last dealing with xml and no luck to have an attribute value returned into the relational table.
It's *<IntrBkSttlmAmt Ccy="???">999999</IntrBkSttlmAmt>*
For the rest the below works in both versions but used on an xml having a 10000 <CdtTrfTxInf> on 11g it took 9 seconds and was killed because no answer was produced after 30 minutes on 10g. A colleague using java loaded the relational table in 34 seconds on 10g and produced the relational table on 11g in just 5 seconds.
The 10g version is surviving with no xmldb installed and there are rumors our thinking heads didn't succeed to deactivate it on 11g yet.
Any suggestion concerning alternate ways to produce a relational table from an xmltype located in a clob column of a relational table are welcome
(looking at
2279478 I thought too many xmltable would have to be used)
with
the_data as
(select q'~
<Document xmlns="urn:iso:std:iso:20022:tech:xsd:pacs.008.001.01">
<pacs.008.001.01>
<GrpHdr>
<MsgId>1L1U000JB4UT1FVS</MsgId>
<MsgId>9X9X999XX9XX9XXX</MsgId>
<CreDtTm>YYYY-MM-DDTHH:MI:SS</CreDtTm>
<NbOfTxs>99999</NbOfTxs>
<TtlIntrBkSttlmAmt Ccy="???">9999999</TtlIntrBkSttlmAmt>
<IntrBkSttlmDt>YYYY-MM-DD</IntrBkSttlmDt>
<SttlmInf>
<SttlmMtd>XXXX</SttlmMtd>
<ClrSys>
<ClrSysId>XXXX</ClrSysId>
</ClrSys>
</SttlmInf>
</GrpHdr>
<CdtTrfTxInf>
<PmtId>
<InstrId>XXXXXXX999999-XX999999.XX</InstrId>
<EndToEndId>X9999999999</EndToEndId>
<TxId>X9999-9999999999</TxId>
</PmtId>
<PmtTpInf>
<SvcLvl>
<Cd>XXXX</Cd>
</SvcLvl>
</PmtTpInf>
<IntrBkSttlmAmt Ccy="???">999999</IntrBkSttlmAmt>
<ChrgBr>XXXX</ChrgBr>
<InstgAgt>
<FinInstnId>
<BIC>XXXXXX9X</BIC>
</FinInstnId>
</InstgAgt>
<Dbtr>
<Nm>NAME</Nm>
<PstlAdr>
<AdrLine>ADDRESS</AdrLine>
<AdrLine>CITY</AdrLine>
<Ctry>XX</Ctry>
</PstlAdr>
</Dbtr>
<DbtrAcct>
<Id>
<IBAN>XX99999999999999999</IBAN>
</Id>
</DbtrAcct>
<DbtrAgt>
<FinInstnId>
<BIC>XXXXXX9X</BIC>
</FinInstnId>
</DbtrAgt>
<CdtrAgt>
<FinInstnId>
<BIC>XXXXXX9X</BIC>
</FinInstnId>
</CdtrAgt>
<Cdtr>
<Nm>NAME</Nm>
<PstlAdr>
<AdrLine>ADDRESS</AdrLine>
<AdrLine>CITY</AdrLine>
<Ctry>XX</Ctry>
</PstlAdr>
</Cdtr>
<CdtrAcct>
<Id>
<IBAN>XX99999999999999999</IBAN>
</Id>
</CdtrAcct>
<RmtInf>
<Strd>
<CdtrRefInf>
<CdtrRef>X99999999-9999999999</CdtrRef>
</CdtrRefInf>
<AddtlRmtInf>ADDITIONAL INFO</AddtlRmtInf>
</Strd>
</RmtInf>
</CdtTrfTxInf>
</pacs.008.001.01>
</Document>
~' the_column
from dual
)
select v.instrid,v.endtoendid,v.txid,v.cd,
v.ccy, /* returned as NULL - the only attribute value */
v.intrbksttlmamt,v.chrgbr,v.bic1,v.nm1,v.adrline11,v.adrline12,v.ctry1,v.iban1,
v.bic2,v.bic3,v.nm2,v.adrline21,v.adrline22,v.ctry2,v.iban2,v.cdtrref,v.addtlrmtinf
from (select xmltype(the_column) the_column_xml
from the_data
) w,
xmltable(xmlnamespaces(default 'urn:iso:std:iso:20022:tech:xsd:pacs.008.001.01'),
'for $r in /Document/pacs.008.001.01/CdtTrfTxInf
return <rw>
<InstrId>{$r/PmtId/InstrId}</InstrId>
<EndToEndId>{$r/PmtId/EndToEndId}</EndToEndId>
<TxId>{$r/PmtId/TxId}</TxId>
<Cd>{$r/PmtTpInf/SvcLvl/Cd}</Cd>
<Ccy>{$r/IntrBkSttlmAmt/@Ccy}</Ccy>
<IntrBkSttlmAmt>{ora:replace($r/IntrBkSttlmAmt,"[.]",",")}</IntrBkSttlmAmt>
<ChrgBr>{$r/ChrgBr}</ChrgBr>
<BIC1>{$r/InstgAgt/FinInstnId}</BIC1>
<Nm1>{$r/Dbtr/Nm}</Nm1>
<AdrLine11>{$r/Dbtr/PstlAdr/AdrLine[1]}</AdrLine11>
<AdrLine12>{$r/Dbtr/PstlAdr/AdrLine[2]}</AdrLine12>
<Ctry1>{$r/Dbtr/PstlAdr/Ctry}</Ctry1>
<IBAN1>{$r/DbtrAcct/Id}</IBAN1>
<BIC2>{$r/DbtrAgt/FinInstnId}</BIC2>
<BIC3>{$r/CdtrAgt/FinInstnId}</BIC3>
<Nm2>{$r/Cdtr/Nm}</Nm2>
<AdrLine21>{$r/Cdtr/PstlAdr/AdrLine[1]}</AdrLine21>
<AdrLine22>{$r/Cdtr/PstlAdr/AdrLine[2]}</AdrLine22>
<Ctry2>{$r/Cdtr/PstlAdr/Ctry}</Ctry2>
<IBAN2>{$r/CdtrAcct/Id}</IBAN2>
<CdtrRef>{$r/RmtInf/Strd/CdtrRefInf/CdtrRef}</CdtrRef>
<AddtlRmtInf>{$r/RmtInf/Strd/AddtlRmtInf}</AddtlRmtInf>
</rw>'
passing w.the_column_xml
columns instrid varchar2(300) path '/rw/InstrId',
endtoendid varchar2(150) path '/rw/EndToEndId',
txid varchar2(200) path '/rw/TxId',
cd varchar2(50) path '/rw/Cd',
ccy varchar2(50) path '/rw/Ccy',
intrbksttlmamt varchar2(50) path '/rw/IntrBkSttlmAmt',
chrgbr varchar2(100) path '/rw/ChrgBr',
bic1 varchar2(100) path '/rw/BIC1',
nm1 varchar2(1000) path '/rw/Nm1',
adrline11 varchar2(1000) path '/rw/AdrLine11',
adrline12 varchar2(1000) path '/rw/AdrLine12',
ctry1 varchar2(50) path '/rw/Ctry1',
iban1 varchar2(200) path '/rw/IBAN1',
bic2 varchar2(100) path '/rw/BIC2',
bic3 varchar2(100) path '/rw/BIC3',
nm2 varchar2(1000) path '/rw/Nm2',
adrline21 varchar2(1000) path '/rw/AdrLine21',
adrline22 varchar2(1000) path '/rw/AdrLine22',
ctry2 varchar2(50) path '/rw/Ctry2',
iban2 varchar2(200) path '/rw/IBAN2',
cdtrref varchar2(1000) path '/rw/CdtrRef',
addtlrmtinf varchar2(1000) path '/rw/AddtlRmtInf'
) v
Regards
Etbin