-
Notifications
You must be signed in to change notification settings - Fork 1
/
Copy pathInstall_ETL.sql
687 lines (529 loc) · 30 KB
/
Install_ETL.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
/*********************************************************************
Author : TothF
Remark : Objects for ETL
Date : 2022.01.05
*********************************************************************/
Prompt *****************************************************************
Prompt ** I N S T A L L I N G E T L _ T A B L E S **
Prompt *****************************************************************
/*============================================================================================*/
create table ETL_TABLES (
/*============================================================================================*/
LOCAL_NAME varchar2( 500 ) not null,
REMOTE_NAME varchar2( 500 ) not null,
TRANSFER_TYPE varchar2( 500 ) not null,
JOB_STARTED timestamp null,
JOB_ID number null,
JOB_FINISHED timestamp null,
JOB_RESULT varchar2( 4000 ) null,
NOF_INSERTED_ROWS number null,
NOF_UPDATED_ROWS number null,
NOF_DELETED_ROWS number null
);
comment on table ETL_TABLES is 'This table configures and administrates the ETL Tables';
comment on column ETL_TABLES.LOCAL_NAME is 'The name of the target table (with schema name if necessary) eg: ITEMS';
comment on column ETL_TABLES.REMOTE_NAME is 'The name of the source data source whith db_link name (table or view) eg: ITEMS@MASTER';
comment on column ETL_TABLES.TRANSFER_TYPE is '"FULL" = truncate target then insert every rows from source, "MERGE" = merge/upsert based on PK, or a column name such: ID = incremental based on ID, MODIF_TIME = incremental based on MODIF_TIME etc.';
comment on column ETL_TABLES.JOB_STARTED is 'Start time of last ETL Job';
comment on column ETL_TABLES.JOB_ID is 'ID of last ETL Job';
comment on column ETL_TABLES.JOB_FINISHED is 'End time of last ETL Job';
comment on column ETL_TABLES.JOB_RESULT is 'Result of last ETL Job run';
comment on column ETL_TABLES.NOF_INSERTED_ROWS is 'Number of inserted rows in the last Job run';
comment on column ETL_TABLES.NOF_UPDATED_ROWS is 'Number of updated rows in the last Job run';
comment on column ETL_TABLES.NOF_DELETED_ROWS is 'Number of deleted rows in the last Job run';
alter table ETL_TABLES add ( constraint ETL_TABLES_PK primary key ( LOCAL_NAME ) );
Prompt *****************************************************************
Prompt ** F I L L I N G U P E T L _ T A B L E S **
Prompt *****************************************************************
SET DEFINE OFF;
/*
Insert into ETL_TABLES (LOCAL_NAME,REMOTE_NAME,TRANSFER_TYPE) values ('ITEMS','ITEMS@MASTER','FULL');
*/
Prompt *****************************************************************
Prompt ** C R E A T I N G T Y P E **
Prompt *****************************************************************
create or replace type T_STRING_LIST as table of varchar2( 32000 );
/
Prompt *****************************************************************
Prompt ** I N S T A L L I N G E T L _ P K G **
Prompt *****************************************************************
/*============================================================================================*/
create or replace package PKG_ETL as
procedure ETL_TABLE ( I_TARGET_TABLE_NAME in varchar2 );
procedure START_ETL ( I_TARGET_TABLE_NAME in varchar2 := null );
function ONE_TAB_DEF_DIFF ( I_TARGET_TABLE_NAME in varchar2 ) return T_STRING_LIST PIPELINED;
function ALL_TAB_DEF_DIFF return T_STRING_LIST PIPELINED;
function EXEC_SQL ( I_SQL in varchar2 ) return T_STRING_LIST PIPELINED;
function ONE_TAB_DAT_DIFF ( I_TARGET_TABLE_NAME in varchar2 ) return T_STRING_LIST PIPELINED;
function ALL_TAB_DAT_DIFF return T_STRING_LIST PIPELINED;
end;
/
/*============================================================================================*/
create or replace package body PKG_ETL as
--******************************************************************************
--
-- DESCRIPTION:
-- This package can manage ETL process
--
-- AUTHORS:
--
-- FTH: Ferenc Toth
--
-- MODIFICATION HISTORY:
--
-- YYYY.MM.DD | GGGGNN | DESCRIPTION
--------------+----------+-----------------------------------------------------------
-- 2022.01.05 | 1.0 FTH | Created
--------------+----------+-----------------------------------------------------------
--
--******************************************************************************
----------------------------------------
function GET_PK ( I_TABLE_NAME in varchar2
, I_PREFIX in varchar2 := null
) return varchar2 is
----------------------------------------
L_PK varchar2(4000);
L_SEP varchar2(40) := ',';
begin
for L_A_PK in ( select column_name
from user_constraints uc, user_cons_columns dbc
where uc.constraint_type = 'P'
and dbc.constraint_name = uc.constraint_name
and dbc.table_name = I_TABLE_NAME
order by position
)
loop
if nvl(length(L_PK),0)+length(L_A_PK.COLUMN_NAME) < 4000 then
L_PK:=L_PK||I_PREFIX||L_A_PK.column_name||L_SEP;
end if;
end loop;
L_PK := substr(L_PK,1,length(L_PK)-(length(L_SEP)));
return L_PK;
end;
----------------------------------------
function GET_COLUMN_LIST ( I_TABLE_NAME in varchar2 ) return varchar2 is
----------------------------------------
L_CL varchar2(4000);
L_SEP varchar2(40) := ',';
begin
for L_C in ( select column_name
from user_tab_columns
where table_name = I_TABLE_NAME
order by column_id
)
loop
L_CL:=L_CL||L_C.COLUMN_NAME||L_SEP;
end loop;
L_CL := substr(L_CL,1,length(L_CL)-(length(L_SEP)));
return L_CL;
end;
---------------------------------------------------------------------------
procedure ETL_TABLE ( I_TARGET_TABLE_NAME in varchar2 ) as
---------------------------------------------------------------------------
V_ETL_TABLE ETL_TABLES%rowtype;
V_JOB_RESULT ETL_TABLES.JOB_RESULT%type := 'SUCCESS';
V_NOF_INSERTED_ROWS number := 0;
V_NOF_UPDATED_ROWS number := 0;
V_NOF_DELETED_ROWS number := 0;
V_SQL varchar2( 2000 );
V_BLOCK varchar2( 32000 );
V_WHERE varchar2( 4000 );
V_SQC number;
V_SQE varchar2(2000);
V_CNT number;
----------------------------------------
procedure GENERATE_SQL as
----------------------------------------
L_NUMBER number;
L_TIMESTAMP timestamp;
L_DATE date;
L_DATA_TYPE varchar2( 200 );
begin
V_SQL := 'select '|| GET_COLUMN_LIST( I_TARGET_TABLE_NAME ) ||' from '||V_ETL_TABLE.REMOTE_NAME;
if upper( V_ETL_TABLE.TRANSFER_TYPE ) not in ( 'FULL', 'MERGE' ) then
select min( data_type )
into L_DATA_TYPE
from user_tab_columns
where table_name = I_TARGET_TABLE_NAME
and column_name = V_ETL_TABLE.TRANSFER_TYPE;
if L_DATA_TYPE is null then
V_ETL_TABLE.TRANSFER_TYPE := 'FULL';
elsif L_DATA_TYPE = 'DATE' then
execute immediate 'select max('||V_ETL_TABLE.TRANSFER_TYPE||') from '||I_TARGET_TABLE_NAME into L_DATE;
L_DATE := nvl( L_DATE, sysdate - 10000 );
V_SQL := V_SQL || ' where '||V_ETL_TABLE.TRANSFER_TYPE||' > to_date( '''''|| to_char( L_DATE, 'YYYY.MM.DD HH24:MI:SS' ) ||''''' , ''''YYYY.MM.DD HH24:MI:SS'''' ) order by '||V_ETL_TABLE.TRANSFER_TYPE||' asc';
elsif substr( L_DATA_TYPE, 1, 9 ) = 'TIMESTAMP' then
execute immediate 'select max('||V_ETL_TABLE.TRANSFER_TYPE||') from '||I_TARGET_TABLE_NAME into L_TIMESTAMP;
L_TIMESTAMP := nvl( L_TIMESTAMP, systimestamp - 10000 );
V_SQL := V_SQL || ' where '||V_ETL_TABLE.TRANSFER_TYPE||' > to_timestamp( '''''|| to_char( L_TIMESTAMP, 'YYYY.MM.DD HH24:MI:SS.FF' ) ||''''' , ''''YYYY.MM.DD HH24:MI:SS.FF'''' ) order by '||V_ETL_TABLE.TRANSFER_TYPE||' asc';
elsif L_DATA_TYPE = 'NUMBER' then
execute immediate 'select max('||V_ETL_TABLE.TRANSFER_TYPE||') from '||I_TARGET_TABLE_NAME into L_NUMBER;
L_NUMBER := nvl( L_NUMBER, 0 );
V_SQL := V_SQL || ' where '||V_ETL_TABLE.TRANSFER_TYPE||' > '|| to_char( L_NUMBER ) ||' order by '||V_ETL_TABLE.TRANSFER_TYPE||' asc';
else
V_ETL_TABLE.TRANSFER_TYPE := 'FULL';
end if;
end if;
end;
----------------------------------------
procedure GENERATE_WHERE as
----------------------------------------
L_NUMBER number;
L_TIMESTAMP timestamp;
begin
V_WHERE := '( '||GET_PK( I_TARGET_TABLE_NAME )||' ) = ( select '||GET_PK( I_TARGET_TABLE_NAME, 'V_ROW.' )||' from dual )' ;
end;
----------------------------------------
procedure GENERATE_BLOCK as
----------------------------------------
L_CRLF varchar(2) := chr(13)||chr(10); -- $0D0A CrLf
begin
if V_ETL_TABLE.TRANSFER_TYPE = 'FULL' then
V_BLOCK := 'declare'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_INS number := 0;'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_UPD number := 0;'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_DEL number := 0;'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_RES ETL_TABLES.JOB_RESULT%type := ''SUCCESS'';'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_SQC number;'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_SQE varchar2(2000);'||L_CRLF;
V_BLOCK := V_BLOCK || 'begin'||L_CRLF;
V_BLOCK := V_BLOCK || ' begin'||L_CRLF;
V_BLOCK := V_BLOCK || ' select count(*) into V_DEL from '||I_TARGET_TABLE_NAME||';'||L_CRLF;
V_BLOCK := V_BLOCK || ' execute immediate ''truncate table '||I_TARGET_TABLE_NAME||''';'||L_CRLF;
V_BLOCK := V_BLOCK || ' insert into '||I_TARGET_TABLE_NAME||' '||V_SQL||';'||L_CRLF;
V_BLOCK := V_BLOCK || ' select count(*) into V_INS from '||I_TARGET_TABLE_NAME||';'||L_CRLF;
V_BLOCK := V_BLOCK || ' commit;'||L_CRLF;
V_BLOCK := V_BLOCK || ' exception when others then'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_SQC := sys.standard.sqlcode;'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_SQE := sys.standard.sqlerrm;'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_RES := V_SQC||'' ''||V_SQE;'||L_CRLF;
V_BLOCK := V_BLOCK || ' end;'||L_CRLF;
V_BLOCK := V_BLOCK || ' :INS := V_INS;'||L_CRLF;
V_BLOCK := V_BLOCK || ' :UPD := V_UPD;'||L_CRLF;
V_BLOCK := V_BLOCK || ' :DEL := V_DEL;'||L_CRLF;
V_BLOCK := V_BLOCK || ' :RES := V_RES;'||L_CRLF;
V_BLOCK := V_BLOCK || 'end;'||L_CRLF;
else
V_BLOCK := 'declare'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_DS sys_refcursor;'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_SQL varchar(3000) := '''||V_SQL||''';'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_ROW '||I_TARGET_TABLE_NAME||'%rowtype;'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_INS number := 0;'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_UPD number := 0;'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_DEL number := 0;'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_RES ETL_TABLES.JOB_RESULT%type := ''SUCCESS'';'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_SQC number;'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_SQE varchar2(2000);'||L_CRLF;
V_BLOCK := V_BLOCK || 'begin'||L_CRLF;
V_BLOCK := V_BLOCK || ' open V_DS for V_SQL;'||L_CRLF;
V_BLOCK := V_BLOCK || ' loop'||L_CRLF;
V_BLOCK := V_BLOCK || ' fetch V_DS into V_ROW;'||L_CRLF;
V_BLOCK := V_BLOCK || ' exit when V_DS%notfound;'||L_CRLF;
V_BLOCK := V_BLOCK || ' begin'||L_CRLF;
V_BLOCK := V_BLOCK || ' insert into '||I_TARGET_TABLE_NAME||' values V_ROW;'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_INS := V_INS + 1;'||L_CRLF;
V_BLOCK := V_BLOCK || ' exception '||L_CRLF;
V_BLOCK := V_BLOCK || ' when dup_val_on_index then'||L_CRLF;
V_BLOCK := V_BLOCK || ' update '||I_TARGET_TABLE_NAME||' set row = V_ROW where '||V_WHERE||';'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_UPD := V_UPD + 1;'||L_CRLF;
V_BLOCK := V_BLOCK || ' when others then'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_SQC := sys.standard.sqlcode;'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_SQE := sys.standard.sqlerrm;'||L_CRLF;
V_BLOCK := V_BLOCK || ' V_RES := V_SQC||'' ''||V_SQE;'||L_CRLF;
V_BLOCK := V_BLOCK || ' exit;'||L_CRLF;
V_BLOCK := V_BLOCK || ' end;'||L_CRLF;
V_BLOCK := V_BLOCK || ' commit;'||L_CRLF;
V_BLOCK := V_BLOCK || ' end loop;'||L_CRLF;
V_BLOCK := V_BLOCK || ' close V_DS;'||L_CRLF;
V_BLOCK := V_BLOCK || ' :INS := V_INS;'||L_CRLF;
V_BLOCK := V_BLOCK || ' :UPD := V_UPD;'||L_CRLF;
V_BLOCK := V_BLOCK || ' :DEL := V_DEL;'||L_CRLF;
V_BLOCK := V_BLOCK || ' :RES := V_RES;'||L_CRLF;
V_BLOCK := V_BLOCK || 'end;'||L_CRLF;
end if;
end;
begin
select * into V_ETL_TABLE from ETL_TABLES where LOCAL_NAME = I_TARGET_TABLE_NAME;
select count(*) into V_CNT from all_jobs where job = V_ETL_TABLE.JOB_ID and broken='N';
if V_CNT = 1 and V_ETL_TABLE.JOB_STARTED is null then
update ETL_TABLES
set JOB_STARTED = systimestamp
where LOCAL_NAME = I_TARGET_TABLE_NAME;
commit;
GENERATE_SQL;
GENERATE_WHERE;
GENERATE_BLOCK;
execute immediate V_BLOCK using out V_NOF_INSERTED_ROWS, out V_NOF_UPDATED_ROWS, out V_NOF_DELETED_ROWS, out V_JOB_RESULT;
update ETL_TABLES
set JOB_FINISHED = systimestamp
, JOB_RESULT = V_JOB_RESULT
, NOF_INSERTED_ROWS = V_NOF_INSERTED_ROWS
, NOF_UPDATED_ROWS = V_NOF_UPDATED_ROWS
, NOF_DELETED_ROWS = V_NOF_DELETED_ROWS
where LOCAL_NAME = I_TARGET_TABLE_NAME;
commit;
end if;
exception when others then
V_SQC := sys.standard.sqlcode;
V_SQE := sys.standard.sqlerrm;
update ETL_TABLES
set JOB_FINISHED = systimestamp
, JOB_RESULT = to_char( V_SQC )||' - '||V_SQE
, NOF_INSERTED_ROWS = V_NOF_INSERTED_ROWS
, NOF_UPDATED_ROWS = V_NOF_UPDATED_ROWS
, NOF_DELETED_ROWS = V_NOF_DELETED_ROWS
where LOCAL_NAME = I_TARGET_TABLE_NAME;
commit;
end;
---------------------------------------------------------------------------
procedure START_ETL ( I_TARGET_TABLE_NAME in varchar2 := null ) as
---------------------------------------------------------------------------
V_JOB_ID number;
V_WHAT varchar2( 2000 );
V_SLEEP number := 1; -- wait some seconds between two job starting
V_CNT number;
begin
for L_R in ( select * from ETL_TABLES where LOCAL_NAME = nvl( I_TARGET_TABLE_NAME, LOCAL_NAME ) )
loop
V_WHAT := 'PKG_ETL.ETL_TABLE( '''||L_R.LOCAL_NAME||''' );';
select count(*) into V_CNT from all_jobs where job = L_R.JOB_ID and broken='N';
if V_CNT = 0 then
dbms_job.submit( job => V_JOB_ID
, what => V_WHAT
, next_date => sysdate - 1
, interval => null
);
update ETL_TABLES
set JOB_STARTED = null
, JOB_ID = V_JOB_ID
, JOB_FINISHED = null
, JOB_RESULT = null
, NOF_INSERTED_ROWS = null
, NOF_UPDATED_ROWS = null
, NOF_DELETED_ROWS = null
where LOCAL_NAME = L_R.LOCAL_NAME;
commit;
$IF DBMS_DB_VERSION.VERSION < 18 $THEN
sys.dbms_lock.sleep( V_SLEEP );
$ELSE
sys.dbms_session.sleep( V_SLEEP );
$END
end if;
end loop;
end;
---------------------------------------------------------------------------
function ONE_TAB_DEF_DIFF ( I_TARGET_TABLE_NAME in varchar2 ) return T_STRING_LIST PIPELINED as
---------------------------------------------------------------------------
-- use :
-- select * from PKG_ETL.ONE_TAB_DEF_DIFF( 'INVOICE_FILE');
---------------------------------------------------------------------------
V_ETL_TABLE ETL_TABLES%rowtype;
V_R_TAB_NAME varchar2( 300 );
V_MS_POS number;
V_DB_LINK varchar2( 300 );
V_DS_L sys_refcursor;
V_DS_R sys_refcursor;
V_N number := 0;
V_L_COLUMN_NAME varchar2( 300 );
V_L_DATA_TYPE varchar2( 300 );
V_L_DATA_LENGTH number;
V_L_DATA_PRECISION number;
V_L_DATA_SCALE number;
V_R_COLUMN_NAME varchar2( 300 );
V_R_DATA_TYPE varchar2( 300 );
V_R_DATA_LENGTH number;
V_R_DATA_PRECISION number;
V_R_DATA_SCALE number;
begin
select * into V_ETL_TABLE from ETL_TABLES where LOCAL_NAME = I_TARGET_TABLE_NAME;
V_MS_POS := instr( V_ETL_TABLE.REMOTE_NAME, '@' );
if V_MS_POS = 0 then
V_R_TAB_NAME := V_ETL_TABLE.REMOTE_NAME;
V_DB_LINK := null;
else
V_R_TAB_NAME := substr( V_ETL_TABLE.REMOTE_NAME, 1 , V_MS_POS - 1 );
V_DB_LINK := substr( V_ETL_TABLE.REMOTE_NAME, V_MS_POS, 300 );
end if;
PIPE ROW( 'Source : '||V_ETL_TABLE.REMOTE_NAME );
PIPE ROW( 'Target : '||V_ETL_TABLE.LOCAL_NAME );
open V_DS_L for 'select COLUMN_NAME, DATA_TYPE, DATA_LENGTH, DATA_PRECISION, DATA_SCALE from user_tab_columns where table_name = '''||V_ETL_TABLE.LOCAL_NAME||''' order by column_name';
fetch V_DS_L into V_L_COLUMN_NAME, V_L_DATA_TYPE, V_L_DATA_LENGTH, V_L_DATA_PRECISION, V_L_DATA_SCALE;
if V_DS_L%notfound then
PIPE ROW( ' ' );
PIPE ROW( ' ! Table (target) does not exist locally.' );
PIPE ROW( '-----------------------------------------------------------' );
close V_DS_L;
return;
end if;
open V_DS_R for 'select COLUMN_NAME, DATA_TYPE, DATA_LENGTH, DATA_PRECISION, DATA_SCALE from user_tab_columns'||V_DB_LINK||' where table_name = '''||V_R_TAB_NAME||''' order by column_name';
fetch V_DS_R into V_R_COLUMN_NAME, V_R_DATA_TYPE, V_R_DATA_LENGTH, V_R_DATA_PRECISION, V_R_DATA_SCALE;
if V_DS_R%notfound then
PIPE ROW( ' ' );
PIPE ROW( ' ! Table (source) does not exist remotely.' );
PIPE ROW( '-----------------------------------------------------------' );
close V_DS_R;
return;
end if;
loop
if V_L_COLUMN_NAME = V_R_COLUMN_NAME then
if V_L_DATA_TYPE != V_R_DATA_TYPE
or V_L_DATA_LENGTH != V_R_DATA_LENGTH
or V_L_DATA_PRECISION != V_R_DATA_PRECISION
or V_L_DATA_SCALE != V_L_DATA_SCALE then
PIPE ROW( ' ' );
PIPE ROW( ' ! Column '||V_L_COLUMN_NAME|| ' definitions are different:' );
PIPE ROW( ' Source : Type: '||V_R_DATA_TYPE||', Length: '||to_char( V_R_DATA_LENGTH )||', Precision: '||to_char( V_R_DATA_PRECISION )||', Scale: '||to_char( V_R_DATA_SCALE ) );
PIPE ROW( ' Target : Type: '||V_L_DATA_TYPE||', Length: '||to_char( V_L_DATA_LENGTH )||', Precision: '||to_char( V_L_DATA_PRECISION )||', Scale: '||to_char( V_L_DATA_SCALE ) );
V_N := V_N + 1;
end if;
if V_DS_L%isopen then
fetch V_DS_L into V_L_COLUMN_NAME, V_L_DATA_TYPE, V_L_DATA_LENGTH, V_L_DATA_PRECISION, V_L_DATA_SCALE;
if V_DS_L%notfound then
close V_DS_L;
end if;
end if;
if V_DS_R%isopen then
fetch V_DS_R into V_R_COLUMN_NAME, V_R_DATA_TYPE, V_R_DATA_LENGTH, V_R_DATA_PRECISION, V_R_DATA_SCALE;
if V_DS_R%notfound then
close V_DS_R;
end if;
end if;
elsif V_L_COLUMN_NAME > V_R_COLUMN_NAME or not V_DS_L%isopen then
PIPE ROW( ' ' );
PIPE ROW( ' ! Column : '||V_R_COLUMN_NAME|| ' is missing locally' );
PIPE ROW( ' Type : '||V_R_DATA_TYPE||', Length: '||to_char( V_R_DATA_LENGTH )||', Precision: '||to_char( V_R_DATA_PRECISION )||', Scale: '||to_char( V_R_DATA_SCALE ) );
V_N := V_N + 1;
if V_DS_R%isopen then
fetch V_DS_R into V_R_COLUMN_NAME, V_R_DATA_TYPE, V_R_DATA_LENGTH, V_R_DATA_PRECISION, V_R_DATA_SCALE;
if V_DS_R%notfound then
close V_DS_R;
end if;
end if;
elsif V_L_COLUMN_NAME < V_R_COLUMN_NAME or not V_DS_R%isopen then
PIPE ROW( ' ' );
PIPE ROW( ' ! Column : '||V_L_COLUMN_NAME|| ' is missing remotely' );
PIPE ROW( ' Type : '||V_L_DATA_TYPE||', Length: '||to_char( V_L_DATA_LENGTH )||', Precision: '||to_char( V_L_DATA_PRECISION )||', Scale: '||to_char( V_L_DATA_SCALE ) );
V_N := V_N + 1;
if V_DS_L%isopen then
fetch V_DS_L into V_L_COLUMN_NAME, V_L_DATA_TYPE, V_L_DATA_LENGTH, V_L_DATA_PRECISION, V_L_DATA_SCALE;
if V_DS_L%notfound then
close V_DS_L;
end if;
end if;
end if;
exit when not V_DS_L%isopen and not V_DS_R%isopen;
end loop;
if V_N = 0 then
PIPE ROW( ' = The definition of tables are identical.' );
end if;
PIPE ROW( '-----------------------------------------------------------' );
return;
end;
---------------------------------------------------------------------------
function ALL_TAB_DEF_DIFF return T_STRING_LIST PIPELINED as
---------------------------------------------------------------------------
-- use :
-- select * from PKG_ETL.ALL_TAB_DEF_DIFF();
---------------------------------------------------------------------------
begin
PIPE ROW( '-----------------------------------------------------------' );
for L_R in ( select LOCAL_NAME from ETL_TABLES order by LOCAL_NAME )
loop
for L_C in ( select * from table( PKG_ETL.ONE_TAB_DEF_DIFF( L_R.LOCAL_NAME ) ) )
loop
PIPE ROW( L_C.column_value );
end loop;
end loop;
return;
end;
---------------------------------------------------------------------------
function EXEC_SQL ( I_SQL in varchar2 ) return T_STRING_LIST PIPELINED as
---------------------------------------------------------------------------
V_DATA sys_refcursor;
V_CURSOR integer;
V_COLUMNS integer;
V_DESC dbms_sql.desc_tab2;
V_STR varchar2( 4000 );
V_CV varchar2( 4000 );
V_NUM number;
V_SEP varchar2(10) := chr( 9 ); -- horizontal tab
begin
open V_DATA for I_SQL;
V_CURSOR := dbms_sql.to_cursor_number( V_DATA );
dbms_sql.describe_columns2( V_CURSOR, V_COLUMNS, V_DESC );
for V_I in 1..V_COLUMNS
loop
if length( V_STR ) < 4000 or V_STR is null then
V_STR := substr( V_STR || V_DESC( V_I ).col_name || V_SEP, 1, 4000 );
end if;
end loop;
PIPE ROW( V_STR );
V_STR := '';
for V_I in 1..V_COLUMNS
loop
dbms_sql.define_column( V_CURSOR, V_I, V_STR, 32000 );
end loop;
V_STR := '';
while dbms_sql.fetch_rows( V_CURSOR ) > 0
loop
for V_I in 1..V_COLUMNS
loop
dbms_sql.column_value( V_CURSOR, V_I, V_CV );
if length( V_STR ) < 4000 or V_STR is null then
V_STR := substr( V_STR || V_CV || V_SEP, 1, 4000 );
end if;
end loop;
PIPE ROW( V_STR );
V_STR := '';
end loop;
dbms_sql.close_cursor( V_CURSOR );
return;
end;
---------------------------------------------------------------------------
function ONE_TAB_DAT_DIFF ( I_TARGET_TABLE_NAME in varchar2 ) return T_STRING_LIST PIPELINED as
---------------------------------------------------------------------------
-- use :
-- select * from PKG_ETL.ONE_TAB_DAT_DIFF( 'INVOICE_FILE');
---------------------------------------------------------------------------
V_ETL_TABLE ETL_TABLES%rowtype;
V_CL varchar2( 4000 );
begin
select * into V_ETL_TABLE from ETL_TABLES where LOCAL_NAME = I_TARGET_TABLE_NAME;
V_CL := GET_COLUMN_LIST( V_ETL_TABLE.LOCAL_NAME );
PIPE ROW( ' ' );
PIPE ROW( V_ETL_TABLE.LOCAL_NAME||' minus '||V_ETL_TABLE.REMOTE_NAME );
PIPE ROW( ' ' );
for L_C in ( select * from table( PKG_ETL.EXEC_SQL ( 'select '|| V_CL ||' from '||V_ETL_TABLE.LOCAL_NAME|| ' minus select '|| V_CL ||' from '||V_ETL_TABLE.REMOTE_NAME ) ) )
loop
PIPE ROW( L_C.column_value );
end loop;
PIPE ROW( '-----------------------------------------------------------' );
PIPE ROW( ' ' );
PIPE ROW( V_ETL_TABLE.REMOTE_NAME||' minus '||V_ETL_TABLE.LOCAL_NAME );
PIPE ROW( ' ' );
for L_C in ( select * from table( PKG_ETL.EXEC_SQL ( 'select '|| V_CL ||' from '||V_ETL_TABLE.REMOTE_NAME|| ' minus select '|| V_CL ||' from '||V_ETL_TABLE.LOCAL_NAME ) ) )
loop
PIPE ROW( L_C.column_value );
end loop;
PIPE ROW( '=============================================================================' );
return;
end;
---------------------------------------------------------------------------
function ALL_TAB_DAT_DIFF return T_STRING_LIST PIPELINED as
---------------------------------------------------------------------------
-- use :
-- select * from PKG_ETL.ALL_TAB_DAT_DIFF();
---------------------------------------------------------------------------
begin
PIPE ROW( '=============================================================================' );
for L_R in ( select LOCAL_NAME from ETL_TABLES order by LOCAL_NAME )
loop
for L_C in ( select * from table( PKG_ETL.ONE_TAB_DAT_DIFF( L_R.LOCAL_NAME ) ) )
loop
PIPE ROW( L_C.column_value );
end loop;
end loop;
return;
end;
end;
/