-
Notifications
You must be signed in to change notification settings - Fork 4
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
1 parent
bd871e8
commit 88f6567
Showing
11 changed files
with
824 additions
and
0 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,77 @@ | ||
|
||
create or replace function F_BLOB_TO_LIST ( I_BLOB in blob | ||
) return T_STRING_LIST PIPELINED is | ||
/******************************************************************************************************************** | ||
The F_BLOB_TO_LIST creates list of lines from the BLOB input parameter. | ||
It can manage LF or CR+LF line delimiters. | ||
Sample: | ||
------- | ||
select * from table( F_BLOB_TO_LIST ( clob_to_blob( 'hello'||chr(13)||chr(10)||'bello' ) ) ) | ||
Result: | ||
------- | ||
hello | ||
bello | ||
History of changes | ||
yyyy.mm.dd | Version | Author | Changes | ||
-----------+---------+----------------+------------------------- | ||
2017.01.16 | 1.0 | Ferenc Toth | Created | ||
********************************************************************************************************************/ | ||
|
||
V_LINE varchar2( 32000 ); | ||
V_OFFSET number := 1; | ||
V_AMOUNT number := 4000; | ||
V_LENGTH number; | ||
V_BUFFER varchar2( 32000 ); | ||
V_STRING_LIST T_STRING_LIST := T_STRING_LIST(); | ||
|
||
begin | ||
-- check | ||
V_LENGTH := dbms_lob.getlength( I_BLOB ); | ||
|
||
if V_LENGTH > 0 then | ||
|
||
while V_OFFSET < V_LENGTH loop | ||
|
||
-- get the next part of blob | ||
V_BUFFER := utl_raw.cast_to_varchar2( dbms_lob.substr( I_BLOB, V_AMOUNT, V_OFFSET ) ); | ||
V_BUFFER := replace( V_BUFFER, chr( 13 ), null ); | ||
|
||
-- crate a list from it | ||
V_STRING_LIST.delete; | ||
for L_R in ( select * from table( F_CSV_TO_LIST( V_BUFFER, chr( 10 ), null ) ) ) | ||
loop | ||
V_STRING_LIST.extend; | ||
V_STRING_LIST( V_STRING_LIST.count ) := L_R.COLUMN_VALUE; | ||
end loop; | ||
|
||
-- go through the list elements | ||
for L_I in 1..V_STRING_LIST.count | ||
loop | ||
V_LINE := V_LINE || V_STRING_LIST( L_I ); | ||
if L_I < V_STRING_LIST.count then -- the last row should be truncated | ||
PIPE ROW( V_LINE ); | ||
V_LINE := ''; | ||
end if; | ||
end loop; | ||
|
||
V_OFFSET := V_OFFSET + V_AMOUNT; | ||
|
||
end loop; | ||
|
||
-- put out the last one as well | ||
if V_LINE is not null then | ||
PIPE ROW( V_LINE ); | ||
end if; | ||
|
||
end if; | ||
|
||
return; | ||
|
||
end; | ||
/ |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,71 @@ | ||
|
||
create or replace function F_CSV_FILE_TO_TABLE ( I_DIRECTORY in varchar2 | ||
, I_FILE_NAME in varchar2 | ||
, I_SEPARATOR in varchar2 := ',' | ||
, I_ENCLOSED_BY in varchar2 := null | ||
) return T_STRING_LIST_TAB PIPELINED is | ||
/******************************************************************************************************************** | ||
The F_CSV_FILE_TO_TABLE creates CSV (string list) table from the file, specified by the parameters. | ||
The SEPARATOR and the ENCLOSED belong to the CSV strings and not to the lines. The lines could end with CR+LF or only LF (optionally). | ||
The DIRECTORY is an Oracle and not OS directory! | ||
Samples: | ||
------- | ||
select * from table( F_CSV_FILE_TO_TABLE ( 'FILEIO', 'WEATHER_DATA_1000_20160512_151722.csv', ';', null ) ) | ||
Results: | ||
------- | ||
T_STRING_LIST('WEATHER_DATA','1','2016.05.12','15:17:28','ERDF') | ||
T_STRING_LIST('2010.12.31','90900','H1','7,70') | ||
T_STRING_LIST('2011.01.01','90900','NH3','10,20') | ||
T_STRING_LIST('2011.11.01','13711','H1','4,90') | ||
T_STRING_LIST('2011.11.01','15310','NH3','4,10') | ||
.... | ||
History of changes | ||
yyyy.mm.dd | Version | Author | Changes | ||
-----------+---------+----------------+------------------------- | ||
2017.01.16 | 1.0 | Ferenc Toth | Created | ||
********************************************************************************************************************/ | ||
|
||
V_FILE bfile; | ||
V_BLOB blob; | ||
V_STRING_LIST T_STRING_LIST := T_STRING_LIST(); | ||
|
||
begin | ||
|
||
V_FILE := bfilename( I_DIRECTORY, I_FILE_NAME ); | ||
dbms_lob.open( V_FILE, dbms_lob.lob_readonly ); | ||
|
||
dbms_lob.createtemporary( V_BLOB, true ); | ||
dbms_lob.open( V_BLOB, dbms_lob.lob_readwrite ); | ||
dbms_lob.loadfromfile( dest_lob => V_BLOB, src_lob => V_FILE, amount => dbms_lob.getlength( V_FILE ) ); | ||
dbms_lob.close( V_BLOB ); | ||
dbms_lob.fileclose( V_FILE ); | ||
|
||
for L_R in ( select * from table( F_BLOB_TO_LIST ( V_BLOB ) ) ) | ||
loop | ||
V_STRING_LIST.extend; | ||
V_STRING_LIST( V_STRING_LIST.count ) := L_R.COLUMN_VALUE; | ||
end loop; | ||
|
||
for L_R in ( select * from table( F_CSV_LIST_TO_TABLE ( V_STRING_LIST, nvl(I_SEPARATOR,','), I_ENCLOSED_BY ) ) ) | ||
loop | ||
PIPE ROW( L_R.COLUMN_VALUE ); | ||
end loop; | ||
|
||
return; | ||
|
||
exception when others then | ||
|
||
if dbms_lob.fileisopen( V_FILE ) = 1 then | ||
dbms_lob.fileclose( V_FILE ); | ||
end if; | ||
|
||
raise; | ||
|
||
end; | ||
/ |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,60 @@ | ||
|
||
create or replace function F_CSV_LIST_TO_TABLE ( I_CSV_LIST in T_STRING_LIST | ||
, I_SEPARATOR in varchar2 := ',' | ||
, I_ENCLOSED_BY in varchar2 := null | ||
) return T_STRING_LIST_TAB PIPELINED is | ||
/******************************************************************************************************************** | ||
The F_CSV_LIST_TO_TABLE just creates a separator/delimiter separated string from the input | ||
optionally enclosed by encloser. | ||
Parameters: | ||
----------- | ||
I_TABLE the tabke of string lists to transform to list of CSV string | ||
I_SEPARATOR the field separator/delimiter | ||
I_ENCLOSED_BY the optional encloser (both left and right) | ||
Samples: | ||
------- | ||
F_CSV_LIST_TO_TABLE ( T_STRING_LIST ( 'A,B,C', '1,2,"3,1415"' ), ',' ,'"' ) | ||
Results: | ||
------- | ||
T_STRING_LIST('A','B','C') | ||
T_STRING_LIST('1','2','3,1415') | ||
History of changes | ||
yyyy.mm.dd | Version | Author | Changes | ||
-----------+---------+----------------+------------------------- | ||
2017.01.06 | 1.0 | Ferenc Toth | Created | ||
********************************************************************************************************************/ | ||
|
||
V_CSV_LIST T_STRING_LIST := T_STRING_LIST(); | ||
|
||
begin | ||
|
||
for L_I in 1..I_CSV_LIST.count | ||
loop | ||
|
||
V_CSV_LIST.delete; | ||
for L_R in ( select * from table( F_CSV_TO_LIST ( I_CSV_STRING => I_CSV_LIST( L_I ) | ||
, I_SEPARATOR => I_SEPARATOR | ||
, I_ENCLOSED_BY => I_ENCLOSED_BY | ||
) | ||
) | ||
) | ||
loop | ||
V_CSV_LIST.extend; | ||
V_CSV_LIST( V_CSV_LIST.count ) := L_R.COLUMN_VALUE; | ||
end loop; | ||
PIPE ROW( V_CSV_LIST ); | ||
|
||
end loop; | ||
|
||
return; | ||
|
||
end; | ||
/ | ||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,123 @@ | ||
|
||
create or replace function F_CSV_TO_LIST ( I_CSV_STRING in varchar2 | ||
, I_SEPARATOR in varchar2 := ',' | ||
, I_ENCLOSED_BY in varchar2 := null | ||
) return T_STRING_LIST PIPELINED is | ||
/******************************************************************************************************************** | ||
The F_CSV_TO_LIST is a "smart" string list separated by strings, optionally enclosed by string parser. | ||
if the separator/delimiter is between enclosers, then the separator will be the part of the field. | ||
if the encloser is not closed or not started then the encloser will be the part of the field. | ||
Parameters: | ||
----------- | ||
I_CSV_STRING the ( delimited and optionally enclosed ) string to parse | ||
I_SEPARATOR the field separator/delimiter | ||
I_ENCLOSED_BY the optional encloser (both left and right) | ||
Samples: | ||
------- | ||
select * from table( F_CSV_TO_LIST ( '1,2,3,1415', ',' ) ) | ||
select * from table( F_CSV_TO_LIST ( '"1,2","3,1415"', ',' ) ) | ||
select * from table( F_CSV_TO_LIST ( '"1,2","3,1415"', ',', '"' ) ) | ||
Results: | ||
------- | ||
1 | ||
2 | ||
3 | ||
1415 | ||
"1 | ||
2" | ||
"3 | ||
1415" | ||
1,2 | ||
3,1415 | ||
History of changes | ||
yyyy.mm.dd | Version | Author | Changes | ||
-----------+---------+----------------+------------------------- | ||
2017.01.06 | 1.0 | Ferenc Toth | Created | ||
********************************************************************************************************************/ | ||
|
||
V_INSIDE boolean := false; | ||
V_CSV varchar2( 32000 ) := I_CSV_STRING; | ||
V_FIELD varchar2( 32000 ); | ||
V_SEPARATOR varchar2( 300 ) := nvl( I_SEPARATOR, ',' ); | ||
|
||
begin | ||
|
||
loop | ||
|
||
if V_CSV is null then | ||
PIPE ROW( V_FIELD ); | ||
exit; | ||
end if; | ||
|
||
if not V_INSIDE then | ||
|
||
-- did we reach a separator outside? | ||
if substr( V_CSV , 1 , length( V_SEPARATOR ) ) = V_SEPARATOR then | ||
V_CSV := substr( V_CSV, length( V_SEPARATOR ) + 1 ); | ||
PIPE ROW( V_FIELD ); | ||
V_FIELD := ''; | ||
|
||
-- a new field starts with "enclosed by" | ||
elsif substr( V_CSV, 1 , length( I_ENCLOSED_BY ) ) = I_ENCLOSED_BY then | ||
|
||
V_CSV := substr( V_CSV, length( I_ENCLOSED_BY ) + 1 ); | ||
V_INSIDE := true; | ||
V_FIELD := I_ENCLOSED_BY; | ||
|
||
-- a new field starts | ||
else | ||
V_FIELD := substr( V_CSV, 1 , 1 ); | ||
V_CSV := substr( V_CSV, 2 ); | ||
V_INSIDE := true; | ||
end if; | ||
|
||
else -- inside | ||
|
||
-- did we reach the end of field | ||
if ( I_ENCLOSED_BY is null or substr( V_FIELD, 1, length( I_ENCLOSED_BY ) ) != I_ENCLOSED_BY ) | ||
and substr( V_CSV, 1, length( V_SEPARATOR ) ) = V_SEPARATOR then | ||
|
||
V_CSV := substr( V_CSV, length( V_SEPARATOR ) + 1 ); | ||
PIPE ROW( V_FIELD ); | ||
V_INSIDE := false; | ||
V_FIELD := ''; | ||
|
||
-- did we reach the end of field with an "enclosed by" | ||
elsif substr( V_CSV , 1 , length( I_ENCLOSED_BY ) ) = I_ENCLOSED_BY and | ||
nvl( substr( V_CSV , length( I_ENCLOSED_BY ) + 1, length( V_SEPARATOR ) ), V_SEPARATOR ) = V_SEPARATOR then | ||
|
||
V_CSV := substr( V_CSV, length( I_ENCLOSED_BY ) + 1 ); | ||
V_FIELD := V_FIELD||I_ENCLOSED_BY; | ||
-- if the field is really enclosed, then we remove the enclose strings | ||
if substr( V_FIELD, 1, length( I_ENCLOSED_BY ) ) = I_ENCLOSED_BY and | ||
substr( V_FIELD, -length( I_ENCLOSED_BY ) ) = I_ENCLOSED_BY then | ||
V_FIELD := substr( V_FIELD, length( I_ENCLOSED_BY ) + 1, length( V_FIELD ) - 2 * length( I_ENCLOSED_BY ) ); | ||
end if; | ||
V_INSIDE := false; | ||
|
||
-- just add it to the field | ||
else | ||
V_FIELD := V_FIELD || substr( V_CSV, 1 , 1 ); | ||
V_CSV := substr( V_CSV, 2 ); | ||
end if; | ||
|
||
end if; | ||
|
||
end loop; | ||
|
||
return; | ||
|
||
end; | ||
/ | ||
|
Oops, something went wrong.