diff --git a/demos/xlsx_builder_pkg_demo.sql b/demos/xlsx_builder_pkg_demo.sql
index 712cd52..cfd9e99 100755
--- a/demos/xlsx_builder_pkg_demo.sql
+++ b/demos/xlsx_builder_pkg_demo.sql
@@ -1,12 +1,13 @@
-- see http://technology.amis.nl/blog/10995/create-an-excel-file-with-plsql
begin
+ xlsx_builder_pkg.clear_workbook;
xlsx_builder_pkg.new_sheet;
xlsx_builder_pkg.cell( 5, 1, 5 );
xlsx_builder_pkg.cell( 3, 1, 3 );
xlsx_builder_pkg.cell( 2, 2, 45 );
xlsx_builder_pkg.cell( 3, 2, 'Anton Scheffer', p_alignment => xlsx_builder_pkg.get_alignment( p_wraptext => true ) );
- xlsx_builder_pkg.cell( 1, 4, sysdate );
+ xlsx_builder_pkg.cell( 1, 4, sysdate, p_fontId => xlsx_builder_pkg.get_font( 'Calibri', p_rgb => 'FFFF0000' ) );
xlsx_builder_pkg.cell( 2, 4, sysdate, p_numFmtId => xlsx_builder_pkg.get_numFmt( 'dd/mm/yyyy h:mm' ) );
xlsx_builder_pkg.cell( 3, 4, sysdate, p_numFmtId => xlsx_builder_pkg.get_numFmt( xlsx_builder_pkg.orafmt2excel( 'dd/mon/yyyy' ) ) );
xlsx_builder_pkg.cell( 5, 5, 75, p_borderId => xlsx_builder_pkg.get_border( 'double', 'double', 'double', 'double' ) );
@@ -33,5 +34,71 @@ begin
end;
/
+-- Create an Excel file with validation
+begin
+ xlsx_builder_pkg.clear_workbook;
+ xlsx_builder_pkg.new_sheet;
+ xlsx_builder_pkg.cell( 1, 6, 5 );
+ xlsx_builder_pkg.cell( 1, 7, 3 );
+ xlsx_builder_pkg.cell( 1, 8, 7 );
+ xlsx_builder_pkg.new_sheet;
+ xlsx_builder_pkg.cell( 2, 6, 15, p_sheet => 2 );
+ xlsx_builder_pkg.cell( 2, 7, 13, p_sheet => 2 );
+ xlsx_builder_pkg.cell( 2, 8, 17, p_sheet => 2 );
+ xlsx_builder_pkg.list_validation( 6, 3, 1, 6, 1, 8, p_show_error => true, p_sheet => 1 );
+ xlsx_builder_pkg.defined_name( 2, 6, 2, 8, 'Anton', 2 );
+ xlsx_builder_pkg.list_validation
+ ( 6, 1, 'Anton'
+ , p_style => 'information'
+ , p_title => 'valid values are'
+ , p_prompt => '13, 15 and 17'
+ , p_show_error => true
+ , p_error_title => 'Are you sure?'
+ , p_error_txt => 'Valid values are: 13, 15 and 17'
+ , p_sheet => 1 );
+ xlsx_builder_pkg.save( 'MY_DIR', 'my.xlsx' );
+end;
+/
+begin
+ xlsx_builder_pkg.clear_workbook;
+ xlsx_builder_pkg.new_sheet;
+ xlsx_builder_pkg.cell( 1, 6, 5 );
+ xlsx_builder_pkg.cell( 1, 7, 3 );
+ xlsx_builder_pkg.cell( 1, 8, 7 );
+ xlsx_builder_pkg.set_autofilter( 1,1, p_row_start => 5, p_row_end => 8 );
+ xlsx_builder_pkg.new_sheet;
+ xlsx_builder_pkg.cell( 2, 6, 5 );
+ xlsx_builder_pkg.cell( 2, 7, 3 );
+ xlsx_builder_pkg.cell( 2, 8, 7 );
+ xlsx_builder_pkg.set_autofilter( 2,2, p_row_start => 5, p_row_end => 8 );
+ xlsx_builder_pkg.save( 'MY_DIR', 'my.xlsx' );
+end;
+/
+
+-- Create workbook with frozen cells
+begin
+ xlsx_builder_pkg.clear_workbook;
+ xlsx_builder_pkg.new_sheet;
+ for c in 1 .. 10
+ loop
+ xlsx_builder_pkg.cell( c, 1, 'COL' || c );
+ xlsx_builder_pkg.cell( c, 2, 'val' || c );
+ xlsx_builder_pkg.cell( c, 3, c );
+ end loop;
+ xlsx_builder_pkg.freeze_rows( 1 );
+ xlsx_builder_pkg.new_sheet;
+ for r in 1 .. 10
+ loop
+ xlsx_builder_pkg.cell( 1, r, 'ROW' || r );
+ xlsx_builder_pkg.cell( 2, r, 'val' || r );
+ xlsx_builder_pkg.cell( 3, r, r );
+ end loop;
+ xlsx_builder_pkg.freeze_cols( 3 );
+ xlsx_builder_pkg.new_sheet;
+ xlsx_builder_pkg.cell( 3, 3, 'Start freeze' );
+ xlsx_builder_pkg.freeze_pane( 3,3 );
+ xlsx_builder_pkg.save( 'MY_DIR', 'my.xlsx' );
+end;
+/
diff --git a/ora/xlsx_builder_pkg.pkb b/ora/xlsx_builder_pkg.pkb
index ae28410..8f4ad26 100755
--- a/ora/xlsx_builder_pkg.pkb
+++ b/ora/xlsx_builder_pkg.pkb
@@ -1,5 +1,9 @@
CREATE OR REPLACE package body xlsx_builder_pkg
as
+--
+ c_LOCAL_FILE_HEADER constant raw(4) := hextoraw( '504B0304' ); -- Local file header signature
+ c_END_OF_CENTRAL_DIRECTORY constant raw(4) := hextoraw( '504B0506' ); -- End of central directory signature
+--
type tp_XF_fmt is record
( numFmtId pls_integer
, fontId pls_integer
@@ -10,7 +14,6 @@ as
type tp_col_fmts is table of tp_XF_fmt index by pls_integer;
type tp_row_fmts is table of tp_XF_fmt index by pls_integer;
type tp_widths is table of number index by pls_integer;
- type tp_strings is table of varchar2(32767) index by pls_integer;
type tp_cell is record
( value number
, style varchar2(50)
@@ -29,11 +32,11 @@ as
, url varchar2(1000)
);
type tp_hyperlinks is table of tp_hyperlink index by pls_integer;
- subtype tp_author is varchar2(32767);
+ subtype tp_author is varchar2(32767 char);
type tp_authors is table of pls_integer index by tp_author;
authors tp_authors;
type tp_comment is record
- ( text varchar2(32767)
+ ( text varchar2(32767 char)
, author tp_author
, row pls_integer
, column pls_integer
@@ -42,6 +45,21 @@ as
);
type tp_comments is table of tp_comment index by pls_integer;
type tp_mergecells is table of varchar2(21) index by pls_integer;
+ type tp_validation is record
+ ( type varchar2(10)
+ , errorstyle varchar2(32)
+ , showinputmessage boolean
+ , prompt varchar2(32767 char)
+ , title varchar2(32767 char)
+ , error_title varchar2(32767 char)
+ , error_txt varchar2(32767 char)
+ , showerrormessage boolean
+ , formula1 varchar2(32767 char)
+ , formula2 varchar2(32767 char)
+ , allowBlank boolean
+ , sqref varchar2(32767 char)
+ );
+ type tp_validations is table of tp_validation index by pls_integer;
type tp_sheet is record
( rows tp_rows
, widths tp_widths
@@ -54,6 +72,7 @@ as
, row_fmts tp_row_fmts
, comments tp_comments
, mergecells tp_mergecells
+ , validations tp_validations
);
type tp_sheets is table of tp_sheet index by pls_integer;
type tp_numFmt is record
@@ -72,6 +91,7 @@ as
, family pls_integer
, fontsize number
, theme pls_integer
+ , RGB varchar2(8)
, underline boolean
, italic boolean
, bold boolean
@@ -85,15 +105,26 @@ as
);
type tp_borders is table of tp_border index by pls_integer;
type tp_numFmtIndexes is table of pls_integer index by pls_integer;
+ type tp_strings is table of pls_integer index by varchar2(32767 char);
+ type tp_str_ind is table of varchar2(32767 char) index by pls_integer;
+ type tp_defined_name is record
+ ( name varchar2(32767 char)
+ , ref varchar2(32767 char)
+ , sheet pls_integer
+ );
+ type tp_defined_names is table of tp_defined_name index by pls_integer;
type tp_book is record
( sheets tp_sheets
, strings tp_strings
+ , str_ind tp_str_ind
+ , str_cnt pls_integer := 0
, fonts tp_fonts
, fills tp_fills
, borders tp_borders
, numFmts tp_numFmts
, cellXfs tp_cellXfs
, numFmtIndexes tp_numFmtIndexes
+ , defined_names tp_defined_names
);
workbook tp_book;
--
@@ -121,6 +152,13 @@ as
end loop;
utl_file.fclose( t_fh );
end;
+--
+ function raw2num( p_raw raw, p_len integer, p_pos integer )
+ return number
+ is
+ begin
+ return utl_raw.cast_to_binary_integer( utl_raw.substr( p_raw, p_pos, p_len ), utl_raw.little_endian );
+ end;
--
function little_endian( p_big number, p_bytes pls_integer := 4 )
return raw
@@ -128,29 +166,58 @@ as
begin
return utl_raw.substr( utl_raw.cast_from_binary_integer( p_big, utl_raw.little_endian ), 1, p_bytes );
end;
+--
+ function blob2num( p_blob blob, p_len integer, p_pos integer )
+ return number
+ is
+ begin
+ return utl_raw.cast_to_binary_integer( dbms_lob.substr( p_blob, p_len, p_pos ), utl_raw.little_endian );
+ end;
--
procedure add1file
- ( p_zipped_blob in out nocopy blob
+ ( p_zipped_blob in out blob
, p_name varchar2
, p_content blob
)
is
t_now date;
t_blob blob;
+ t_len integer;
t_clen integer;
+ t_crc32 raw(4) := hextoraw( '00000000' );
+ t_compressed boolean := false;
+ t_name raw(32767);
begin
t_now := sysdate;
- t_blob := utl_compress.lz_compress( p_content );
- t_clen := dbms_lob.getlength( t_blob );
+ t_len := nvl( dbms_lob.getlength( p_content ), 0 );
+ if t_len > 0
+ then
+ t_blob := utl_compress.lz_compress( p_content );
+ t_clen := dbms_lob.getlength( t_blob ) - 18;
+ t_compressed := t_clen < t_len;
+ t_crc32 := dbms_lob.substr( t_blob, 4, t_clen + 11 );
+ end if;
+ if not t_compressed
+ then
+ t_clen := t_len;
+ t_blob := p_content;
+ end if;
if p_zipped_blob is null
then
dbms_lob.createtemporary( p_zipped_blob, true );
end if;
+ t_name := utl_i18n.string_to_raw( p_name, 'AL32UTF8' );
dbms_lob.append( p_zipped_blob
- , utl_raw.concat( hextoraw( '504B0304' ) -- Local file header signature
- , hextoraw( '1400' ) -- version 2.0
- , hextoraw( '0000' ) -- no General purpose bits
- , hextoraw( '0800' ) -- deflate
+ , utl_raw.concat( c_LOCAL_FILE_HEADER -- Local file header signature
+ , hextoraw( '1400' ) -- version 2.0
+ , case when t_name = utl_i18n.string_to_raw( p_name, 'US8PC437' )
+ then hextoraw( '0000' ) -- no General purpose bits
+ else hextoraw( '0008' ) -- set Language encoding flag (EFS)
+ end
+ , case when t_compressed
+ then hextoraw( '0800' ) -- deflate
+ else hextoraw( '0000' ) -- stored
+ end
, little_endian( to_number( to_char( t_now, 'ss' ) ) / 2
+ to_number( to_char( t_now, 'mi' ) ) * 32
+ to_number( to_char( t_now, 'hh24' ) ) * 2048
@@ -161,29 +228,38 @@ as
+ ( to_number( to_char( t_now, 'yyyy' ) ) - 1980 ) * 512
, 2
) -- File last modification date
- , dbms_lob.substr( t_blob, 4, t_clen - 7 ) -- CRC-32
- , little_endian( t_clen - 18 ) -- compressed size
- , little_endian( dbms_lob.getlength( p_content ) ) -- uncompressed size
- , little_endian( length( p_name ), 2 ) -- File name length
- , hextoraw( '0000' ) -- Extra field length
- , utl_raw.cast_to_raw( p_name ) -- File name
+ , t_crc32 -- CRC-32
+ , little_endian( t_clen ) -- compressed size
+ , little_endian( t_len ) -- uncompressed size
+ , little_endian( utl_raw.length( t_name ), 2 ) -- File name length
+ , hextoraw( '0000' ) -- Extra field length
+ , t_name -- File name
)
);
- dbms_lob.copy( p_zipped_blob, t_blob, t_clen - 18, dbms_lob.getlength( p_zipped_blob ) + 1, 11 ); -- compressed content
- dbms_lob.freetemporary( t_blob );
+ if t_compressed
+ then
+ dbms_lob.copy( p_zipped_blob, t_blob, t_clen, dbms_lob.getlength( p_zipped_blob ) + 1, 11 ); -- compressed content
+ elsif t_clen > 0
+ then
+ dbms_lob.copy( p_zipped_blob, t_blob, t_clen, dbms_lob.getlength( p_zipped_blob ) + 1, 1 ); -- content
+ end if;
+ if dbms_lob.istemporary( t_blob ) = 1
+ then
+ dbms_lob.freetemporary( t_blob );
+ end if;
end;
--
- procedure finish_zip( p_zipped_blob in out nocopy blob )
+ procedure finish_zip( p_zipped_blob in out blob )
is
t_cnt pls_integer := 0;
t_offs integer;
t_offs_dir_header integer;
t_offs_end_header integer;
- t_comment raw(32767) := utl_raw.cast_to_raw( 'Zip-implementation by Anton Scheffer' );
+ t_comment raw(32767) := utl_raw.cast_to_raw( 'Implementation by Anton Scheffer' );
begin
t_offs_dir_header := dbms_lob.getlength( p_zipped_blob );
- t_offs := dbms_lob.instr( p_zipped_blob, hextoraw( '504B0304' ), 1 );
- while t_offs > 0
+ t_offs := 1;
+ while dbms_lob.substr( p_zipped_blob, utl_raw.length( c_LOCAL_FILE_HEADER ), t_offs ) = c_LOCAL_FILE_HEADER
loop
t_cnt := t_cnt + 1;
dbms_lob.append( p_zipped_blob
@@ -192,26 +268,39 @@ as
, dbms_lob.substr( p_zipped_blob, 26, t_offs + 4 )
, hextoraw( '0000' ) -- File comment length
, hextoraw( '0000' ) -- Disk number where file starts
- , hextoraw( '0100' ) -- Internal file attributes
- , hextoraw( '2000B681' ) -- External file attributes
+ , hextoraw( '0000' ) -- Internal file attributes =>
+ -- 0000 binary file
+ -- 0100 (ascii)text file
+ , case
+ when dbms_lob.substr( p_zipped_blob
+ , 1
+ , t_offs + 30 + blob2num( p_zipped_blob, 2, t_offs + 26 ) - 1
+ ) in ( hextoraw( '2F' ) -- /
+ , hextoraw( '5C' ) -- \
+ )
+ then hextoraw( '10000000' ) -- a directory/folder
+ else hextoraw( '2000B681' ) -- a file
+ end -- External file attributes
, little_endian( t_offs - 1 ) -- Relative offset of local file header
, dbms_lob.substr( p_zipped_blob
- , utl_raw.cast_to_binary_integer( dbms_lob.substr( p_zipped_blob, 2, t_offs + 26 ), utl_raw.little_endian )
+ , blob2num( p_zipped_blob, 2, t_offs + 26 )
, t_offs + 30
) -- File name
)
);
- t_offs := dbms_lob.instr( p_zipped_blob, hextoraw( '504B0304' ), t_offs + 32 );
+ t_offs := t_offs + 30 + blob2num( p_zipped_blob, 4, t_offs + 18 ) -- compressed size
+ + blob2num( p_zipped_blob, 2, t_offs + 26 ) -- File name length
+ + blob2num( p_zipped_blob, 2, t_offs + 28 ); -- Extra field length
end loop;
t_offs_end_header := dbms_lob.getlength( p_zipped_blob );
dbms_lob.append( p_zipped_blob
- , utl_raw.concat( hextoraw( '504B0506' ) -- End of central directory signature
+ , utl_raw.concat( c_END_OF_CENTRAL_DIRECTORY -- End of central directory signature
, hextoraw( '0000' ) -- Number of this disk
, hextoraw( '0000' ) -- Disk where central directory starts
, little_endian( t_cnt, 2 ) -- Number of central directory records on this disk
, little_endian( t_cnt, 2 ) -- Total number of central directory records
, little_endian( t_offs_end_header - t_offs_dir_header ) -- Size of central directory
- , little_endian( t_offs_dir_header ) -- Relative offset of local file header
+ , little_endian( t_offs_dir_header ) -- Offset of start of central directory, relative to start of archive
, little_endian( nvl( utl_raw.length( t_comment ), 0 ), 2 ) -- ZIP file comment length
, t_comment
)
@@ -258,13 +347,16 @@ as
workbook.sheets( s ).row_fmts.delete();
workbook.sheets( s ).comments.delete();
workbook.sheets( s ).mergecells.delete();
+ workbook.sheets( s ).validations.delete();
end loop;
workbook.strings.delete();
+ workbook.str_ind.delete();
workbook.fonts.delete();
workbook.fills.delete();
workbook.borders.delete();
workbook.numFmts.delete();
workbook.cellXfs.delete();
+ workbook.defined_names.delete();
workbook := null;
end;
--
@@ -274,6 +366,10 @@ as
t_ind pls_integer;
begin
workbook.sheets( t_nr ).name := nvl( dbms_xmlgen.convert( translate( p_sheetname, 'a/\[]*:?', 'a' ) ), 'Sheet' || t_nr );
+ if workbook.strings.count() = 0
+ then
+ workbook.str_cnt := 0;
+ end if;
if workbook.fonts.count() = 0
then
t_ind := get_font( 'Calibri' );
@@ -375,6 +471,7 @@ as
, p_underline boolean := false
, p_italic boolean := false
, p_bold boolean := false
+ , p_rgb varchar2 := null -- this is a hex ALPHA Red Green Blue value
)
return pls_integer
is
@@ -391,6 +488,9 @@ as
and workbook.fonts( f ).underline = p_underline
and workbook.fonts( f ).italic = p_italic
and workbook.fonts( f ).bold = p_bold
+ and ( workbook.fonts( f ).rgb = p_rgb
+ or ( workbook.fonts( f ).rgb is null and p_rgb is null )
+ )
)
then
return f;
@@ -405,6 +505,7 @@ as
workbook.fonts( t_ind ).underline := p_underline;
workbook.fonts( t_ind ).italic := p_italic;
workbook.fonts( t_ind ).bold := p_bold;
+ workbook.fonts( t_ind ).rgb := p_rgb;
return t_ind;
end;
--
@@ -548,19 +649,6 @@ as
end if;
return 's="' || t_XfId || '"';
end;
---
- function clean_string (p_string in varchar2)
- return varchar2
- is
- invalid_ascii constant varchar2(32) :=
- chr(00)||chr(01)||chr(02)||chr(03)||chr(04)||chr(05)||chr(06)||chr(07)||
- chr(08)|| chr(11)||chr(12)|| chr(14)||chr(15)||
- chr(16)||chr(17)||chr(18)||chr(19)||chr(20)||chr(21)||chr(22)||chr(23)||
- chr(24)||chr(25)||chr(26)||chr(27)||chr(28)||chr(29)||chr(30)||chr(31)
- ;
- begin
- return translate(translate( p_string, invalid_ascii, chr(1)), chr(0)||chr(1), ' ');
- end;
--
procedure cell
( p_col pls_integer
@@ -580,6 +668,23 @@ as
workbook.sheets( t_sheet ).rows( p_row )( p_col ).style := null;
workbook.sheets( t_sheet ).rows( p_row )( p_col ).style := get_XfId( t_sheet, p_col, p_row, p_numFmtId, p_fontId, p_fillId, p_borderId, p_alignment );
end;
+--
+ function add_string( p_string varchar2 )
+ return pls_integer
+ is
+ t_cnt pls_integer;
+ begin
+ if workbook.strings.exists( p_string )
+ then
+ t_cnt := workbook.strings( p_string );
+ else
+ t_cnt := workbook.strings.count();
+ workbook.str_ind( t_cnt ) := p_string;
+ workbook.strings( nvl( p_string, '' ) ) := t_cnt;
+ end if;
+ workbook.str_cnt := workbook.str_cnt + 1;
+ return t_cnt;
+ end;
--
procedure cell
( p_col pls_integer
@@ -596,8 +701,7 @@ as
t_sheet pls_integer := nvl( p_sheet, workbook.sheets.count() );
t_alignment tp_alignment := p_alignment;
begin
- workbook.sheets( t_sheet ).rows( p_row )( p_col ).value := workbook.strings.count();
- workbook.strings( workbook.strings.count() ) := clean_string( p_value );
+ workbook.sheets( t_sheet ).rows( p_row )( p_col ).value := add_string( p_value );
if t_alignment.wrapText is null and instr( p_value, chr(13) ) > 0
then
t_alignment.wrapText := true;
@@ -645,8 +749,7 @@ as
t_ind pls_integer;
t_sheet pls_integer := nvl( p_sheet, workbook.sheets.count() );
begin
- workbook.sheets( t_sheet ).rows( p_row )( p_col ).value := workbook.strings.count();
- workbook.strings( workbook.strings.count() ) := clean_string( nvl( p_value, p_url ) );
+ workbook.sheets( t_sheet ).rows( p_row )( p_col ).value := add_string( nvl( p_value, p_url ) );
workbook.sheets( t_sheet ).rows( p_row )( p_col ).style := 't="s" ' || get_XfId( t_sheet, p_col, p_row, '', get_font( 'Calibri', p_theme => 10, p_underline => true ) );
t_ind := workbook.sheets( t_sheet ).hyperlinks.count() + 1;
workbook.sheets( t_sheet ).hyperlinks( t_ind ).cell := alfan_col( p_col ) || p_row;
@@ -689,6 +792,111 @@ as
t_ind := workbook.sheets( t_sheet ).mergecells.count() + 1;
workbook.sheets( t_sheet ).mergecells( t_ind ) := alfan_col( p_tl_col ) || p_tl_row || ':' || alfan_col( p_br_col ) || p_br_row;
end;
+--
+ procedure add_validation
+ ( p_type varchar2
+ , p_sqref varchar2
+ , p_style varchar2 := 'stop' -- stop, warning, information
+ , p_formula1 varchar2 := null
+ , p_formula2 varchar2 := null
+ , p_title varchar2 := null
+ , p_prompt varchar := null
+ , p_show_error boolean := false
+ , p_error_title varchar2 := null
+ , p_error_txt varchar2 := null
+ , p_sheet pls_integer := null
+ )
+ is
+ t_ind pls_integer;
+ t_sheet pls_integer := nvl( p_sheet, workbook.sheets.count() );
+ begin
+ t_ind := workbook.sheets( t_sheet ).validations.count() + 1;
+ workbook.sheets( t_sheet ).validations( t_ind ).type := p_type;
+ workbook.sheets( t_sheet ).validations( t_ind ).errorstyle := p_style;
+ workbook.sheets( t_sheet ).validations( t_ind ).sqref := p_sqref;
+ workbook.sheets( t_sheet ).validations( t_ind ).formula1 := p_formula1;
+ workbook.sheets( t_sheet ).validations( t_ind ).error_title := p_error_title;
+ workbook.sheets( t_sheet ).validations( t_ind ).error_txt := p_error_txt;
+ workbook.sheets( t_sheet ).validations( t_ind ).title := p_title;
+ workbook.sheets( t_sheet ).validations( t_ind ).prompt := p_prompt;
+ workbook.sheets( t_sheet ).validations( t_ind ).showerrormessage := p_show_error;
+ end;
+--
+ procedure list_validation
+ ( p_sqref_col pls_integer
+ , p_sqref_row pls_integer
+ , p_tl_col pls_integer -- top left
+ , p_tl_row pls_integer
+ , p_br_col pls_integer -- bottom right
+ , p_br_row pls_integer
+ , p_style varchar2 := 'stop' -- stop, warning, information
+ , p_title varchar2 := null
+ , p_prompt varchar := null
+ , p_show_error boolean := false
+ , p_error_title varchar2 := null
+ , p_error_txt varchar2 := null
+ , p_sheet pls_integer := null
+ )
+ is
+ begin
+ add_validation( 'list'
+ , alfan_col( p_sqref_col ) || p_sqref_row
+ , p_style => lower( p_style )
+ , p_formula1 => '$' || alfan_col( p_tl_col ) || '$' || p_tl_row || ':$' || alfan_col( p_br_col ) || '$' || p_br_row
+ , p_title => p_title
+ , p_prompt => p_prompt
+ , p_show_error => p_show_error
+ , p_error_title => p_error_title
+ , p_error_txt => p_error_txt
+ , p_sheet => p_sheet
+ );
+ end;
+--
+ procedure list_validation
+ ( p_sqref_col pls_integer
+ , p_sqref_row pls_integer
+ , p_defined_name varchar2
+ , p_style varchar2 := 'stop' -- stop, warning, information
+ , p_title varchar2 := null
+ , p_prompt varchar := null
+ , p_show_error boolean := false
+ , p_error_title varchar2 := null
+ , p_error_txt varchar2 := null
+ , p_sheet pls_integer := null
+ )
+ is
+ begin
+ add_validation( 'list'
+ , alfan_col( p_sqref_col ) || p_sqref_row
+ , p_style => lower( p_style )
+ , p_formula1 => p_defined_name
+ , p_title => p_title
+ , p_prompt => p_prompt
+ , p_show_error => p_show_error
+ , p_error_title => p_error_title
+ , p_error_txt => p_error_txt
+ , p_sheet => p_sheet
+ );
+ end;
+--
+ procedure defined_name
+ ( p_tl_col pls_integer -- top left
+ , p_tl_row pls_integer
+ , p_br_col pls_integer -- bottom right
+ , p_br_row pls_integer
+ , p_name varchar2
+ , p_sheet pls_integer := null
+ , p_localsheet pls_integer := null
+ )
+ is
+ t_ind pls_integer;
+ t_sheet pls_integer := nvl( p_sheet, workbook.sheets.count() );
+ begin
+ t_ind := workbook.defined_names.count() + 1;
+ workbook.defined_names( t_ind ).name := p_name;
+ workbook.defined_names( t_ind ).ref := 'Sheet' || t_sheet || '!$' || alfan_col( p_tl_col ) || '$' || p_tl_row || ':$' || alfan_col( p_br_col ) || '$' || p_br_row;
+ workbook.defined_names( t_ind ).sheet := p_localsheet;
+ end;
--
procedure set_column_width
( p_col pls_integer
@@ -743,8 +951,10 @@ as
, p_sheet pls_integer := null
)
is
+ t_sheet pls_integer := nvl( p_sheet, workbook.sheets.count() );
begin
- workbook.sheets( nvl( p_sheet, workbook.sheets.count() ) ).freeze_rows := p_nr_rows;
+ workbook.sheets( t_sheet ).freeze_cols := null;
+ workbook.sheets( t_sheet ).freeze_rows := p_nr_rows;
end;
--
procedure freeze_cols
@@ -752,8 +962,22 @@ as
, p_sheet pls_integer := null
)
is
+ t_sheet pls_integer := nvl( p_sheet, workbook.sheets.count() );
begin
- workbook.sheets( nvl( p_sheet, workbook.sheets.count() ) ).freeze_cols := p_nr_cols;
+ workbook.sheets( t_sheet ).freeze_rows := null;
+ workbook.sheets( t_sheet ).freeze_cols := p_nr_cols;
+ end;
+--
+ procedure freeze_pane
+ ( p_col pls_integer
+ , p_row pls_integer
+ , p_sheet pls_integer := null
+ )
+ is
+ t_sheet pls_integer := nvl( p_sheet, workbook.sheets.count() );
+ begin
+ workbook.sheets( t_sheet ).freeze_rows := p_row;
+ workbook.sheets( t_sheet ).freeze_cols := p_col;
end;
--
procedure set_autofilter
@@ -767,52 +991,88 @@ as
t_ind pls_integer;
t_sheet pls_integer := nvl( p_sheet, workbook.sheets.count() );
begin
- t_ind := workbook.sheets( t_sheet ).autofilters.count() + 1;
+ t_ind := 1;
workbook.sheets( t_sheet ).autofilters( t_ind ).column_start := p_column_start;
workbook.sheets( t_sheet ).autofilters( t_ind ).column_end := p_column_end;
workbook.sheets( t_sheet ).autofilters( t_ind ).row_start := p_row_start;
workbook.sheets( t_sheet ).autofilters( t_ind ).row_end := p_row_end;
+ defined_name
+ ( p_column_start
+ , p_row_start
+ , p_column_end
+ , p_row_end
+ , '_xlnm._FilterDatabase'
+ , t_sheet
+ , t_sheet - 1
+ );
end;
--
- procedure add1xml
- ( p_excel in out nocopy blob
- , p_filename varchar2
- , p_xml clob
- )
- is
+/*
+ procedure add1xml
+ ( p_excel in out nocopy blob
+ , p_filename varchar2
+ , p_xml clob
+ )
+ is
t_tmp blob;
- l_count binary_integer;
- begin
+ c_step constant number := 24396;
+ begin
dbms_lob.createtemporary( t_tmp, true );
- l_count := trunc( length( p_xml ) / 4000 );
-
- if mod( length( p_xml ), 4000 ) = 0 then
- l_count := greatest(l_count - 1, 0);
- end if;
-
- for i in 0 .. l_count
- loop
- dbms_lob.append( t_tmp, utl_i18n.string_to_raw( substr( p_xml, i * 4000 + 1, 4000 ), 'AL32UTF8') );
- end loop;
- add1file( p_excel, p_filename, t_tmp );
- dbms_lob.freetemporary( t_tmp );
- end;
+ for i in 0 .. trunc( length( p_xml ) / c_step )
+ loop
+ dbms_lob.append( t_tmp, utl_i18n.string_to_raw( substr( p_xml, i * c_step + 1, c_step ), 'AL32UTF8' ) );
+ end loop;
+ add1file( p_excel, p_filename, t_tmp );
+ dbms_lob.freetemporary( t_tmp );
+ end;
+*/
+--
+ procedure add1xml
+ ( p_excel in out nocopy blob
+ , p_filename varchar2
+ , p_xml clob
+ )
+ is
+ t_tmp blob;
+ dest_offset integer := 1;
+ src_offset integer := 1;
+ lang_context integer;
+ warning integer;
+ begin
+ lang_context := dbms_lob.DEFAULT_LANG_CTX;
+ dbms_lob.createtemporary( t_tmp, true );
+ dbms_lob.converttoblob
+ ( t_tmp
+ , p_xml
+ , dbms_lob.lobmaxsize
+ , dest_offset
+ , src_offset
+ , nls_charset_id( 'AL32UTF8' )
+ , lang_context
+ , warning
+ );
+ add1file( p_excel, p_filename, t_tmp );
+ dbms_lob.freetemporary( t_tmp );
+ end;
--
function finish
return blob
is
t_excel blob;
t_xxx clob;
- t_tmp clob;
+ t_tmp varchar2(32767 char);
+ t_str varchar2(32767 char);
t_c number;
t_h number;
t_w number;
t_cw number;
- t_cell varchar2(1000);
+ t_cell varchar2(1000 char);
t_row_ind pls_integer;
t_col_min pls_integer;
t_col_max pls_integer;
t_col_ind pls_integer;
+ t_len pls_integer;
+ts timestamp := systimestamp;
begin
dbms_lob.createtemporary( t_excel, true );
t_xxx := '
@@ -907,10 +1167,13 @@ as
case when workbook.fonts( f ).italic then '' end ||
case when workbook.fonts( f ).underline then '' end ||
'
-
+
-
+
';
end loop;
t_xxx := t_xxx || '
@@ -979,10 +1242,20 @@ as
t_xxx := t_xxx || '
';
end loop;
- t_xxx := t_xxx || '
-
-
-';
+ t_xxx := t_xxx || '';
+ if workbook.defined_names.count() > 0
+ then
+ t_xxx := t_xxx || '';
+ for s in 1 .. workbook.defined_names.count()
+ loop
+ t_xxx := t_xxx || '
+' || workbook.defined_names( s ).ref || '';
+ end loop;
+ t_xxx := t_xxx || '';
+ end if;
+ t_xxx := t_xxx || '';
add1xml( t_excel, 'xl/workbook.xml', t_xxx );
t_xxx := '
@@ -1284,13 +1557,22 @@ as
';
- if workbook.sheets( s ).freeze_rows > 0
+ if workbook.sheets( s ).freeze_rows > 0 and workbook.sheets( s ).freeze_cols > 0
then
- t_xxx := t_xxx || '';
- end if;
- if workbook.sheets( s ).freeze_cols > 0
- then
- t_xxx := t_xxx || '';
+ t_xxx := t_xxx || ( ''
+ );
+ else
+ if workbook.sheets( s ).freeze_rows > 0
+ then
+ t_xxx := t_xxx || '';
+ end if;
+ if workbook.sheets( s ).freeze_cols > 0
+ then
+ t_xxx := t_xxx || '';
+ end if;
end if;
t_xxx := t_xxx || '
@@ -1302,7 +1584,7 @@ as
while t_col_ind is not null
loop
t_xxx := t_xxx ||
- '';
+ '';
t_col_ind := workbook.sheets( s ).widths.next( t_col_ind );
end loop;
t_xxx := t_xxx || '';
@@ -1313,26 +1595,31 @@ as
while t_row_ind is not null
loop
t_tmp := t_tmp || '';
+ t_len := length( t_tmp );
t_col_ind := workbook.sheets( s ).rows( t_row_ind ).first();
while t_col_ind is not null
loop
- t_cell := '';
- t_cell := t_cell || to_char( workbook.sheets( s ).rows( t_row_ind )( t_col_ind ).value, 'TM9', 'NLS_NUMERIC_CHARACTERS=.,' );
- t_cell := t_cell || '';
+ t_cell := ''
+ || to_char( workbook.sheets( s ).rows( t_row_ind )( t_col_ind ).value, 'TM9', 'NLS_NUMERIC_CHARACTERS=.,' )
+ || '';
+ if t_len > 32000
+ then
+ dbms_lob.writeappend( t_xxx, t_len, t_tmp );
+ t_tmp := null;
+ t_len := 0;
+ end if;
t_tmp := t_tmp || t_cell;
+ t_len := t_len + length( t_cell );
t_col_ind := workbook.sheets( s ).rows( t_row_ind ).next( t_col_ind );
end loop;
t_tmp := t_tmp || '
';
- if length( t_tmp ) > 8000
- then
- t_xxx := t_xxx || t_tmp;
- t_tmp := null;
- end if;
t_row_ind := workbook.sheets( s ).rows.next( t_row_ind );
end loop;
- t_xxx := t_xxx || t_tmp || '';
+ t_tmp := t_tmp || '';
+ t_len := length( t_tmp );
+ dbms_lob.writeappend( t_xxx, t_len, t_tmp );
for a in 1 .. workbook.sheets( s ).autofilters.count()
loop
t_xxx := t_xxx || '';
+ for m in 1 .. workbook.sheets( s ).validations.count()
+ loop
+ t_xxx := t_xxx || '';
+ if workbook.sheets( s ).validations( m ).formula1 is not null
+ then
+ t_xxx := t_xxx || '' || workbook.sheets( s ).validations( m ).formula1 || '';
+ end if;
+ if workbook.sheets( s ).validations( m ).formula2 is not null
+ then
+ t_xxx := t_xxx || '' || workbook.sheets( s ).validations( m ).formula2 || '';
+ end if;
+ t_xxx := t_xxx || '';
+ end loop;
+ t_xxx := t_xxx || '';
+ end if;
+--
if workbook.sheets( s ).hyperlinks.count() > 0
then
t_xxx := t_xxx || '';
@@ -1364,6 +1696,7 @@ as
then
t_xxx := t_xxx || '';
end if;
+--
t_xxx := t_xxx || '';
add1xml( t_excel, 'xl/worksheets/sheet' || s || '.xml', t_xxx );
if workbook.sheets( s ).hyperlinks.count() > 0 or workbook.sheets( s ).comments.count() > 0
@@ -1476,16 +1809,17 @@ style="position:absolute;margin-left:35.25pt;margin-top:3pt;z-index:' || to_char
t_xxx := t_xxx || '';
add1xml( t_excel, 'xl/_rels/workbook.xml.rels', t_xxx );
t_xxx := '
-';
+';
t_tmp := null;
- for i in 0 .. workbook.strings.count() - 1
+ for i in 0 .. workbook.str_ind.count() - 1
loop
- t_tmp := t_tmp || '' || dbms_xmlgen.convert( substr( workbook.strings( i ), 1, 32000 ) ) || '';
- if length( t_tmp ) > 8000
+ t_str := '' || dbms_xmlgen.convert( substr( workbook.str_ind( i ), 1, 32000 ) ) || '';
+ if length( t_tmp ) + length( t_str ) > 32000
then
t_xxx := t_xxx || t_tmp;
t_tmp := null;
end if;
+ t_tmp := t_tmp || t_str;
end loop;
t_xxx := t_xxx || t_tmp || '';
add1xml( t_excel, 'xl/sharedStrings.xml', t_xxx );
@@ -1567,7 +1901,10 @@ style="position:absolute;margin-left:35.25pt;margin-top:3pt;z-index:' || to_char
dbms_sql.column_value( t_c, c, n_tab );
for i in 0 .. t_r - 1
loop
- cell( c, t_cur_row + i, n_tab( i + n_tab.first() ), p_sheet => t_sheet );
+ if n_tab( i + n_tab.first() ) is not null
+ then
+ cell( c, t_cur_row + i, n_tab( i + n_tab.first() ), p_sheet => t_sheet );
+ end if;
end loop;
n_tab.delete;
when t_desc_tab( c ).col_type in ( 12, 178, 179, 180, 181 , 231 )
@@ -1575,7 +1912,10 @@ style="position:absolute;margin-left:35.25pt;margin-top:3pt;z-index:' || to_char
dbms_sql.column_value( t_c, c, d_tab );
for i in 0 .. t_r - 1
loop
- cell( c, t_cur_row + i, d_tab( i + d_tab.first() ), p_sheet => t_sheet );
+ if d_tab( i + d_tab.first() ) is not null
+ then
+ cell( c, t_cur_row + i, d_tab( i + d_tab.first() ), p_sheet => t_sheet );
+ end if;
end loop;
d_tab.delete;
when t_desc_tab( c ).col_type in ( 1, 8, 9, 96, 112 )
@@ -1583,7 +1923,10 @@ style="position:absolute;margin-left:35.25pt;margin-top:3pt;z-index:' || to_char
dbms_sql.column_value( t_c, c, v_tab );
for i in 0 .. t_r - 1
loop
- cell( c, t_cur_row + i, v_tab( i + v_tab.first() ), p_sheet => t_sheet );
+ if v_tab( i + v_tab.first() ) is not null
+ then
+ cell( c, t_cur_row + i, v_tab( i + v_tab.first() ), p_sheet => t_sheet );
+ end if;
end loop;
v_tab.delete;
else
diff --git a/ora/xlsx_builder_pkg.pks b/ora/xlsx_builder_pkg.pks
index 97c805c..67f922e 100755
--- a/ora/xlsx_builder_pkg.pks
+++ b/ora/xlsx_builder_pkg.pks
@@ -6,6 +6,7 @@ as
** Date: 19-02-2011
** Website: http://technology.amis.nl/blog
** See also: http://technology.amis.nl/blog/?p=10995
+** See also: https://technology.amis.nl/2011/02/19/create-an-excel-file-with-plsql/
**
** Changelog:
** Date: 21-02-2011
@@ -18,7 +19,43 @@ as
** Fixed issue with timezone's set to a region(name) instead of a offset
** Date: 08-04-2011
** Fixed issue with XML-escaping from text
+** Date: 27-05-2011
+** Added MIT-license
+** Date: 11-08-2011
+** Fixed NLS-issue with column width
+** Date: 29-09-2011
+** Added font color
+** Date: 16-10-2011
+** fixed bug in add_string
+** Date: 26-04-2012
+** Fixed set_autofilter (only one autofilter per sheet, added _xlnm._FilterDatabase)
+** Added list_validation = drop-down
+** Date: 27-08-2013
+** Added freeze_pane
**
+******************************************************************************
+******************************************************************************
+Copyright (C) 2011, 2012 by Anton Scheffer
+
+Permission is hereby granted, free of charge, to any person obtaining a copy
+of this software and associated documentation files (the "Software"), to deal
+in the Software without restriction, including without limitation the rights
+to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
+copies of the Software, and to permit persons to whom the Software is
+furnished to do so, subject to the following conditions:
+
+The above copyright notice and this permission notice shall be included in
+all copies or substantial portions of the Software.
+
+THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
+IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
+FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
+AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
+LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
+OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN
+THE SOFTWARE.
+
+******************************************************************************
******************************************** */
--
type tp_alignment is record
@@ -45,6 +82,7 @@ as
, p_underline boolean := false
, p_italic boolean := false
, p_bold boolean := false
+ , p_rgb varchar2 := null -- this is a hex ALPHA Red Green Blue value
)
return pls_integer;
--
@@ -163,6 +201,45 @@ top
, p_br_row pls_integer
, p_sheet pls_integer := null
);
+--
+ procedure list_validation
+ ( p_sqref_col pls_integer
+ , p_sqref_row pls_integer
+ , p_tl_col pls_integer -- top left
+ , p_tl_row pls_integer
+ , p_br_col pls_integer -- bottom right
+ , p_br_row pls_integer
+ , p_style varchar2 := 'stop' -- stop, warning, information
+ , p_title varchar2 := null
+ , p_prompt varchar := null
+ , p_show_error boolean := false
+ , p_error_title varchar2 := null
+ , p_error_txt varchar2 := null
+ , p_sheet pls_integer := null
+ );
+--
+ procedure list_validation
+ ( p_sqref_col pls_integer
+ , p_sqref_row pls_integer
+ , p_defined_name varchar2
+ , p_style varchar2 := 'stop' -- stop, warning, information
+ , p_title varchar2 := null
+ , p_prompt varchar := null
+ , p_show_error boolean := false
+ , p_error_title varchar2 := null
+ , p_error_txt varchar2 := null
+ , p_sheet pls_integer := null
+ );
+--
+ procedure defined_name
+ ( p_tl_col pls_integer -- top left
+ , p_tl_row pls_integer
+ , p_br_col pls_integer -- bottom right
+ , p_br_row pls_integer
+ , p_name varchar2
+ , p_sheet pls_integer := null
+ , p_localsheet pls_integer := null
+ );
--
procedure set_column_width
( p_col pls_integer
@@ -199,6 +276,12 @@ top
( p_nr_cols pls_integer := 1
, p_sheet pls_integer := null
);
+--
+ procedure freeze_pane
+ ( p_col pls_integer
+ , p_row pls_integer
+ , p_sheet pls_integer := null
+ );
--
procedure set_autofilter
( p_column_start pls_integer := null
@@ -223,8 +306,5 @@ top
, p_filename varchar2 := null
, p_sheet pls_integer := null
);
---
-
-end xlsx_builder_pkg;
+end;
/
-
diff --git a/setup/grants.sql b/setup/grants.sql
index 0edbaa8..694d05b 100755
--- a/setup/grants.sql
+++ b/setup/grants.sql
@@ -4,3 +4,5 @@
-- required for NTLM utilities
grant execute on dbms_crypto to &&your_schema;
+-- Required for XLSX_BUILDER_PKG
+grant execute on sys.utl_file to &&your_schema;