-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathtrans_v2_1.sql
1883 lines (1582 loc) · 75 KB
/
trans_v2_1.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
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
create or replace PACKAGE trans
IS
/* TRANS stands for TRANSformation and TRANSfer
------------------------------------------------------------------------------------------------
This package is a set of handy functions and procedures for data transformation and transfer,
mainly associated with the data preparation for sending with email.
Igor Perkovic
Created: June, 2017.
Last modified: 20.12.2018. 8:56:19
CHANGE LOG:
===================================================================
20.12.2018. 8:56:19
-------------------
~ Changed default color in predefined table css
15.6.2018. 8:15:35
------------------
+ Added to_char(systimestamp, 'Dy, DD Mon YYYY HH24:MI:SS TZHTZM', 'NLS_DATE_LANGUAGE=ENGLISH') in MAIL for correct Sent date creation
8.6.2018. 14:11:15
-----------------------------------------------------------------
+ Add v_pass for password input in MAIL procedure
8.3.2018. 10:19:59
-----------------------------------------------------------------
+ Custom headers and footers in CSV functions
~ Changed DBMS_SQL.DESCRIBE_COLUMNS > DBMS_SQL.DESCRIBE_COLUMNS2
~ Changed DBMS_SQL.DESC_TAB > DBMS_SQL.DESC_TAB2
04.10.2017.
-----------------------------------------------------------------
+ Added CRLF or CR choice in "query2html" and "ref2html"
22.09.2017.
-----------------------------------------------------------------
+ Added procedure blob2file
14.09.2017.
-----------------------------------------------------------------
For query2csv_file and ref2csv_file
+ added default values for parameters
For MAIL
+ added 4th CLOB attachment as default
12.09.2017.
-----------------------------------------------------------------
Added 2 procedures
+ query2csv_file
+ ref2csv_file
for creating csv files.
It was already implemented with query2csv and clob2file, but these are a few miliseconds faster in average...
---------------------------------------------------------------------------------------------------------------
*/
FUNCTION query2csv(
/*
Igor Perkovic, Created: 11.07.2017. | Last updated: 21.07.2017.
THE PURPOSE:
This function translates the SQL query to the CSV format and return the result as a CLOB variable.
This way I can pass the CLOB to the CLOB2FILE procedure - if I want to save the result as a CSV file, or
I can send the CLOB result via email with MAIL procedure.
IN SHORT: From SQL query to file or as a mail attachment (in cooperation with P_CLOB2FILE and MAIL procedures)
OPTIONS:
You can customize the output a bit through the procedure INput parameters:
*/
p_sql IN VARCHAR2, -- SQL query
p_type IN NUMBER := 0, -- '1' for mail, '0' for file is default
p_delimiter IN VARCHAR2 :=';', -- Main delimiter
p_header IN NUMBER := 2, -- 1 = Header ON | 2 = CUSTOM HEADRE ON | 0 = HEADER OFF
p_footer IN NUMBER := 0, -- 1 = Footer ON | 0 = Footer OFF
p_cust_header IN VARCHAR2 := NULL, -- Custom header
p_cust_footer IN VARCHAR2 := NULL, -- Custom footer
p_text_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping text data
p_number_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping number data
p_date_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping dates
p_date_format IN VARCHAR2 :='DD.MM.RRRR') -- Date format
RETURN CLOB;
FUNCTION ref2csv(
/*
Igor Perkovic, Created: 11.07.2017. | Last modified: 21.07.2017.
THE PURPOSE:
This function catches the SYS_REFCURSOR from some outer function and transform the function result to the CSV format
and return the result as a CLOB variable.
This way I can pass the CLOB to the CLOB2FILE procedure - if I want to save the result as a CSV file, or
I can send the CLOB result via email using procedure MAIL.
OPTIONS:
You can customize the output a bit through the procedure INput parameters:
*/
p_refcursor IN OUT SYS_REFCURSOR, -- get the sys_refcursor
p_type IN NUMBER := 0, -- '1' for mail, '0' for file is default
p_delimiter IN VARCHAR2 :=';', -- Main delimiter
p_header IN NUMBER := 2, -- 1 = Header ON | 2 = CUSTOM HEADRE ON | 0 = HEADER OFF
p_footer IN NUMBER := 0, -- 1 = Footer ON | 0 = Footer OFF
p_cust_header IN VARCHAR2 := NULL, -- Custom header
p_cust_footer IN VARCHAR2 := NULL, -- Custom footer
p_text_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping text data
p_number_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping number data
p_date_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping dates
p_date_format IN VARCHAR2 :='DD.MM.RRRR') -- Date format
RETURN CLOB;
FUNCTION query2html(
/*
Igor Perkovic, Created: 12.07.2017. | Updated: 21.07.2017.
THE PURPOSE:
This function translates the SQL query to HTML table and return the result as a CLOB variable.
This way I can pass the CLOB to the CLOB2FILE procedure - if I want to save the result as a html file, or
I can send the CLOB result via email with MAIL procedure.
OPTIONS:
You can customize the output a bit through the procedure INput parameters:
*/
p_sql IN VARCHAR2, -- SQL query
p_css IN NUMBER :=0, -- No CSS by default - this is for in-mail sending (clob in mail body embedded).
-- as a side option, this can be used for CSS predefined styles, like 1,2,3, ...
-- but for now, there is only one CSS in code.
p_crlf IN NUMBER :=1, -- "crlf" is set to 1 by default. 0 is "cr" only.
p_charset IN VARCHAR2 := 'UTF-8', -- META CHARSET encoding string
p_tagl IN VARCHAR2 := '<td>', -- left tag (universal)
p_tagr IN VARCHAR2 := '</td>', -- right tag (universal)
p_tagl_v IN VARCHAR2 := '<td>', -- left tag for text data fields
p_tagl_n IN VARCHAR2 := '<td>', -- left tag for number data fields
p_tagl_d IN VARCHAR2 := '<td>', -- left tag for dates fields
p_text_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping text data
p_number_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping number data
p_date_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping dates
p_date_format IN VARCHAR2 :='DD-MM-YYYY',-- Date format
p_cust_header IN VARCHAR2 := '',
p_cust_footer IN VARCHAR2 := 'Powered by: <b>your_site.com</b>'
)
RETURN CLOB;
FUNCTION ref2html(
/*
Igor Perkovic, Created: 12.07.2017. | Updated: 21.07.2017.
THE PURPOSE:
This function translates the SYS_REF cursor to HTML table and return the result as a CLOB variable.
This way I can pass the CLOB to the CLOB2FILE procedure - if I want to save the result as a html file, or
I can send the CLOB result via email with MAIL procedure.
OPTIONS:
You can customize the output a bit through the procedure INput parameters:
*/
p_refcursor IN OUT SYS_REFCURSOR, -- get the sys_refcursor
p_css IN NUMBER :=0, -- No CSS by default - this is for in-mail sending (clob in mail body embedded).
-- as a side option, this can be used for CSS predefined styles, like 1,2,3, ...
-- but for now, there is only one CSS in code.
p_crlf IN NUMBER :=1, -- "crlf" is set to 1 by default. 0 is "cr" only.
p_charset IN VARCHAR2 := 'UTF-8', -- META CHARSET encoding string
p_tagl IN VARCHAR2 := '<td>', -- left tag (universal)
p_tagr IN VARCHAR2 := '</td>', -- right tag (universal)
p_tagl_v IN VARCHAR2 := '<td>', -- left tag for text data fields
p_tagl_n IN VARCHAR2 := '<td>', -- left tag for number data fields
p_tagl_d IN VARCHAR2 := '<td>', -- left tag for dates fields
p_text_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping text data
p_number_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping number data
p_date_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping dates
p_date_format IN VARCHAR2 :='DD-MM-YYYY',-- Date format
p_cust_header IN VARCHAR2 := '',
p_cust_footer IN VARCHAR2 := 'Powered by: <b>your_site.com</b>'
)
RETURN CLOB;
FUNCTION file2blob(
p_dir VARCHAR2,
p_file_name VARCHAR2)
RETURN BLOB;
FUNCTION clob2blob (
/* Igor Perkovic, Created 18.7.2017 | Last modified: 21.07.2017
If you want to send any CLOB as attachment through an email function, which does not use the raw format for writting data (and it doesn't hahaha)
then all specific characters like čćžšđ ČĆŽŠĐ would be transfered as cczsd CCZSD...
Now, with this function we will convert this bad, bad CLOB to good and shiny BLOB with DESIRED ENCODING (mic drop!)
Thanks to Udo, https://community.oracle.com/thread/2318795 for this idea...IT WORKS!
*/
in_clob IN CLOB,
in_charset IN VARCHAR2 DEFAULT 'EE8MSWIN1250')
RETURN BLOB;
PROCEDURE clob2file (
v_clob IN CLOB,
v_dir IN VARCHAR2,
v_fname IN VARCHAR2
);
PROCEDURE blob2file(
p_blob IN BLOB,
p_dir IN VARCHAR2,
p_file IN VARCHAR2
);
PROCEDURE query2csv_file(
/*
Igor Perkovic, 10.07.2017.
THE PURPOSE:
This function translates the SQL query to the CSV format and write the result into the CSV file.
OPTIONS:
You can customize the output a bit through the procedure INput parameters:
*/
p_sql IN VARCHAR2,
p_delimiter IN VARCHAR2 :=',',
p_text_quote IN VARCHAR2 :='"',
p_number_quote IN VARCHAR2 := NULL,
p_date_quote IN VARCHAR2 := NULL,
p_date_format IN VARCHAR2 :='RRRR.MM.DD HH24:MI:SS',
p_dir IN VARCHAR2,
p_header_file IN VARCHAR2,
p_data_file IN VARCHAR2 := NULL
);
PROCEDURE ref2csv_file(
/*
Igor Perkovic, 10.07.2017.
THE PURPOSE:
This procedure catches the SYS_REFCURSOR from some outer function and write the result into the CSV file format.
OPTIONS:
You can customize the output a bit through the procedure INput parameters:
*/
p_refcursor IN OUT SYS_REFCURSOR, -- get the sys_refcursor
p_delimiter IN VARCHAR2 :=',', -- Main delimiter
p_text_quote IN VARCHAR2 :='"', -- Quote symbol for wrapping text data
p_number_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping number data
p_date_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping dates
p_date_format IN VARCHAR2 :='RRRR.MM.DD HH24:MI:SS', -- Date format
p_dir IN VARCHAR2, -- DIR alias
p_header_file IN VARCHAR2, -- file name
p_data_file IN VARCHAR2 := NULL
);
PROCEDURE MAIL (
/*
Igor Perkovic, 21. July, 2017.
THE PURPOSE: To send emails with multiple attachments to multiple recipients
SPECIFICATION: This procedure can send up to 3 CLOB + 3 BLOB (overall 6) attachments.
The number of attachment can be easily extended if needed...
--------------------------------------------------------------------------------------------
Change log: 14.08.2017. - Added v_from, smtpHost and smtpPort as input variables and if-then switch,
so I can add another smtp servers and ports
*/
v_from IN VARCHAR2 := 'mail@address.com',
v_pass IN VARCHAR2 := '<password>',
smtpHost IN VARCHAR2 := 'smtp.mailgun.org',
smtpPort IN NUMBER := 587,
p_to IN VARCHAR2, -- recipient(s)
p_cc IN VARCHAR2 DEFAULT NULL, -- recipient(s)
p_bcc IN VARCHAR2 DEFAULT NULL, -- recipient(s)
p_subject IN VARCHAR2, -- First part of the subject
p_text_msg IN VARCHAR2 DEFAULT NULL, -- Plain text message
p_html_msg IN VARCHAR2 DEFAULT NULL, -- HTML message
p_clob_in IN CLOB DEFAULT NULL, -- Any CLOB you want. Either defined as parameter, or passed as a result of some function.
p_charset IN VARCHAR2 :='UTF-8', -- You can change the character set encoding
att_c IN CLOB DEFAULT NULL,
att_c_file IN VARCHAR2 DEFAULT NULL,
att_c_mime IN VARCHAR2 := 'text/html',
att_c2 IN CLOB DEFAULT NULL,
att_c2_file IN VARCHAR2 DEFAULT NULL,
att_c2_mime IN VARCHAR2 := 'text/html',
att_c3 IN CLOB DEFAULT NULL,
att_c3_file IN VARCHAR2 DEFAULT NULL,
att_c3_mime IN VARCHAR2 := 'text/html',
att_c4 IN CLOB DEFAULT NULL,
att_c4_file IN VARCHAR2 DEFAULT NULL,
att_c4_mime IN VARCHAR2 := 'text/html',
att_b IN BLOB DEFAULT NULL,
att_b_file IN VARCHAR2 DEFAULT NULL,
att_b_mime IN VARCHAR2 := 'application/excel',
att_b2 IN BLOB DEFAULT NULL,
att_b2_file IN VARCHAR2 DEFAULT NULL,
att_b2_mime IN VARCHAR2 := 'application/excel',
att_b3 IN BLOB DEFAULT NULL,
att_b3_file IN VARCHAR2 DEFAULT NULL,
att_b3_mime IN VARCHAR2 := 'application/excel'
);
/*
oooooooooooo oooo
`888' `8 `888
888 oooo ooo .oooo. ooo. .oo. .oo. oo.ooooo. 888 .ooooo. .oooo.o
888oooo8 `88b..8P' `P )88b `888P"Y88bP"Y88b 888' `88b 888 d88' `88b d88( "8
888 " Y888' .oP"888 888 888 888 888 888 888 888ooo888 `"Y88b.
888 o .o8"'88b d8( 888 888 888 888 888 888 888 888 .o o. )88b
o888ooooood8 o88' 888o `Y888""8o o888o o888o o888o 888bod8P' o888o `Y8bod8P' 8""888P'
888
o888o
EXAMPLE 1: Send a picture from folder as BLOB attachment through Metronet smtp server
--------------------------------------------------------------------------------------
declare
b blob;
begin
b := trans.file2blob('DIR','Igor.png');
trans.MAIL(
v_from => 'Woofy@mail.hr',
smtpHost => 'smtp.provider.com',
smtpPort => 25,
p_to => 'john_doe@mail.com',
p_subject => 'Try and do not cry',
p_html_msg => '<HTML><head><meta charset="UTF-8"></head> <BODY><P><font face="Segoe UI"> ... your masterpiece... </font></P> </BODY></HTML>',
att_b => b,
att_b_file => 'Igor.png',
att_b_mime => 'image/png'
);
end;
EXAMPLE 2: Mail with HTML report in mail boday
--------------------------------------------------------------------
Prerequisites: as_xlsx
declare
m_clob clob;
begin
m_clob := trans.query2html(
p_sql => 'select * from dept',
p_css => 1,
p_charset => 'Windows-1250');
trans.MAIL(
v_from => 'monitoring@mail.com',
smtpHost => 'smtp.provider.com',
smtpPort => 25,
p_to => 'john_doe@mail.com',
p_subject => 'TRY',
p_clob_in => m_clob,
p_charset => 'Windows-1250'
);
end;
EXAMPLE 3: Multi-attachment and multi-recipients
--------------------------------------------------------------------
Prerequisites: as_xlsx
DECLARE
l_clob CLOB;
m_clob CLOB;
b BLOB;
c BLOB;
catch SYS_REFCURSOR;
fn_cur SYS_REFCURSOR;
fm_cur SYS_REFCURSOR;
BEGIN
catch := monitoring.fn_report_data('heta');
l_clob := trans.ref2csv(
p_refcursor => catch,
p_delimiter => ';',
p_text_quote => '"',
p_date_format => 'YYYY-MM-DD'
);
m_clob := trans.query2html(
p_sql => 'select * from emp',
p_charset => 'Windows-1250',
p_css => 1,
p_date_format => 'DD/MM/RRRR'
);
-- If I want to generate xlsx file
as_xlsx.new_sheet('EMP');
as_xlsx.query2sheet( 'select * from emp', p_sheet => 1 );
as_xlsx.new_sheet('DEPT');
as_xlsx.query2sheet( 'select * from dept', p_sheet => 2 );
-- Get the result blob into variable b for sending through the MAIL procedure
b := as_xlsx.finish;
fn_cur := fn_1(arg);
fm_cur := fn_2(arg);
-- Process the query result
as_xlsx.clear_workbook;
as_xlsx.query2sheet( p_cur => fn_cur, p_sheetname => 'one' );
as_xlsx.query2sheet( p_cur => fm_cur, p_sheetname => 'two' );
c := as_xlsx.finish;
trans.MAIL (
p_to =>'john_doe@mail.com',
p_bcc =>'john_doe_bcc@mail.com',
p_subject => 'Monitoring',
p_clob_in => m_clob,
att_c => l_clob,
att_c_file => 'file1.csv',
att_b => b,
att_b_file => 'file2.xlsx',
att_b2 => c,
att_b2_file => 'file3.xlsx'
);
END;
EXAMPLE 4: Create a CSV file from query
--------------------------------------------------------------------
BEGIN
trans.query2csv_file(
p_sql => 'select * from employee',
p_delimiter => '|',
p_text_quote => '"',
p_number_quote => '',
p_date_quote => '',
p_date_format => 'DD/MM/RRRR',
p_dir => 'DIR',
p_header_file => 'trynow.csv');
END;
EXAMPLE 5: Catch the SYS_REFCURSOR from outer function names_for('New York')
and write the results into the file 'TRY.csv'
DECLARE
catch SYS_REFCURSOR;
BEGIN
catch := names_for('New York');
trans.sysref2csv_file (
p_refcursor => catch,
p_delimiter => ';',
p_text_quote => '"',
p_date_format => 'YYYY-MM-DD',
p_dir => 'DIR',
p_header_file => 'TRY.csv'
);
END;
*/
END;
/
/*
oooooooooo. .oooooo. oooooooooo. oooooo oooo
`888' `Y8b d8P' `Y8b `888' `Y8b `888. .8'
888 888 888 888 888 888 `888. .8'
888oooo888' 888 888 888 888 `888.8'
888 `88b 888 888 888 888 `888'
888 .88P `88b d88' 888 d88' 888
o888bood8P' `Y8bood8P' o888bood8P' o888o
*/
create or replace PACKAGE BODY trans
IS
/*
.oooo.
.dP""Y88b
.ooooo oo oooo oooo .ooooo. oooo d8b oooo ooo ]8P' .ooooo. .oooo.o oooo ooo
d88' `888 `888 `888 d88' `88b `888""8P `88. .8' .d8P' d88' `"Y8 d88( "8 `88. .8'
888 888 888 888 888ooo888 888 `88..8' .dP' 888 `"Y88b. `88..8'
888 888 888 888 888 .o 888 `888' .oP .o 888 .o8 o. )88b `888'
`V8bod888 `V88V"V8P' `Y8bod8P' d888b .8' 8888888888 `Y8bod8P' 8""888P' `8'
888. .o..P'
8P' `Y8P'
"
*/
FUNCTION query2csv(
p_sql IN VARCHAR2, -- SQL query
p_type IN NUMBER := 0, -- '1' for mail, '0' for file is default
p_delimiter IN VARCHAR2 :=';', -- Main delimiter
p_header IN NUMBER := 2,
p_footer IN NUMBER := 0,
p_cust_header IN VARCHAR2 := NULL,
p_cust_footer IN VARCHAR2 := NULL,
p_text_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping text data
p_number_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping number data
p_date_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping dates
p_date_format IN VARCHAR2 :='DD.MM.RRRR') -- Date format
RETURN CLOB
AS
v_finaltxt VARCHAR2(4000);
v_v_val VARCHAR2(4000);
v_n_val NUMBER;
v_d_val DATE;
v_ret NUMBER;
c NUMBER;
d NUMBER;
col_cnt INTEGER;
rec_tab DBMS_SQL.DESC_TAB2;
col_num NUMBER;
crlf VARCHAR2(5) := CHR(13) || CHR(10);
cr VARCHAR2(5) := CHR(13);
v_clob CLOB := EMPTY_CLOB();
BEGIN
/* Query processing */
c := DBMS_SQL.OPEN_CURSOR;
DBMS_SQL.PARSE(c, p_sql, DBMS_SQL.NATIVE);
d := DBMS_SQL.EXECUTE(c);
/* Let's read and describe the columns automatically */
DBMS_SQL.DESCRIBE_COLUMNS2(c, col_cnt, rec_tab);
FOR j in 1..col_cnt
LOOP
CASE rec_tab(j).col_type
/* Text or varchar type */
WHEN 1 THEN DBMS_SQL.DEFINE_COLUMN(c,j,v_v_val,2000);
/* Number type */
WHEN 2 THEN DBMS_SQL.DEFINE_COLUMN(c,j,v_n_val);
/* DAte type */
WHEN 12 THEN DBMS_SQL.DEFINE_COLUMN(c,j,v_d_val);
ELSE
/* Other types */
DBMS_SQL.DEFINE_COLUMN(c,j,v_v_val,2000);
END CASE;
END LOOP;
IF p_header = 1 THEN
/* This part outputs the HEADER */
DBMS_LOB.CreateTemporary( v_clob, true );
FOR j in 1..col_cnt
LOOP
v_finaltxt := ltrim(v_finaltxt||p_delimiter||p_text_quote||rec_tab(j).col_name||p_text_quote,p_delimiter);
END LOOP;
IF p_type = 0 THEN
v_clob := v_finaltxt || cr;
ELSE
v_clob := v_finaltxt || UTL_TCP.crlf;
END IF;
END IF;
IF p_header = 2 THEN
/* This part outputs the CUSTOM HEADER */
IF p_type = 0 THEN
v_clob := p_cust_header || cr;
ELSE
v_clob := p_cust_header || UTL_TCP.crlf;
END IF;
END IF;
/* This part outputs the DATA */
LOOP
v_ret := DBMS_SQL.FETCH_ROWS(c);
EXIT WHEN v_ret = 0;
v_finaltxt := NULL;
FOR j in 1..col_cnt
LOOP
CASE rec_tab(j).col_type
WHEN 1 THEN DBMS_SQL.COLUMN_VALUE(c,j,v_v_val);
v_finaltxt := ltrim(v_finaltxt||p_delimiter||p_text_quote||replace(v_v_val,p_delimiter,'')||p_text_quote,p_delimiter);
WHEN 2 THEN DBMS_SQL.COLUMN_VALUE(c,j,v_n_val);
v_finaltxt := ltrim(v_finaltxt||p_delimiter||p_number_quote||replace(v_n_val,p_delimiter,'.')||p_number_quote,p_delimiter);
WHEN 12 THEN DBMS_SQL.COLUMN_VALUE(c,j,v_d_val);
v_finaltxt := ltrim(v_finaltxt||p_delimiter||p_date_quote||to_char(v_d_val,p_date_format)||p_date_quote,p_delimiter);
ELSE
v_finaltxt := ltrim(v_finaltxt||p_delimiter||p_text_quote||v_v_val||p_text_quote,p_delimiter);
END CASE;
END LOOP;
/* If we will transform this CLOB into the file, then we don't need extra blank line with CR + LF */
IF p_type = 0 THEN
v_clob := v_clob || v_finaltxt || cr;
/* But if we send this CLOB through the mail, we could use it */
ELSE
v_clob := v_clob || v_finaltxt || UTL_TCP.crlf;
END IF;
END LOOP;
IF p_footer = 1 THEN
/* This part outputs the CUSTOM HEADER */
IF p_type = 0 THEN
v_clob := v_clob || p_cust_footer || cr;
ELSE
v_clob := v_clob || p_cust_footer || UTL_TCP.crlf;
END IF;
END IF;
/* Cleaning */
DBMS_SQL.CLOSE_CURSOR(c);
/* The result! */
return v_clob;
/* Some more cleaning */
if DBMS_LOB.IsOpen( v_clob ) = 1 then
DBMS_LOB.FreeTemporary( v_clob );
end if;
END;
/*
.o88o. .oooo.
888 `" .dP""Y88b
oooo d8b .ooooo. o888oo ]8P' .ooooo. .oooo.o oooo ooo
`888""8P d88' `88b 888 .d8P' d88' `"Y8 d88( "8 `88. .8'
888 888ooo888 888 .dP' 888 `"Y88b. `88..8'
888 888 .o 888 .oP .o 888 .o8 o. )88b `888'
d888b `Y8bod8P' o888o 8888888888 `Y8bod8P' 8""888P' `8'
*/
FUNCTION ref2csv(
/*
Igor Perkovic, Created: 11.07.2017. | Last modified: 21.07.2017.
THE PURPOSE:
This function catches the SYS_REFCURSOR from some outer function and transform the function result to the CSV format
and return the result as a CLOB variable.
This way I can pass the CLOB to the P_CLOB2FILE procedure - if I want to save the result as a CSV file, or
I can send the CLOB result via email using procedure MAIL.
OPTIONS:
You can customize the output a bit through the procedure INput parameters:
*/
p_refcursor IN OUT SYS_REFCURSOR, -- get the sys_refcursor
p_type IN NUMBER := 0, -- '1' for mail, '0' for file is default
p_delimiter IN VARCHAR2 :=';', -- Main delimiter
p_header IN NUMBER := 2,
p_footer IN NUMBER := 0,
p_cust_header IN VARCHAR2 := NULL,
p_cust_footer IN VARCHAR2 := NULL,
p_text_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping text data
p_number_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping number data
p_date_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping dates
p_date_format IN VARCHAR2 :='DD.MM.RRRR') -- Date format
RETURN CLOB
AS
v_finaltxt VARCHAR2(4000);
v_v_val VARCHAR2(4000);
v_n_val NUMBER;
v_d_val DATE;
v_ret NUMBER;
c BINARY_INTEGER;
col_cnt BINARY_INTEGER;
rec_tab DBMS_SQL.DESC_TAB2;
col_num NUMBER;
crlf VARCHAR2(5) := CHR(13) || CHR(10);
cr VARCHAR2(5) := CHR(13);
v_clob CLOB := EMPTY_CLOB();
BEGIN
/* Query processing */
c := DBMS_SQL.TO_CURSOR_NUMBER(p_refcursor);
/* Let's read and describe the columns automatically */
DBMS_SQL.DESCRIBE_COLUMNS2(c, col_cnt, rec_tab);
FOR j in 1..col_cnt
LOOP
CASE rec_tab(j).col_type
/* Text or varchar type */
WHEN 1 THEN DBMS_SQL.DEFINE_COLUMN(c,j,v_v_val,2000);
/* Number type */
WHEN 2 THEN DBMS_SQL.DEFINE_COLUMN(c,j,v_n_val);
/* DAte type */
WHEN 12 THEN DBMS_SQL.DEFINE_COLUMN(c,j,v_d_val);
ELSE
/* Other types */
DBMS_SQL.DEFINE_COLUMN(c,j,v_v_val,2000);
END CASE;
END LOOP;
IF p_header = 1 THEN
/* This part outputs the HEADER */
DBMS_LOB.CreateTemporary( v_clob, true );
FOR j in 1..col_cnt
LOOP
v_finaltxt := ltrim(v_finaltxt||p_delimiter||p_text_quote||rec_tab(j).col_name||p_text_quote,p_delimiter);
END LOOP;
IF p_type = 0 THEN
v_clob := v_finaltxt || cr;
ELSE
v_clob := v_finaltxt || UTL_TCP.crlf;
END IF;
END IF;
IF p_header = 2 THEN
/* This part outputs the CUSTOM HEADER */
IF p_type = 0 THEN
v_clob := p_cust_header || cr;
ELSE
v_clob := p_cust_header || UTL_TCP.crlf;
END IF;
END IF;
/* This part outputs the DATA */
LOOP
v_ret := DBMS_SQL.FETCH_ROWS(c);
EXIT WHEN v_ret = 0;
v_finaltxt := NULL;
FOR j in 1..col_cnt
LOOP
CASE rec_tab(j).col_type
WHEN 1 THEN DBMS_SQL.COLUMN_VALUE(c,j,v_v_val);
v_finaltxt := ltrim(v_finaltxt||p_delimiter||p_text_quote||replace(v_v_val,p_delimiter,'')||p_text_quote,p_delimiter);
WHEN 2 THEN DBMS_SQL.COLUMN_VALUE(c,j,v_n_val);
v_finaltxt := ltrim(v_finaltxt||p_delimiter||p_number_quote||replace(v_n_val,p_delimiter,'.')||p_number_quote,p_delimiter);
WHEN 12 THEN DBMS_SQL.COLUMN_VALUE(c,j,v_d_val);
v_finaltxt := ltrim(v_finaltxt||p_delimiter||p_date_quote||to_char(v_d_val,p_date_format)||p_date_quote,p_delimiter);
ELSE
v_finaltxt := ltrim(v_finaltxt||p_delimiter||p_text_quote||v_v_val||p_text_quote,p_delimiter);
END CASE;
END LOOP;
/* If we will transform this CLOB into the file, then we don't need extra blank line with CR + LF */
IF p_type = 0 THEN
v_clob := v_clob || v_finaltxt || cr;
/* But if we send this CLOB through the mail, we could use it */
ELSE
v_clob := v_clob || v_finaltxt || UTL_TCP.crlf;
END IF;
END LOOP;
IF p_footer = 1 THEN
/* This part outputs the CUSTOM HEADER */
IF p_type = 0 THEN
v_clob := v_clob || p_cust_footer || cr;
ELSE
v_clob := v_clob || p_cust_footer || UTL_TCP.crlf;
END IF;
END IF;
/* Cleaning */
DBMS_SQL.CLOSE_CURSOR(c);
/* The result! */
return v_clob;
/* Some more cleaning */
if DBMS_LOB.IsOpen( v_clob ) = 1 then
DBMS_LOB.FreeTemporary( v_clob );
end if;
END;
/*
.oooo. oooo . oooo
.dP""Y88b `888 .o8 `888
.ooooo oo oooo oooo .ooooo. oooo d8b oooo ooo ]8P' 888 .oo. .o888oo ooo. .oo. .oo. 888
d88' `888 `888 `888 d88' `88b `888""8P `88. .8' .d8P' 888P"Y88b 888 `888P"Y88bP"Y88b 888
888 888 888 888 888ooo888 888 `88..8' .dP' 888 888 888 888 888 888 888
888 888 888 888 888 .o 888 `888' .oP .o 888 888 888 . 888 888 888 888
`V8bod888 `V88V"V8P' `Y8bod8P' d888b .8' 8888888888 o888o o888o "888" o888o o888o o888o o888o
888. .o..P'
8P' `Y8P'
"
*/
FUNCTION query2html(
/*
Igor Perkovic, Created: 12.07.2017. | Updated: 21.07.2017.
THE PURPOSE:
This function translates the SQL query to HTML table and return the result as a CLOB variable.
This way I can pass the CLOB to the P_CLOB2FILE procedure - if I want to save the result as a html file, or
I can send the CLOB result via email with the MAIL procedure.
OPTIONS:
You can customize the output a bit through the procedure INput parameters:
*/
p_sql IN VARCHAR2, -- SQL query
p_css IN NUMBER :=0, -- No CSS by default - this is for in-mail sending (clob in mail body embedded).
-- as a side option, this can be used for CSS predefined styles, like 1,2,3, ...
-- but for now, there is only one CSS in code.
p_crlf IN NUMBER :=1, -- "crlf" is set to 1 by default. 0 is "cr" only.
p_charset IN VARCHAR2 := 'UTF-8', -- META CHARSET encoding string
p_tagl IN VARCHAR2 := '<td>', -- left tag (universal)
p_tagr IN VARCHAR2 := '</td>', -- right tag (universal)
p_tagl_v IN VARCHAR2 := '<td>', -- left tag for text data fields
p_tagl_n IN VARCHAR2 := '<td>', -- left tag for number data fields
p_tagl_d IN VARCHAR2 := '<td>', -- left tag for dates fields
p_text_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping text data
p_number_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping number data
p_date_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping dates
p_date_format IN VARCHAR2 :='DD-MM-YYYY',-- Date format
p_cust_header IN VARCHAR2 := '',
p_cust_footer IN VARCHAR2 := 'Powered by: <b>your_site.com</b>'
)
RETURN CLOB
AS
v_finaltxt VARCHAR2(4000);
v_v_val VARCHAR2(4000);
v_n_val NUMBER;
v_d_val DATE;
v_ret NUMBER;
c NUMBER;
d NUMBER;
col_cnt INTEGER;
rec_tab DBMS_SQL.DESC_TAB2;
col_num NUMBER;
crlf VARCHAR2(5) := CHR(13) || CHR(10);
cr VARCHAR2(5) := CHR(13);
v_date VARCHAR2(15) := TO_CHAR(TRUNC(SYSDATE),'YYYY-MM-DD');
v_header CLOB := EMPTY_CLOB();
v_footer CLOB := EMPTY_CLOB();
v_css CLOB := EMPTY_CLOB();
v_clob CLOB := EMPTY_CLOB();
BEGIN
/* Query processing */
c := DBMS_SQL.OPEN_CURSOR;
DBMS_SQL.PARSE(c, p_sql, DBMS_SQL.NATIVE);
d := DBMS_SQL.EXECUTE(c);
/* Let's read and describe the columns automatically */
DBMS_SQL.DESCRIBE_COLUMNS2(c, col_cnt, rec_tab);
FOR j in 1..col_cnt
LOOP
CASE rec_tab(j).col_type
WHEN 1 THEN DBMS_SQL.DEFINE_COLUMN(c,j,v_v_val,2000);
WHEN 2 THEN DBMS_SQL.DEFINE_COLUMN(c,j,v_n_val);
WHEN 12 THEN DBMS_SQL.DEFINE_COLUMN(c,j,v_d_val);
ELSE
DBMS_SQL.DEFINE_COLUMN(c,j,v_v_val,2000);
END CASE;
END LOOP;
-- This part outputs the HEADER
DBMS_LOB.CreateTemporary( v_clob, true );
DBMS_LOB.CreateTemporary( v_header, true );
DBMS_LOB.CreateTemporary( v_footer, true );
FOR j in 1..col_cnt
LOOP
v_finaltxt := ltrim(v_finaltxt||'<th>'||p_text_quote||rec_tab(j).col_name||p_text_quote||'</th>');
END LOOP;
/* If we want some style...
this can be changed to desired style or even change to function argument - if you want to change your style often,
OR you can set some predefined set (presets) here in the function and then call those presets by number from this IN argumnet...*/
IF p_css <> 0 THEN
DBMS_LOB.CreateTemporary( v_css, true );
v_css := '<style type="text/css">
body { font-family: Arial, Helvetica, sans-serif;
font-size:10pt;}
table { empty-cells:show;
border-collapse: collapse;
border:solid 2px #777777;}
td { border:solid 1px #333333;
font-size:10pt; padding:5px;}
th { background:#f9a61a;
border:solid 1px #333333;
font-size:11pt;
padding:5px;
vertical-align:center;
text-align:center;}
dt { font-weight: bold; }
</style>';
SELECT TO_CHAR(TRUNC(SYSDATE),'DD.MM.YYYY') INTO v_date FROM dual;
v_header := '<html> <head><meta charset="'||p_charset||'">'|| v_css ||'</head><body><P><font face="Segoe UI"> Datum: <b>'|| v_date || '</b>'|| p_cust_header || '<br><br>';
v_footer := '</table><br>'||p_cust_footer||'</body></html>';
/* Or style is just not our thing... give me just the vanilla table */
ELSE
v_header := '<table>';
v_footer := '</table>';
END IF;
v_clob := v_header || '<table cellspacing="0" cellpadding="3"><tr>'|| v_finaltxt || '</tr>';
/* This part outputs the DATA */
LOOP
v_ret := DBMS_SQL.FETCH_ROWS(c);
EXIT WHEN v_ret = 0;
v_finaltxt := NULL;
FOR j in 1..col_cnt
LOOP
CASE rec_tab(j).col_type
WHEN 1 THEN DBMS_SQL.COLUMN_VALUE(c,j,v_v_val);
v_finaltxt := ltrim(v_finaltxt||p_tagl_v||p_text_quote||v_v_val||p_text_quote||p_tagr);
WHEN 2 THEN DBMS_SQL.COLUMN_VALUE(c,j,v_n_val);
v_finaltxt := ltrim(v_finaltxt||p_tagl_n||p_number_quote||v_n_val||p_number_quote||p_tagr);
WHEN 12 THEN DBMS_SQL.COLUMN_VALUE(c,j,v_d_val);
v_finaltxt := ltrim(v_finaltxt||p_tagl_d||p_date_quote||to_char(v_d_val,p_date_format)||p_date_quote||p_tagr);
ELSE
v_finaltxt := ltrim(v_finaltxt||p_tagl||p_text_quote||v_v_val||p_text_quote||p_tagr);
END CASE;
END LOOP;
if p_crlf = 1 THEN
v_clob := v_clob || '<tr>' || v_finaltxt || '</tr>'|| crlf;
else
v_clob := v_clob || '<tr>' || v_finaltxt || '</tr>'|| cr;
end if;
END LOOP;
/* Add some footer data if you have it... */
v_clob := v_clob || v_footer;
/* Cleaning...*/
DBMS_SQL.CLOSE_CURSOR(c);
/* THE RESULT!*/
return v_clob;
/*Some more cleaning...*/
IF DBMS_LOB.IsOpen( v_clob ) = 1 THEN DBMS_LOB.FreeTemporary( v_clob ); END IF;
IF DBMS_LOB.IsOpen( v_header ) = 1 THEN DBMS_LOB.FreeTemporary( v_header ); END IF;
IF DBMS_LOB.IsOpen( v_footer ) = 1 THEN DBMS_LOB.FreeTemporary( v_header ); END IF;
IF DBMS_LOB.IsOpen( v_css ) = 1 THEN DBMS_LOB.FreeTemporary( v_css ); END IF;
END;
/*
.o88o. .oooo. oooo . oooo
888 `" .dP""Y88b `888 .o8 `888
oooo d8b .ooooo. o888oo ]8P' 888 .oo. .o888oo ooo. .oo. .oo. 888
`888""8P d88' `88b 888 .d8P' 888P"Y88b 888 `888P"Y88bP"Y88b 888
888 888ooo888 888 .dP' 888 888 888 888 888 888 888
888 888 .o 888 .oP .o 888 888 888 . 888 888 888 888
d888b `Y8bod8P' o888o 8888888888 o888o o888o "888" o888o o888o o888o o888o
*/
FUNCTION ref2html(
/*
Igor Perkovic, Created: 12.07.2017. | Updated: 21.07.2017.
THE PURPOSE:
This function translates the SYS_REF cursor to HTML table and return the result as a CLOB variable.
This way I can pass the CLOB to the P_CLOB2FILE procedure - if I want to save the result as a html file, or
I can send the CLOB result via email..
OPTIONS:
You can customize the output a bit through the procedure INput parameters:
*/
p_refcursor IN OUT SYS_REFCURSOR, -- get the sys_refcursor
p_css IN NUMBER :=0, -- No CSS by default - this is for in-mail sending (clob in mail body embedded).
-- as a side option, this can be used for CSS predefined styles, like 1,2,3, ...
-- but for now, there is only one CSS in code.
p_crlf IN NUMBER :=1, -- "crlf" is set to 1 by default. 0 is "cr" only.
p_charset IN VARCHAR2 := 'UTF-8', -- META CHARSET encoding string
p_tagl IN VARCHAR2 := '<td>', -- left tag (universal)
p_tagr IN VARCHAR2 := '</td>', -- right tag (universal)
p_tagl_v IN VARCHAR2 := '<td>', -- left tag for text data fields
p_tagl_n IN VARCHAR2 := '<td>', -- left tag for number data fields
p_tagl_d IN VARCHAR2 := '<td>', -- left tag for dates fields
p_text_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping text data
p_number_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping number data
p_date_quote IN VARCHAR2 := NULL, -- Quote symbol for wrapping dates
p_date_format IN VARCHAR2 :='DD-MM-YYYY',-- Date format
p_cust_header IN VARCHAR2 := '',
p_cust_footer IN VARCHAR2 := 'Powered by: <b>your_site.com</b>'
)