Skip to content

Commit c66d9b6

Browse files
Add files via upload
1 parent e7f3bc2 commit c66d9b6

File tree

1 file changed

+260
-0
lines changed

1 file changed

+260
-0
lines changed

EXP_IMP_LOB.sql

Lines changed: 260 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,260 @@
1+
2+
create or replace package EXP_IMP_LOB is
3+
4+
/* *******************************************************************************************************
5+
6+
History of changes
7+
yyyy.mm.dd | Version | Author | Changes
8+
-----------+---------+----------------+-------------------------
9+
2017.01.06 | 1.0 | Ferenc Toth | Created
10+
11+
******************************************************************************************************* */
12+
13+
14+
type T_STRING_LIST is table of varchar2( 32000 );
15+
16+
---------------------------------------------------------------------------
17+
function EXPORT ( I_TABLE_NAME in varchar2
18+
, I_COLUMN_NAME in varchar2
19+
, I_WHERE in varchar2 default null
20+
) return T_STRING_LIST pipelined;
21+
---------------------------------------------------------------------------
22+
23+
---------------------------------------------------------------------------
24+
procedure IMPORT_NEW;
25+
---------------------------------------------------------------------------
26+
27+
---------------------------------------------------------------------------
28+
procedure IMPORT_APPEND ( I_RAW in varchar2);
29+
---------------------------------------------------------------------------
30+
31+
---------------------------------------------------------------------------
32+
procedure DIRECT_SQL ( I_SQL in varchar2 );
33+
---------------------------------------------------------------------------
34+
35+
---------------------------------------------------------------------------
36+
procedure IMPORT_UPDATE ( I_TABLE_NAME in varchar2
37+
, I_COLUMN_NAME in varchar2
38+
, I_PK in varchar2
39+
);
40+
---------------------------------------------------------------------------
41+
42+
end;
43+
/
44+
45+
46+
47+
create or replace package body EXP_IMP_LOB is
48+
49+
/* *******************************************************************************************************
50+
51+
History of changes
52+
yyyy.mm.dd | Version | Author | Changes
53+
-----------+---------+----------------+-------------------------
54+
2017.01.06 | 1.0 | Ferenc Toth | Created
55+
56+
******************************************************************************************************* */
57+
58+
G_TABLE_NAME varchar( 40 );
59+
G_COLUMN_NAME varchar( 40 );
60+
G_COLUMN_TYPE varchar( 40 );
61+
G_PK_KEY varchar( 4000 );
62+
G_PK_LST varchar( 4000 );
63+
G_LENGTH number := 200;
64+
G_BLOB blob;
65+
G_CLOB clob;
66+
67+
---------------------------------------------------------------------------
68+
procedure GET_PK ( I_TABLE_NAME in varchar ) is
69+
---------------------------------------------------------------------------
70+
L_SEP varchar ( 40 ) := ',';
71+
L_DATA_TYPE varchar2( 30 );
72+
begin
73+
G_PK_KEY := '';
74+
G_PK_LST := '';
75+
for L_A_PK in ( select COLUMN_NAME
76+
from USER_CONSTRAINTS UC
77+
, USER_CONS_COLUMNS DBC
78+
where UC.CONSTRAINT_TYPE = 'P'
79+
and DBC.CONSTRAINT_NAME = UC.CONSTRAINT_NAME
80+
and DBC.TABLE_NAME = I_TABLE_NAME
81+
order by position
82+
)
83+
loop
84+
if nvl( length( G_PK_KEY ), 0 ) + length( L_A_PK.COLUMN_NAME ) < 4000 then
85+
select DATA_TYPE into L_DATA_TYPE from user_tab_columns where table_name = G_TABLE_NAME and column_name = L_A_PK.COLUMN_NAME;
86+
if instr( L_DATA_TYPE, 'CHAR') > 0 then
87+
G_PK_KEY := G_PK_KEY||'''''''''||'||L_A_PK.COLUMN_NAME||'||''''''''||'''||L_SEP||'''||';
88+
elsif instr( L_DATA_TYPE, 'DATE') > 0 then
89+
G_PK_KEY := G_PK_KEY||'''TO_DATE(''''''||TO_CHAR('||L_A_PK.COLUMN_NAME||',''YYYY.MM.DD HH24:MI:SS'')||'''''',''''YYYY.MM.DD HH24:MI:SS'''')''||'''||L_SEP||'''||';
90+
else
91+
G_PK_KEY := G_PK_KEY||L_A_PK.COLUMN_NAME||'||'''||L_SEP||'''||';
92+
end if;
93+
G_PK_LST := G_PK_LST||L_A_PK.COLUMN_NAME||L_SEP;
94+
end if;
95+
end loop;
96+
G_PK_KEY := substr( G_PK_KEY, 1, length( G_PK_KEY ) - ( 6 + length( L_SEP ) ) );
97+
G_PK_LST := substr( G_PK_LST, 1, length( G_PK_LST ) - length(L_SEP));
98+
end;
99+
100+
101+
---------------------------------------------------------------------------
102+
function EXPORT ( I_TABLE_NAME in varchar2
103+
, I_COLUMN_NAME in varchar2
104+
, I_WHERE in varchar2 default null
105+
) return T_STRING_LIST pipelined is
106+
---------------------------------------------------------------------------
107+
V_BLOB blob;
108+
V_CLOB clob;
109+
V_CUR_SQL varchar( 32000 );
110+
V_LOB_SQL varchar( 32000 );
111+
V_RAW varchar( 32000 );
112+
V_START number;
113+
V_PK varchar( 4000 );
114+
V_REC_SET sys_refcursor;
115+
116+
begin
117+
G_TABLE_NAME := upper( trim( I_TABLE_NAME ) );
118+
G_COLUMN_NAME := upper( trim( I_COLUMN_NAME ) );
119+
GET_PK( G_TABLE_NAME );
120+
select DATA_TYPE into G_COLUMN_TYPE from user_tab_columns where table_name = G_TABLE_NAME and column_name = G_COLUMN_NAME;
121+
if G_COLUMN_TYPE not in ('CLOB','NCLOB','BLOB') then
122+
raise_application_error ( -20001, 'The type of column '||I_COLUMN_NAME||' is not CLOB, NCLOB or BLOB' );
123+
end if;
124+
125+
V_CUR_SQL := 'select '||G_PK_KEY||' from '||G_TABLE_NAME||' where '||nvl( I_WHERE, ' 1 = 1 ');
126+
open V_REC_SET for V_CUR_SQL;
127+
loop
128+
fetch V_REC_SET into V_PK;
129+
exit when V_REC_SET%notfound;
130+
PIPE ROW( '/******************************************************' );
131+
PIPE ROW( ' TABLE :'||G_TABLE_NAME );
132+
PIPE ROW( ' COLUMN :'||G_COLUMN_NAME );
133+
PIPE ROW( ' ROW :'||V_PK );
134+
PIPE ROW( '******************************************************/' );
135+
PIPE ROW( 'BEGIN' );
136+
PIPE ROW( ' EXP_IMP_LOB.IMPORT_NEW;' );
137+
V_LOB_SQL := 'select '||G_COLUMN_NAME||' from '||G_TABLE_NAME||' where ('||G_PK_LST||') in ( select '||V_PK||' from dual )';
138+
139+
if G_COLUMN_TYPE = 'BLOB' then
140+
execute immediate V_LOB_SQL into V_BLOB;
141+
if nvl( dbms_lob.getlength( V_BLOB ), 0 ) > 0 then
142+
V_START := 1;
143+
for L_I IN 1..ceil( dbms_lob.getlength( V_BLOB ) / G_LENGTH )
144+
loop
145+
V_RAW := dbms_lob.substr( V_BLOB, G_LENGTH, V_START );
146+
PIPE ROW( ' EXP_IMP_LOB.IMPORT_APPEND ( '''||V_RAW||''');' );
147+
V_START := V_START + G_LENGTH;
148+
end loop;
149+
PIPE ROW( ' EXP_IMP_LOB.IMPORT_UPDATE ( '''||G_TABLE_NAME||''','''||G_COLUMN_NAME||''','''||replace(V_PK,'''','''''')||''' ); ');
150+
PIPE ROW( ' COMMIT;' );
151+
end if;
152+
else
153+
execute immediate V_LOB_SQL into V_CLOB;
154+
if nvl( dbms_lob.getlength( V_CLOB ), 0 ) > 0 then
155+
V_START := 1;
156+
for L_I IN 1..ceil( dbms_lob.getlength( V_CLOB ) / G_LENGTH )
157+
loop
158+
V_RAW := UTL_RAW.CAST_TO_RAW( dbms_lob.substr( V_CLOB, G_LENGTH, V_START ) );
159+
PIPE ROW( ' EXP_IMP_LOB.IMPORT_APPEND ( '''||V_RAW||''');' );
160+
V_START := V_START + G_LENGTH;
161+
end loop;
162+
PIPE ROW( ' EXP_IMP_LOB.IMPORT_UPDATE ( '''||G_TABLE_NAME||''','''||G_COLUMN_NAME||''','''||replace(V_PK,'''','''''')||''' ); ');
163+
PIPE ROW( ' COMMIT;' );
164+
end if;
165+
end if;
166+
PIPE ROW( 'END;' );
167+
PIPE ROW( '/' );
168+
PIPE ROW( ' ' );
169+
end loop;
170+
close V_REC_SET;
171+
172+
return;
173+
174+
end;
175+
176+
---------------------------------------------------------------------------
177+
procedure IMPORT_NEW is
178+
---------------------------------------------------------------------------
179+
begin
180+
G_BLOB := null;
181+
G_CLOB := null;
182+
end;
183+
184+
---------------------------------------------------------------------------
185+
procedure IMPORT_APPEND ( I_RAW in varchar2 ) is
186+
---------------------------------------------------------------------------
187+
V_BLOB blob;
188+
begin
189+
V_BLOB := hextoraw( I_RAW );
190+
if nvl( dbms_lob.getlength( V_BLOB ), 0 ) > 0 then
191+
if nvl( dbms_lob.getlength( G_BLOB ), 0 ) = 0 then
192+
G_BLOB := V_BLOB;
193+
else
194+
DBMS_LOB.APPEND( G_BLOB, V_BLOB );
195+
end if;
196+
end if;
197+
end;
198+
199+
---------------------------------------------------------------------------
200+
procedure DIRECT_SQL ( I_SQL in varchar2 ) is
201+
---------------------------------------------------------------------------
202+
begin
203+
if nvl( dbms_lob.getlength( G_BLOB ), 0 ) > 0 then
204+
execute immediate I_SQL using G_BLOB;
205+
else
206+
execute immediate I_SQL using G_CLOB;
207+
end if;
208+
commit;
209+
end;
210+
211+
-- I downloaded this from the Net:
212+
function clobfromblob( p_blob blob ) return clob is
213+
l_clob clob;
214+
l_dest_offsset integer := 1;
215+
l_src_offsset integer := 1;
216+
l_lang_context integer := dbms_lob.default_lang_ctx;
217+
l_warning integer;
218+
begin
219+
if p_blob is null then
220+
return null;
221+
end if;
222+
dbms_lob.createTemporary(lob_loc => l_clob
223+
,cache => false);
224+
dbms_lob.converttoclob(dest_lob => l_clob
225+
,src_blob => p_blob
226+
,amount => dbms_lob.lobmaxsize
227+
,dest_offset => l_dest_offsset
228+
,src_offset => l_src_offsset
229+
,blob_csid => dbms_lob.default_csid
230+
,lang_context => l_lang_context
231+
,warning => l_warning);
232+
return l_clob;
233+
end;
234+
235+
236+
---------------------------------------------------------------------------
237+
procedure IMPORT_UPDATE ( I_TABLE_NAME in varchar2
238+
, I_COLUMN_NAME in varchar2
239+
, I_PK in varchar2
240+
) is
241+
---------------------------------------------------------------------------
242+
V_SQL varchar( 32000 );
243+
begin
244+
G_TABLE_NAME := upper( trim( I_TABLE_NAME ) );
245+
G_COLUMN_NAME := upper( trim( I_COLUMN_NAME ) );
246+
GET_PK( G_TABLE_NAME );
247+
select DATA_TYPE into G_COLUMN_TYPE from user_tab_columns where table_name = G_TABLE_NAME and column_name = G_COLUMN_NAME;
248+
V_SQL := 'update '||I_TABLE_NAME||' set '||I_COLUMN_NAME||' = :1 where ('||G_PK_LST||') in ( select '||I_PK||' from dual )';
249+
if G_COLUMN_TYPE in ( 'CLOB', 'NCLOB' ) then
250+
G_CLOB := clobfromblob ( G_BLOB );
251+
G_BLOB := null;
252+
DIRECT_SQL( V_SQL );
253+
elsif G_COLUMN_TYPE in ( 'BLOB' ) then
254+
DIRECT_SQL( V_SQL );
255+
end if;
256+
end;
257+
258+
259+
end;
260+
/

0 commit comments

Comments
 (0)