Skip to Main Content

SQL & PL/SQL

Announcement

For appeals, questions and feedback about Oracle Forums, please email oracle-forums-moderators_us@oracle.com. Technical questions should be asked in the appropriate category. Thank you!

Oracle sql split text into rows

aetlNov 25 2020 — edited Nov 25 2020

Hello Everyone ,
I have a clob column which has value like this :
{
adam smith
class:abcd
}
{
xxxyyyy
class:abcd
}
{
zzzz
class:abcd
}

class:abcd characters are common all between {}

İ want to split into rows after each class:abcd} :
row 1:{
adam smith
class:abcd
}
row2:{
adam smith
class:abcd
}

row3:{
adam smith
class:abcd
}

I tried to use connect by but i didnt do it exactly.

How can i split this text into rows ?

Regards,

This post has been answered by Paulzip on Nov 26 2020
Jump to Answer

Comments

Paulzip

This looks like a half house JSON document. Is this actual document JSON?

Paulzip

Here you go, something like this. I'm splitting on the braces, rather than the content.

with data(clb) as (
 select 
'{

adam smith

class:abcd

}

{

xxxyyyy

class:abcd

}

{

zzzz

class:abcd

}'
 from dual 
)
, sections(num, clb, start_, end_) as (
 select level, clb, instr(clb, '{', 1, level), instr(clb, '}', 1, level)
 from data
 connect by instr(clb, '}', 1, level) > 0
)
select num, substr(clb, start_, end_-start_+1) str
from sections
aetl

Hello Paulzip,

Your code is working correctly but i couldn't explain my problem.Yes it is an actual json .Here is a sample jscon code. i have a json file like this . When i tried to insert this it raised check constraint error . Becasue there are two "_id" values .İf i insert id by id not in same time it worked .İ want to split braches every "class_..."

{
"_id" : "1000099721",
"id" : [
{
"value" : "55555",
"schemeName" : "MSISDN",
"schemeAgencyName" : "xx"
},
{
"value" : "12416408",
"schemeName" : "CustomerId",
"schemeAgencyName" : "xx"
},
{
"value" : "441630",
"schemeName" : "OTP",
"schemeAgencyName" : "xx"
}
],
"_class" : "model.salesorder.SalesOrderVBO"
}
{
"_id" : "1000099721",
"id" : [
{
"value" : "6666",
"schemeName" : "MSISDN",
"schemeAgencyName" : "xx"
},
{
"value" : "12416408",
"schemeName" : "CustomerId",
"schemeAgencyName" : "xx"
},
{
"value" : "441630",
"schemeName" : "OTP",
"schemeAgencyName" : "xx"
},
{
"value" : "ffa357ee-9759-42ab-8a98-30ea9d410319",
"schemeName" : "ShoppingCartId",
"schemeAgencyName" : "xx"
},
{
"value" : "1000099721",
"schemeName" : "OrderId",
"schemeAgencyName" : "xx"
}
],
"_class" : "model.salesorder.SalesOrderVBO"
}

BluShadow

So, as it's actual JSON you're dealing with, have you considered using the Oracle built-in functionality for JSON data?
JSON Developer's Guide (0 Bytes)

Paulzip

Then why didn't you say it was JSON rather than post an example that wasn't? It just wastes people, like myself's time.

Which Oracle version?

aetl

Oracle 12.2

Paulzip
Answer

Again, your JSON isn't valid. It's an array and you don't have an array marker around it or a comma between the array items. You need to take more care in your posts.

with data(jsn) as (
 select 
 '[ 
  {
  "_id":"1000099721",
  "id":[
   {
     "value":"55555",
     "schemeName":"MSISDN",
     "schemeAgencyName":"xx"
   },
   {
     "value":"12416408",
     "schemeName":"CustomerId",
     "schemeAgencyName":"xx"
   },
   {
     "value":"441630",
     "schemeName":"OTP",
     "schemeAgencyName":"xx"
   }
  ],
  "_class":"model.salesorder.SalesOrderVBO"
}
,{
  "_id":"1000099721",
  "id":[
   {
     "value":"6666",
     "schemeName":"MSISDN",
     "schemeAgencyName":"xx"
   },
   {
     "value":"12416408",
     "schemeName":"CustomerId",
     "schemeAgencyName":"xx"
   },
   {
     "value":"441630",
     "schemeName":"OTP",
     "schemeAgencyName":"xx"
   },
   {
     "value":"ffa357ee-9759-42ab-8a98-30ea9d410319",
     "schemeName":"ShoppingCartId",
     "schemeAgencyName":"xx"
   },
   {
     "value":"1000099721",
     "schemeName":"OrderId",
     "schemeAgencyName":"xx"
   }
  ],
  "_class":"model.salesorder.SalesOrderVBO"
}
]'
from dual
)
select c.*
from data d, 
   json_table (
     d.jsn
   , '$[*]'
     columns (
       order_pos for ordinality
     , id varchar2(30) path '$."_id"'
     , nested path '$[*]'
       columns (
         content varchar2(4000 byte) format json path '$'
       ) 
     )
   ) c
/

ORDER_POS    ID               CONTENT
1            1000099721       {"_id":"1000099721","id":[{"value":"55555","schemeName":"MSISDN","schemeAgencyName":"xx"},{"value":"12416408","schemeName":"CustomerId","schemeAgencyName":"xx"},{"value":"441630","schemeName":"OTP","schemeAgencyName":"xx"}],"_class":"model.salesorder.SalesOrderVBO"}
2            1000099721       {"_id":"1000099721","id":[{"value":"6666","schemeName":"MSISDN","schemeAgencyName":"xx"},{"value":"12416408","schemeName":"CustomerId","schemeAgencyName":"xx"},{"value":"441630","schemeName":"OTP","schemeAgencyName":"xx"},{"value":"ffa357ee-9759-42ab-8a98-30ea9d410319","schemeName":"ShoppingCartId","schemeAgencyName":"xx"},{"value":"1000099721","schemeName":"OrderId","schemeAgencyName":"xx"}],"_class":"model.salesorder.SalesOrderVBO"} 


Marked as Answer by aetl · Nov 27 2020
1 - 7

Post Details

Added on Nov 25 2020
7 comments
442 views