I have an Oracle Table which has a CLOB column. The CLOB column has the following XML code stored –
<AddressDetails>
<SourceAddressID>41</SourceAddressID>
<SourceAddressLevel>BROKER</SourceAddressLevel>
<SourceAddressLevelID>41</SourceAddressLevelID>
<SourceAddressLevelType>BUSINESS</SourceAddressLevelType>
<AddressType>BUSINESS</AddressType>
<Address1>10 Tower Lane</Address1>
<City>MUM</City>
<State>MH</State>
<ZipCode>06001</ZipCode>
<Country>IN</Country>
<PrimaryAddressYN>Y</PrimaryAddressYN>
</AddressDetails>
<AddressDetails>
<SourceAddressID>11</SourceAddressID>
<SourceAddressLevel>INSURED</SourceAddressLevel>
<SourceAddressLevelID>11</SourceAddressLevelID>
<SourceAddressLevelType>BUSINESS</SourceAddressLevelType>
<AddressType>BUSINESS</AddressType>
<Address1>Remond Street</Address1>
<City>HYD</City>
<State>HY</State>
<ZipCode>05250</ZipCode>
<Country>IN</Country>
<PrimaryAddressYN>Y</PrimaryAddressYN>
</AddressDetails>
<AddressDetails>
<SourceAddressID>1</SourceAddressID>
<SourceAddressLevel>RISK</SourceAddressLevel>
<SourceAddressLevelID>1</SourceAddressLevelID>
<SourceAddressLevelType>LOCATION</SourceAddressLevelType>
<AddressType>BUILDING</AddressType>
<Address1>46 Main St</Address1>
<City>BENG</City>
<State>KT</State>
<ZipCode>05250</ZipCode>
<Country>IN</Country>
</AddressDetails>
I want to replace the line <SourceAddressLevelType>BUSINESS</SourceAddressLevelType>
with
<SourceAddressLevelType>INSURED</SourceAddressLevelType>
only for <SourceAddressLevel> = INSURED
.
For <SourceAddressLevel> = BROKER
, it should remain BUSINESS only <SourceAddressLevelType>BUSINESS</SourceAddressLevelType>
Sample data:
CREATE TABLE table_name (PolicyNo varchar2(10), xml_value CLOB);
INSERT INTO table_name (PolicyNo, xml_value)
SELECT 'P10001', EMPTY_CLOB() || '<AddressDetails>
<SourceAddressID>41</SourceAddressID>
<SourceAddressLevel>BROKER</SourceAddressLevel>
<SourceAddressLevelID>41</SourceAddressLevelID>
<SourceAddressLevelType>BUSINESS</SourceAddressLevelType>
<AddressType>BUSINESS</AddressType>
<Address1>10 Tower Lane</Address1>
<City>MUM</City>
<State>MH</State>
<ZipCode>06001</ZipCode>
<Country>IN</Country>
<PrimaryAddressYN>Y</PrimaryAddressYN>
</AddressDetails>' ||
'<AddressDetails>
<SourceAddressID>11</SourceAddressID>
<SourceAddressLevel>INSURED</SourceAddressLevel>
<SourceAddressLevelID>11</SourceAddressLevelID>
<SourceAddressLevelType>BUSINESS</SourceAddressLevelType>
<AddressType>BUSINESS</AddressType>
<Address1>Remond Street</Address1>
<City>HYD</City>
<State>HY</State>
<ZipCode>05250</ZipCode>
<Country>IN</Country>
<PrimaryAddressYN>Y</PrimaryAddressYN>
</AddressDetails>' ||
'<AddressDetails>
<SourceAddressID>1</SourceAddressID>
<SourceAddressLevel>RISK</SourceAddressLevel>
<SourceAddressLevelID>1</SourceAddressLevelID>
<SourceAddressLevelType>LOCATION</SourceAddressLevelType>
<AddressType>BUILDING</AddressType>
<Address1>46 Main St</Address1>
<City>BENG</City>
<State>KT</State>
<ZipCode>05250</ZipCode>
<Country>IN</Country>
</AddressDetails>' FROM DUAL;
INSERT INTO table_name (PolicyNo, xml_value)
SELECT 'P20002', EMPTY_CLOB() || '<AddressDetails>
<SourceAddressID>26</SourceAddressID>
<SourceAddressLevel>BROKER</SourceAddressLevel>
<SourceAddressLevelID>26</SourceAddressLevelID>
<SourceAddressLevelType>BUSINESS</SourceAddressLevelType>
<AddressType>BUSINESS</AddressType>
<Address1>JP Resort</Address1>
<City>KYN</City>
<State>MH</State>
<ZipCode>421301</ZipCode>
<Country>IN</Country>
<PrimaryAddressYN>Y</PrimaryAddressYN>
</AddressDetails>' ||
'<AddressDetails>
<SourceAddressID>90</SourceAddressID>
<SourceAddressLevel>INSURED</SourceAddressLevel>
<SourceAddressLevelID>90</SourceAddressLevelID>
<SourceAddressLevelType>BUSINESS</SourceAddressLevelType>
<AddressType>BUSINESS</AddressType>
<Address1>Solitair Park</Address1>
<City>PUN</City>
<State>PUN</State>
<ZipCode>665463</ZipCode>
<Country>IN</Country>
<PrimaryAddressYN>Y</PrimaryAddressYN>
</AddressDetails>' ||
'<AddressDetails>
<SourceAddressID>10</SourceAddressID>
<SourceAddressLevel>RISK</SourceAddressLevel>
<SourceAddressLevelID>10</SourceAddressLevelID>
<SourceAddressLevelType>LOCATION</SourceAddressLevelType>
<AddressType>BUILDING</AddressType>
<Address1>Andoman Street</Address1>
<City>AHM</City>
<State>GUJ</State>
<ZipCode>778753</ZipCode>
<Country>IN</Country>
</AddressDetails>' FROM DUAL;
After the change the CLOB column value should be:
<AddressDetails>
<SourceAddressID>41</SourceAddressID>
<SourceAddressLevel>BROKER</SourceAddressLevel>
<SourceAddressLevelID>41</SourceAddressLevelID>
<SourceAddressLevelType>BUSINESS</SourceAddressLevelType>
<AddressType>BUSINESS</AddressType>
<Address1>10 Tower Lane</Address1>
<City>MUM</City>
<State>MH</State>
<ZipCode>06001</ZipCode>
<Country>IN</Country>
<PrimaryAddressYN>Y</PrimaryAddressYN>
</AddressDetails>
<AddressDetails>
<SourceAddressID>11</SourceAddressID>
<SourceAddressLevel>INSURED</SourceAddressLevel>
<SourceAddressLevelID>11</SourceAddressLevelID>
<SourceAddressLevelType>INSURED</SourceAddressLevelType>
<AddressType>BUSINESS</AddressType>
<Address1>Remond Street</Address1>
<City>HYD</City>
<State>HY</State>
<ZipCode>05250</ZipCode>
<Country>IN</Country>
<PrimaryAddressYN>Y</PrimaryAddressYN>
</AddressDetails>
<AddressDetails>
<SourceAddressID>1</SourceAddressID>
<SourceAddressLevel>RISK</SourceAddressLevel>
<SourceAddressLevelID>1</SourceAddressLevelID>
<SourceAddressLevelType>LOCATION</SourceAddressLevelType>
<AddressType>BUILDING</AddressType>
<Address1>46 Main St</Address1>
<City>BENG</City>
<State>KT</State>
<ZipCode>05250</ZipCode>
<Country>IN</Country>
</AddressDetails>
and for second record
<AddressDetails>
<SourceAddressID>26</SourceAddressID>
<SourceAddressLevel>BROKER</SourceAddressLevel>
<SourceAddressLevelID>26</SourceAddressLevelID>
<SourceAddressLevelType>BUSINESS</SourceAddressLevelType>
<AddressType>BUSINESS</AddressType>
<Address1>JP Resort</Address1>
<City>KYN</City>
<State>MH</State>
<ZipCode>421301</ZipCode>
<Country>IN</Country>
<PrimaryAddressYN>Y</PrimaryAddressYN>
</AddressDetails>
<AddressDetails>
<SourceAddressID>90</SourceAddressID>
<SourceAddressLevel>INSURED</SourceAddressLevel>
<SourceAddressLevelID>90</SourceAddressLevelID>
<SourceAddressLevelType>INSURED</SourceAddressLevelType>
<AddressType>BUSINESS</AddressType>
<Address1>Solitair Park</Address1>
<City>PUN</City>
<State>PUN</State>
<ZipCode>665463</ZipCode>
<Country>IN</Country>
<PrimaryAddressYN>Y</PrimaryAddressYN>
</AddressDetails>
<AddressDetails>
<SourceAddressID>10</SourceAddressID>
<SourceAddressLevel>RISK</SourceAddressLevel>
<SourceAddressLevelID>10</SourceAddressLevelID>
<SourceAddressLevelType>LOCATION</SourceAddressLevelType>
<AddressType>BUILDING</AddressType>
<Address1>Andoman Street</Address1>
<City>AHM</City>
<State>GUJ</State>
<ZipCode>778753</ZipCode>
<Country>IN</Country>
</AddressDetails>
Is it possible to accomplish this?
2
You can use UPDATE
with an XMLQUERY
and FLWOR expression:
UPDATE table_name
SET xml_value = XMLSERIALIZE(
DOCUMENT
XMLQUERY(
'copy $i := $x modify (
for $j in $i/AddressDetails/SourceAddressLevelType
return replace value of node $j with $new_type
)
return $i'
PASSING XMLTYPE(xml_value) AS "x",
'INSURED' AS "new_type"
RETURNING CONTENT
)
AS CLOB
INDENT SIZE = 4
)
WHERE XMLEXISTS(
'$x/AddressDetails[SourceAddressLevel="INSURED"]'
PASSING XMLTYPE(xml_value) AS "x"
);
Which, for the sample data:
CREATE TABLE table_name (xml_value CLOB);
INSERT INTO table_name (xml_value)
SELECT EMPTY_CLOB() || '<AddressDetails>
<SourceAddressID>41</SourceAddressID>
<SourceAddressLevel>BROKER</SourceAddressLevel>
<SourceAddressLevelID>41</SourceAddressLevelID>
<SourceAddressLevelType>BUSINESS</SourceAddressLevelType>
<AddressType>BUSINESS</AddressType>
<Address1>10 Tower Lane</Address1>
<City>MUM</City>
<State>MH</State>
<ZipCode>06001</ZipCode>
<Country>IN</Country>
<PrimaryAddressYN>Y</PrimaryAddressYN>
</AddressDetails>' FROM DUAL UNION ALL
SELECT EMPTY_CLOB() || '<AddressDetails>
<SourceAddressID>11</SourceAddressID>
<SourceAddressLevel>INSURED</SourceAddressLevel>
<SourceAddressLevelID>11</SourceAddressLevelID>
<SourceAddressLevelType>BUSINESS</SourceAddressLevelType>
<AddressType>BUSINESS</AddressType>
<Address1>Remond Street</Address1>
<City>HYD</City>
<State>HY</State>
<ZipCode>05250</ZipCode>
<Country>IN</Country>
<PrimaryAddressYN>Y</PrimaryAddressYN>
</AddressDetails>' FROM DUAL UNION ALL
SELECT EMPTY_CLOB() || '<AddressDetails>
<SourceAddressID>1</SourceAddressID>
<SourceAddressLevel>RISK</SourceAddressLevel>
<SourceAddressLevelID>1</SourceAddressLevelID>
<SourceAddressLevelType>LOCATION</SourceAddressLevelType>
<AddressType>BUILDING</AddressType>
<Address1>46 Main St</Address1>
<City>BENG</City>
<State>KT</State>
<ZipCode>05250</ZipCode>
<Country>IN</Country>
</AddressDetails>' FROM DUAL;
Then, after the UPDATE
the table contains:
XML_VALUE |
---|
<AddressDetails> <SourceAddressID>41</SourceAddressID> <SourceAddressLevel>BROKER</SourceAddressLevel> <SourceAddressLevelID>41</SourceAddressLevelID> <SourceAddressLevelType>BUSINESS</SourceAddressLevelType> <AddressType>BUSINESS</AddressType> <Address1>10 Tower Lane</Address1> <City>MUM</City> <State>MH</State> <ZipCode>06001</ZipCode> <Country>IN</Country> <PrimaryAddressYN>Y</PrimaryAddressYN> </AddressDetails> |
<AddressDetails> <SourceAddressID>11</SourceAddressID> <SourceAddressLevel>INSURED</SourceAddressLevel> <SourceAddressLevelID>11</SourceAddressLevelID> <SourceAddressLevelType>INSURED</SourceAddressLevelType> <AddressType>BUSINESS</AddressType> <Address1>Remond Street</Address1> <City>HYD</City> <State>HY</State> <ZipCode>05250</ZipCode> <Country>IN</Country> <PrimaryAddressYN>Y</PrimaryAddressYN> </AddressDetails> |
<AddressDetails> <SourceAddressID>1</SourceAddressID> <SourceAddressLevel>RISK</SourceAddressLevel> <SourceAddressLevelID>1</SourceAddressLevelID> <SourceAddressLevelType>LOCATION</SourceAddressLevelType> <AddressType>BUILDING</AddressType> <Address1>46 Main St</Address1> <City>BENG</City> <State>KT</State> <ZipCode>05250</ZipCode> <Country>IN</Country> </AddressDetails> |
fiddle
4