├── lib └── xlsx_builder │ ├── lib │ ├── install.sql │ ├── README.md │ ├── zip_util_pkg.pks │ └── zip_util_pkg.pkb │ ├── install.sql │ ├── install_full.sql │ ├── README.md │ ├── LICENSE.md │ └── xlsx_builder_pkg.pks ├── setup ├── install_all.sql ├── install_libs.sql └── install_main.sql ├── .gitattributes ├── License.md ├── README.md ├── .gitignore └── ora ├── apexir_xlsx_pkg.pks ├── apexir_xlsx_types_pkg.pks └── apexir_xlsx_pkg.pkb /lib/xlsx_builder/lib/install.sql: -------------------------------------------------------------------------------- 1 | Rem Install ZIP_UTIL_PKG 2 | 3 | @@zip_util_pkg.pks 4 | @@zip_util_pkg.pkb -------------------------------------------------------------------------------- /lib/xlsx_builder/lib/README.md: -------------------------------------------------------------------------------- 1 | zip_util 2 | ======== 3 | 4 | A PL/SQL Package to work with zipped files. 5 | -------------------------------------------------------------------------------- /setup/install_all.sql: -------------------------------------------------------------------------------- 1 | Rem Full installation 2 | SET define OFF 3 | 4 | @@install_libs.sql 5 | @@install_main.sql -------------------------------------------------------------------------------- /lib/xlsx_builder/install.sql: -------------------------------------------------------------------------------- 1 | Rem Install XLSX_BUILDER_PKG 2 | 3 | @@xlsx_builder_pkg.pks 4 | @@xlsx_builder_pkg.pkb -------------------------------------------------------------------------------- /setup/install_libs.sql: -------------------------------------------------------------------------------- 1 | Rem Install referenced libraries 2 | 3 | @@../lib/xlsx_builder/lib/install.sql 4 | @@../lib/xlsx_builder/install.sql -------------------------------------------------------------------------------- /setup/install_main.sql: -------------------------------------------------------------------------------- 1 | Rem Install the main package 2 | 3 | @@../ora/apexir_xlsx_types_pkg.pks 4 | @@../ora/apexir_xlsx_pkg.pks 5 | @@../ora/apexir_xlsx_pkg.pkb -------------------------------------------------------------------------------- /lib/xlsx_builder/install_full.sql: -------------------------------------------------------------------------------- 1 | REM Installing XLSX Builder including ZIP_UTIL 2 | 3 | PROMPT ZIP_UTIL Library 4 | PROMPT ================ 5 | @lib/install.sql 6 | 7 | PROMPT XLSX_BUILDER Package 8 | PROMPT ==================== 9 | @@install.sql 10 | -------------------------------------------------------------------------------- /lib/xlsx_builder/README.md: -------------------------------------------------------------------------------- 1 | # XLSX_BUILDER_PKG 2 | A PL/SQL Package to create OOXML workbooks. 3 | This package is based on work done by Anton Scheffer. 4 | It also includes additions to support my own package [APEXIR_XLSX_PKG](https://github.com/commi235/APEX_IR_XLSX) 5 | 6 | ## Installation 7 | ### Single Script 8 | 1. Install ZIP_UTIL_PKG and XLSX_BUILDER_PKG by running install_full.sql script. 9 | 10 | ### One by One 11 | 1. Install the ZIP_UTIL_PKG from the lib folder. 12 | 2. Install XLSX_BUILDER_PKG by running install.sql 13 | -------------------------------------------------------------------------------- /.gitattributes: -------------------------------------------------------------------------------- 1 | # Auto detect text files and perform LF normalization 2 | * text=auto 3 | 4 | # Custom for Visual Studio 5 | *.cs diff=csharp 6 | *.sln merge=union 7 | *.csproj merge=union 8 | *.vbproj merge=union 9 | *.fsproj merge=union 10 | *.dbproj merge=union 11 | 12 | # Standard to msysgit 13 | *.doc diff=astextplain 14 | *.DOC diff=astextplain 15 | *.docx diff=astextplain 16 | *.DOCX diff=astextplain 17 | *.dot diff=astextplain 18 | *.DOT diff=astextplain 19 | *.pdf diff=astextplain 20 | *.PDF diff=astextplain 21 | *.rtf diff=astextplain 22 | *.RTF diff=astextplain 23 | -------------------------------------------------------------------------------- /lib/xlsx_builder/LICENSE.md: -------------------------------------------------------------------------------- 1 | Copyright (C) 2011, 2012 by Anton Scheffer 2 | 3 | Permission is hereby granted, free of charge, to any person obtaining a copy 4 | of this software and associated documentation files (the "Software"), to deal 5 | in the Software without restriction, including without limitation the rights 6 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 7 | copies of the Software, and to permit persons to whom the Software is 8 | furnished to do so, subject to the following conditions: 9 | 10 | The above copyright notice and this permission notice shall be included in 11 | all copies or substantial portions of the Software. 12 | 13 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 14 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 15 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 16 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 17 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 18 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN 19 | THE SOFTWARE. 20 | -------------------------------------------------------------------------------- /License.md: -------------------------------------------------------------------------------- 1 | This license applies to all source code and examples in this software distribution, 2 | UNLESS a specific file contains a different license, copyright notice, or attribution to another author. 3 | 4 | ============= 5 | 6 | The APEX IR XLSX Download Library is released as open source under the BSD license: 7 | http://www.opensource.org/licenses/bsd-license.php 8 | 9 | 10 | Copyright (c) 2014, Moritz Klein (http://mk-commi.blogspot.de) 11 | All rights reserved. 12 | 13 | Redistribution and use in source and binary forms, with or without 14 | modification, are permitted provided that the following conditions are met: 15 | 16 | * Redistributions of source code must retain the above copyright notice, this 17 | list of conditions and the following disclaimer. 18 | 19 | * Redistributions in binary form must reproduce the above copyright notice, 20 | this list of conditions and the following disclaimer in the documentation 21 | and/or other materials provided with the distribution. 22 | 23 | * Neither the name of the copyright holder nor the names of its contributors 24 | may be used to endorse or promote products derived from this software 25 | without specific prior written permission. 26 | 27 | THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" 28 | AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE 29 | IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE 30 | DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE 31 | FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL 32 | DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR 33 | SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER 34 | CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, 35 | OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE 36 | OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 37 | -------------------------------------------------------------------------------- /lib/xlsx_builder/lib/zip_util_pkg.pks: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE PACKAGE zip_util_pkg 2 | AUTHID CURRENT_USER 3 | AS 4 | 5 | /** 6 | * Purpose: Package handles zipping and unzipping of files 7 | * 8 | * Remarks: by Anton Scheffer, see http://forums.oracle.com/forums/thread.jspa?messageID=9289744#9289744 9 | * 10 | * for unzipping, see http://technology.amis.nl/blog/8090/parsing-a-microsoft-word-docx-and-unzip-zipfiles-with-plsql 11 | * for zipping, see http://forums.oracle.com/forums/thread.jspa?threadID=1115748&tstart=0 12 | * 13 | * Who Date Description 14 | * ------ ---------- -------------------------------- 15 | * MBR 09.01.2011 Created 16 | * MK 16.04.2014 Removed UTL_FILE dependencies and file operations 17 | * MK 01.07.2014 Added get_file_clob to immediately retrieve file content as a CLOB 18 | * 19 | * @headcom 20 | **/ 21 | 22 | /** List of all files within zipped file */ 23 | TYPE t_file_list IS TABLE OF CLOB; 24 | 25 | 26 | FUNCTION little_endian( p_big IN NUMBER 27 | , p_bytes IN pls_integer := 4 28 | ) 29 | RETURN RAW; 30 | 31 | FUNCTION get_file_list( p_zipped_blob IN BLOB 32 | , p_encoding IN VARCHAR2 := NULL /* Use CP850 for zip files created with a German Winzip to see umlauts, etc */ 33 | ) 34 | RETURN t_file_list; 35 | 36 | FUNCTION get_file( p_zipped_blob IN BLOB 37 | , p_file_name IN VARCHAR2 38 | , p_encoding IN VARCHAR2 := NULL 39 | ) 40 | RETURN BLOB; 41 | 42 | FUNCTION get_file_clob( p_zipped_blob IN BLOB 43 | , p_file_name IN VARCHAR2 44 | , p_encoding IN VARCHAR2 := NULL 45 | ) 46 | RETURN CLOB; 47 | 48 | PROCEDURE add_file( p_zipped_blob IN OUT NOCOPY BLOB 49 | , p_name IN VARCHAR2 50 | , p_content IN BLOB 51 | ) 52 | ; 53 | 54 | PROCEDURE add_file( p_zipped_blob IN OUT NOCOPY BLOB 55 | , p_name IN VARCHAR2 56 | , p_content CLOB 57 | ) 58 | ; 59 | 60 | PROCEDURE finish_zip( p_zipped_blob IN OUT NOCOPY BLOB); 61 | 62 | END zip_util_pkg; 63 | / -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | APEXIR_XLSX 2 | =========== 3 | 4 | Download APEX Interactive Reports as XLSX files. 5 | With this package you can download any Interactive report using the standard Excel file format. 6 | Main benefits are that all data types are preserved and stored in a way that Excel recognizes them properly. 7 | 8 | SUPPORTED FUNCTIONALITY 9 | ----------------------- 10 | * Automatically derive Interactive Report Region ID (if only one IR on the page) 11 | * Filtering and Sorting 12 | * Control Breaks 13 | * Computations 14 | * Aggregations (with a small limitation, see below) 15 | * Highlights 16 | * VARCHAR2 columns 17 | * DATE columns including formatting (supports &APP_DATE_TIME_FORMAT. substitution) 18 | * NUMBER columns including formatting 19 | * CLOBs (limited to 32767 characters) 20 | * "Group By" view mode (for limitations see below) 21 | * Display column help text as comment on respective column header. 22 | 23 | CURRENT LIMITATIONS 24 | ------------------- 25 | 1. CLOB columns are supported but converted to VARCHAR2(32767) before inserted into the spreadsheet. 26 | Support for full size CLOBs is planned for a future release. 27 | 2. TIMESTAMP columns are treated like DATE columns. 28 | Full support for TIMESTAMP is planned for a future release. 29 | 2. Aggregates defined on the first column of any report are ignored. 30 | The cell is needed to display the aggregation type. 31 | Currently there are no immediate plans to lift that restriction. 32 | 3. For the "Group By" view report to work all used columns also need to be present in the "Standard" report view. 33 | The APEX engine only exposes the SQL query of the standard view currently. 34 | 4. The download only works for authenticated users. 35 | The APEX engine does not give back base_report_id if user isn't authenticated. 36 | This has been identified as a bug by the APEX development Team and should be fixed with APEX 5.0 according to current information. 37 | 5. Deriving IR only works with exactly one IR on the page. 38 | The package will put a message into the debug log if no or multiple IR regions are found. 39 | 40 | INSTALLATION 41 | ------------ 42 | Navigate to folder "setup". 43 | Simply run the script "install_all.sql" if you want everything installed at once. 44 | If you have the referenced libraries already you can run "install_main.sql" to install the main package. 45 | Libraries can be installed standalone by using "install_libs.sql". 46 | 47 | You can also manually create the packages by running the separate package specifications and bodies in your favourite IDE. 48 | 49 | HOW TO USE 50 | ---------- 51 | ###Enable download with default options 52 | 53 | 1. Create the interactive report region. (skip if you already have one) 54 | 2. Create button or similar element to reload page setting request to "XLSX". 55 | 3. Create page process (sample) 56 | Type: PL/SQL anonymous block 57 | Process Point: On Load - Before Header 58 | Condition Type: Request = Expression 1 59 | Expression 1: XLSX 60 | Process: 61 | ```sql 62 | apexir_xlsx_pkg.download(); 63 | ``` 64 | 65 | ###Setting options (refer to package header for more) 66 | 67 | 1. Disable help text on column headers 68 | ```sql 69 | apexir_xlsx_pkg.download( p_col_hdr_help => FALSE ); 70 | ``` 71 | 72 | 2. Do not append date to file name 73 | ```sql 74 | apexir_xlsx_pkg.download( p_append_date => FALSE ); 75 | ``` 76 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | ################# 2 | ## Eclipse 3 | ################# 4 | 5 | *.pydevproject 6 | .project 7 | .metadata 8 | bin/ 9 | tmp/ 10 | *.tmp 11 | *.bak 12 | *.swp 13 | *~.nib 14 | local.properties 15 | .classpath 16 | .settings/ 17 | .loadpath 18 | 19 | # External tool builders 20 | .externalToolBuilders/ 21 | 22 | # Locally stored "Eclipse launch configurations" 23 | *.launch 24 | 25 | # CDT-specific 26 | .cproject 27 | 28 | # PDT-specific 29 | .buildpath 30 | 31 | 32 | ################# 33 | ## Visual Studio 34 | ################# 35 | 36 | ## Ignore Visual Studio temporary files, build results, and 37 | ## files generated by popular Visual Studio add-ons. 38 | 39 | # User-specific files 40 | *.suo 41 | *.user 42 | *.sln.docstates 43 | 44 | # Build results 45 | 46 | [Dd]ebug/ 47 | [Rr]elease/ 48 | x64/ 49 | build/ 50 | [Bb]in/ 51 | [Oo]bj/ 52 | 53 | # MSTest test Results 54 | [Tt]est[Rr]esult*/ 55 | [Bb]uild[Ll]og.* 56 | 57 | *_i.c 58 | *_p.c 59 | *.ilk 60 | *.meta 61 | *.obj 62 | *.pch 63 | *.pdb 64 | *.pgc 65 | *.pgd 66 | *.rsp 67 | *.sbr 68 | *.tlb 69 | *.tli 70 | *.tlh 71 | *.tmp 72 | *.tmp_proj 73 | *.log 74 | *.vspscc 75 | *.vssscc 76 | .builds 77 | *.pidb 78 | *.log 79 | *.scc 80 | 81 | # Visual C++ cache files 82 | ipch/ 83 | *.aps 84 | *.ncb 85 | *.opensdf 86 | *.sdf 87 | *.cachefile 88 | 89 | # Visual Studio profiler 90 | *.psess 91 | *.vsp 92 | *.vspx 93 | 94 | # Guidance Automation Toolkit 95 | *.gpState 96 | 97 | # ReSharper is a .NET coding add-in 98 | _ReSharper*/ 99 | *.[Rr]e[Ss]harper 100 | 101 | # TeamCity is a build add-in 102 | _TeamCity* 103 | 104 | # DotCover is a Code Coverage Tool 105 | *.dotCover 106 | 107 | # NCrunch 108 | *.ncrunch* 109 | .*crunch*.local.xml 110 | 111 | # Installshield output folder 112 | [Ee]xpress/ 113 | 114 | # DocProject is a documentation generator add-in 115 | DocProject/buildhelp/ 116 | DocProject/Help/*.HxT 117 | DocProject/Help/*.HxC 118 | DocProject/Help/*.hhc 119 | DocProject/Help/*.hhk 120 | DocProject/Help/*.hhp 121 | DocProject/Help/Html2 122 | DocProject/Help/html 123 | 124 | # Click-Once directory 125 | publish/ 126 | 127 | # Publish Web Output 128 | *.Publish.xml 129 | *.pubxml 130 | 131 | # NuGet Packages Directory 132 | ## TODO: If you have NuGet Package Restore enabled, uncomment the next line 133 | #packages/ 134 | 135 | # Windows Azure Build Output 136 | csx 137 | *.build.csdef 138 | 139 | # Windows Store app package directory 140 | AppPackages/ 141 | 142 | # Others 143 | sql/ 144 | *.Cache 145 | ClientBin/ 146 | [Ss]tyle[Cc]op.* 147 | ~$* 148 | *~ 149 | *.dbmdl 150 | *.[Pp]ublish.xml 151 | *.pfx 152 | *.publishsettings 153 | 154 | # RIA/Silverlight projects 155 | Generated_Code/ 156 | 157 | # Backup & report files from converting an old project file to a newer 158 | # Visual Studio version. Backup files are not needed, because we have git ;-) 159 | _UpgradeReport_Files/ 160 | Backup*/ 161 | UpgradeLog*.XML 162 | UpgradeLog*.htm 163 | 164 | # SQL Server files 165 | App_Data/*.mdf 166 | App_Data/*.ldf 167 | 168 | ############# 169 | ## Windows detritus 170 | ############# 171 | 172 | # Windows image file caches 173 | Thumbs.db 174 | ehthumbs.db 175 | 176 | # Folder config file 177 | Desktop.ini 178 | 179 | # Recycle Bin used on file shares 180 | $RECYCLE.BIN/ 181 | 182 | # Mac crap 183 | .DS_Store 184 | 185 | 186 | ############# 187 | ## Python 188 | ############# 189 | 190 | *.py[co] 191 | 192 | # Packages 193 | *.egg 194 | *.egg-info 195 | dist/ 196 | build/ 197 | eggs/ 198 | parts/ 199 | var/ 200 | sdist/ 201 | develop-eggs/ 202 | .installed.cfg 203 | 204 | # Installer logs 205 | pip-log.txt 206 | 207 | # Unit test / coverage reports 208 | .coverage 209 | .tox 210 | 211 | #Translations 212 | *.mo 213 | 214 | #Mr Developer 215 | .mr.developer.cfg 216 | 217 | #Build Oracle config file 218 | .atom-build-oracle.json 219 | -------------------------------------------------------------------------------- /ora/apexir_xlsx_pkg.pks: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE PACKAGE "APEXIR_XLSX_PKG" 2 | AUTHID CURRENT_USER 3 | AS 4 | /** 5 | * Package prepares and APEX Interactive Report to be downloaded as an XLSX file.
6 | * Takes all user and global settings and hands them over to XLSX Builder Package by Anton Scheffer.
7 | * Retrieves generated file, amends file name, mime type and file size. 8 | * @headcom 9 | */ 10 | 11 | /** 12 | * Retrieve an interactive report as an XLSX file. 13 | * @param p_ir_region_id The region ID of the interactive report to convert to XLSX. (derived from APEX context if not set manually) 14 | * @param p_app_id Application ID the interactive report belongs to. (derived from APEX context if not set manually) 15 | * @param p_ir_page_id ID of page on which the interactive report resides. (derived from APEX context if not set manually) 16 | * @param p_ir_session_id APEX session from which to take the session variables. (derived from APEX context if not set manually) 17 | * @param p_ir_request Request associated with call. (derived from APEX context if not set manually) 18 | * @param p_ir_view_mode Sets the interactive report view mode to use. 19 | * Leave NULL to use APEX context. 20 | * @param p_column_headers Determines if column headers should be rendered. Default: TRUE 21 | * @param p_col_hdr_help Determines if the help text is added as a comment to column headers. Default: TRUE 22 | * @param p_aggregates Determines if aggregates should be rendered. Default: TRUE 23 | * @param p_process_highlights Determines if highlights should be considered to color rows and cells. Default: TRUE 24 | * @param p_show_report_title Determines if a report title should be rendered as a headline. Default: TRUE 25 | * @param p_show_filters Determines if active filters should be rendered as headlines. Default: TRUE 26 | * @param p_include_page_items Determines if used page items should be rendered as headlines. Default: FALSE 27 | * @param p_show_highlights Determines if highlight definitions should be rendered as headlines. Default: TRUE 28 | * @param p_original_line_break Set to the line break used for normal display of the interactive report. Default: <br /> 29 | * @param p_replace_line_break Sets the line break used in the XLSX file, replaces original line break set above. Default: \r\n 30 | * @param p_filter_replacement Sets the value to be used when replacing original line break in filter display row. Default is one blank 31 | * @param p_append_date Determines if the current date (Format: YYYYMMDD) should be appended to the generated file name. Default: TRUE 32 | * @param p_append_date_fmt The date format to be used when appending current date to filename. Default: YYYYMMDD 33 | * @return Record Type with file name, generated file, mime type, file size 34 | */ 35 | FUNCTION apexir2sheet 36 | ( p_ir_region_id NUMBER := NULL 37 | , p_app_id NUMBER := NV('APP_ID') 38 | , p_ir_page_id NUMBER := NV('APP_PAGE_ID') 39 | , p_ir_session_id NUMBER := NV('SESSION') 40 | , p_ir_request VARCHAR2 := V('REQUEST') 41 | , p_ir_view_mode VARCHAR2 := NULL 42 | , p_column_headers BOOLEAN := TRUE 43 | , p_col_hdr_help BOOLEAN := TRUE 44 | , p_freeze_col_hdr BOOLEAN := FALSE 45 | , p_aggregates IN BOOLEAN := TRUE 46 | , p_process_highlights IN BOOLEAN := TRUE 47 | , p_show_report_title IN BOOLEAN := TRUE 48 | , p_show_filters IN BOOLEAN := TRUE 49 | , p_include_page_items IN BOOLEAN := FALSE 50 | , p_show_highlights IN BOOLEAN := TRUE 51 | , p_original_line_break IN VARCHAR2 := '
' 52 | , p_replace_line_break IN VARCHAR2 := chr(13) || chr(10) 53 | , p_filter_replacement IN VARCHAR2 := ' ' 54 | , p_append_date IN BOOLEAN := TRUE 55 | , p_append_date_fmt IN VARCHAR2 := 'YYYYMMDD' 56 | ) 57 | RETURN apexir_xlsx_types_pkg.t_returnvalue; 58 | 59 | /** 60 | * Download Interactive Report as XLSX file. 61 | * This is a wrapper for APEXIR2SHEET which immediately presents the file for download. 62 | */ 63 | 64 | PROCEDURE download 65 | ( p_ir_region_id NUMBER := NULL 66 | , p_app_id NUMBER := NV('APP_ID') 67 | , p_ir_page_id NUMBER := NV('APP_PAGE_ID') 68 | , p_ir_session_id NUMBER := NV('SESSION') 69 | , p_ir_request VARCHAR2 := V('REQUEST') 70 | , p_ir_view_mode VARCHAR2 := NULL 71 | , p_column_headers BOOLEAN := TRUE 72 | , p_col_hdr_help BOOLEAN := TRUE 73 | , p_freeze_col_hdr BOOLEAN := FALSE 74 | , p_aggregates IN BOOLEAN := TRUE 75 | , p_process_highlights IN BOOLEAN := TRUE 76 | , p_show_report_title IN BOOLEAN := TRUE 77 | , p_show_filters IN BOOLEAN := TRUE 78 | , p_include_page_items IN BOOLEAN := FALSE 79 | , p_show_highlights IN BOOLEAN := TRUE 80 | , p_original_line_break IN VARCHAR2 := '
' 81 | , p_replace_line_break IN VARCHAR2 := chr(13) || chr(10) 82 | , p_filter_replacement IN VARCHAR2 := ' ' 83 | , p_append_date IN BOOLEAN := TRUE 84 | , p_append_date_fmt IN VARCHAR2 := 'YYYYMMDD' 85 | ); 86 | 87 | FUNCTION get_version 88 | RETURN VARCHAR2; 89 | 90 | END APEXIR_XLSX_PKG; 91 | 92 | / 93 | -------------------------------------------------------------------------------- /ora/apexir_xlsx_types_pkg.pks: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE PACKAGE "APEXIR_XLSX_TYPES_PKG" 2 | AUTHID CURRENT_USER 3 | AS 4 | /** 5 | * Package defines all relevant types for APEXIR XLSX Download 6 | * @headcom 7 | */ 8 | 9 | /** 10 | * Record with data about a single highlight definition. 11 | * @param bg_color Background color to be applied 12 | * @param font_color Color to applied to text 13 | * @param highlight_name User defined name for highlighting 14 | * @param highlight_sql SQL clause to check if highlight should be applied 15 | * @param col_num Defines the sql column number to check for highlight being active 16 | * @param affected_column Name of SQL column affected by highlight 17 | */ 18 | TYPE t_apex_ir_highlight IS RECORD 19 | ( bg_color apex_application_page_ir_cond.highlight_row_color%TYPE 20 | , font_color apex_application_page_ir_cond.highlight_row_font_color%TYPE 21 | , highlight_name apex_application_page_ir_cond.condition_name%TYPE 22 | , highlight_sql apex_application_page_ir_cond.condition_sql%TYPE 23 | , col_num NUMBER 24 | , affected_column VARCHAR2(30) 25 | ) 26 | ; 27 | 28 | /** Table holding enabled highlights by name */ 29 | TYPE t_apex_ir_highlights IS TABLE OF t_apex_ir_highlight INDEX BY VARCHAR2(30); 30 | 31 | /** Table holds active highlights by fetch count */ 32 | TYPE t_apex_ir_active_hl IS TABLE OF t_apex_ir_highlight INDEX BY PLS_INTEGER; 33 | 34 | /** Table holds order number of aggregate enabled column indexed by column name for a single aggregate type */ 35 | TYPE t_apex_ir_aggregate IS TABLE OF PLS_INTEGER INDEX BY VARCHAR2(32767); 36 | 37 | /* 38 | * Record of all aggregates using tables indexed by column name. 39 | * Used as temporary storage before attaching aggregates to columns. 40 | * Allows easy check if column is aggregate enabled by using exists. 41 | * @param sum_cols Table of all Columns with "Sum"-Aggregation 42 | * @param avg_cols Table of all Columns with "Average"-Aggregation 43 | * @param max_cols Table of all Columns with "Max"-Aggregation 44 | * @param min_cols Table of all Columns with "Min"-Aggregation 45 | * @param median_cols Table of all Columns with "Median"-Aggregation 46 | * @param count_cols Table of all Columns with "Count"-Aggregation 47 | * @param count_distinct_cols Table of all Columns with "Count Distinct"-Aggregation 48 | */ 49 | TYPE t_apex_ir_aggregates IS RECORD 50 | ( sum_cols t_apex_ir_aggregate 51 | , avg_cols t_apex_ir_aggregate 52 | , max_cols t_apex_ir_aggregate 53 | , min_cols t_apex_ir_aggregate 54 | , median_cols t_apex_ir_aggregate 55 | , count_cols t_apex_ir_aggregate 56 | , count_distinct_cols t_apex_ir_aggregate 57 | ) 58 | ; 59 | 60 | /** 61 | * Record holds aggregate data attached to an APEX IR column. 62 | * @param col_num SQL column number for the aggregate value 63 | * @param last_value Last seen value of aggregation 64 | */ 65 | TYPE t_apex_ir_col_aggregate IS RECORD 66 | ( col_num PLS_INTEGER 67 | , last_value NUMBER 68 | ) 69 | ; 70 | 71 | /** Table holds defined aggregates per column indexed by aggregate name. */ 72 | TYPE t_apex_ir_col_aggregates IS TABLE OF t_apex_ir_col_aggregate INDEX BY VARCHAR2(30); 73 | 74 | /** 75 | * Holds the relevant information about a column in the interactive report. 76 | * @param report_label Column heading as defined on intercative report 77 | * @param is_visible Defines if column is printed in file. 78 | * @param is_break_col Set to TRUE if column is used for control break. 79 | * @param aggregates All defined aggregates for the column. 80 | * @param highlight_conds All highlights defined on column. 81 | * @param format_mask Format mask as defined in IR column definition. 82 | * @param sql_col_num SQL column number to retrieve value. 83 | * @param display_column Column number in file to show value. 84 | * @param group_by_function Aggregate Function SQL for Group By View 85 | */ 86 | TYPE t_apex_ir_col IS RECORD 87 | ( ident VARCHAR2(10) 88 | , report_label apex_application_page_ir_col.report_label%TYPE 89 | , help_text apex_application_page_ir_col.help_text%TYPE 90 | , is_visible BOOLEAN 91 | , is_break_col BOOLEAN := FALSE 92 | , aggregates t_apex_ir_col_aggregates 93 | , highlight_conds t_apex_ir_highlights 94 | , format_mask apex_application_page_ir_col.format_mask%TYPE 95 | , sql_col_num NUMBER 96 | , display_column PLS_INTEGER 97 | , group_by_function apex_application_page_ir_grpby.function_01%TYPE 98 | ) 99 | ; 100 | 101 | /** Table holds all APEX IR columns based on the SQL column alias. */ 102 | TYPE t_apex_ir_cols IS TABLE OF t_apex_ir_col INDEX BY VARCHAR2(30); 103 | 104 | /** Stores all used aggregate types for the interactive report by aggregate name */ 105 | TYPE t_apex_ir_active_aggregates IS TABLE OF BOOLEAN INDEX BY VARCHAR2(30); 106 | 107 | /** 108 | * Holds general information regarding the interactive report. 109 | * @param application_id Application the IR belongs to. 110 | * @param page_id Page ID the IR belongs to. 111 | * @param region_id Region ID of the IR region. 112 | * @param session_id Session ID of the request. 113 | * @param request Value of the request variable. 114 | * @param base_report_id Report ID for the request. 115 | * @param report_title Derived report title. 116 | * @param report_definition Report definition as retrieved by calling APEX_IR.GET_REPORT function. 117 | * @param final_sql Final statement used to get the data. 118 | * @param break_def_column SQL column number of column with break definition. 119 | * @param aggregates_offset SQL column offset to calculate aggregate column numbers. 120 | * @param active_aggregates All active aggregate types on IR. 121 | * @param aggregate_type_disp_column Display column for aggregate types. 122 | * @param view_mode Current view mode of report 123 | */ 124 | TYPE t_apex_ir_info IS RECORD 125 | ( application_id NUMBER 126 | , page_id NUMBER 127 | , region_id NUMBER 128 | , session_id NUMBER 129 | , request VARCHAR2(4000) 130 | , base_report_id NUMBER 131 | , report_title VARCHAR2(4000) 132 | , report_definition apex_ir.t_report 133 | , final_sql VARCHAR2(32767) 134 | , break_def_column PLS_INTEGER 135 | , aggregates_offset PLS_INTEGER 136 | , active_aggregates t_apex_ir_active_aggregates 137 | , aggregate_type_disp_column PLS_INTEGER := 1 138 | , view_mode VARCHAR2(255) 139 | , group_by_cols VARCHAR2(4000) 140 | , group_by_sort VARCHAR2(4000) 141 | , group_by_funcs VARCHAR2(4000) 142 | ) 143 | ; 144 | 145 | /** 146 | * Holds the selected options and calculated settings for the XLSX generation. 147 | * @param show_title Show header line with report title 148 | * @param show_filters Show header lines with filter settings 149 | * @param include_page_items Include used page items in filter details 150 | * @param show_column_headers Show column headers before data 151 | * @param col_hdr_help Include help text on column headers 152 | * @param freeze_column_headers Freeze the column header row 153 | * @param process_highlights Format data according to highlights 154 | * @param show_highlights Show header lines with highlight settings, not useful if set without above 155 | * @param show_aggregates Process aggregates and show on total lines 156 | * @param display_column_count Holds count of displayed columns, used for merged cells in header section 157 | * @param sheet Holds the worksheet reference 158 | * @param default_font default Font for printed values 159 | * @param default_border_color Default color if a border is shown 160 | * @param allow_wrap_text Switch to allow/disallow word wrap 161 | * @param original_line_break The line break character as used in the statement 162 | * @param replace_line_break Line break to be used in XLSX file 163 | * @param default_date_format Default date format, taken from v$nls_parameters 164 | * @param append_date_file_name Append current date to file name or not 165 | * @param requested_view_mode Interactive Report view mode to use 166 | */ 167 | TYPE t_xlsx_options IS RECORD 168 | ( show_title BOOLEAN 169 | , show_filters BOOLEAN 170 | , include_page_items BOOLEAN 171 | , show_column_headers BOOLEAN 172 | , col_hdr_help BOOLEAN 173 | , freeze_column_headers BOOLEAN 174 | , process_highlights BOOLEAN 175 | , show_highlights BOOLEAN 176 | , show_aggregates BOOLEAN 177 | , display_column_count NUMBER 178 | , sheet PLS_INTEGER 179 | , default_font VARCHAR2(100) 180 | , default_border_color VARCHAR2(100) 181 | , allow_wrap_text BOOLEAN 182 | , original_line_break VARCHAR2(10) 183 | , replace_line_break VARCHAR2(10) 184 | , filter_replacement VARCHAR2(10) 185 | , default_date_format VARCHAR2(100) 186 | , append_date_file_name BOOLEAN 187 | , requested_view_mode VARCHAR2(8) 188 | ) 189 | ; 190 | 191 | /** 192 | * Holds column information for all selected columns. 193 | * @param col_name Column alias as used in SQL statement. 194 | * @param col_data_type Data type of the column. 195 | * @param col_type Internal column type, e.g. DISPLAY, ROW_HIGHLIGHT, BREAK_DEF... 196 | * @param is_displayed Defines if column value should be fetched and put into file. 197 | */ 198 | TYPE t_sql_col_info IS RECORD 199 | ( col_name VARCHAR2(32767) 200 | , col_data_type VARCHAR2(30) 201 | , col_type VARCHAR2(30) 202 | , is_displayed BOOLEAN := FALSE 203 | ); 204 | 205 | /** Table of all SQL columns by position in SQL statement */ 206 | TYPE t_sql_col_infos IS TABLE OF t_sql_col_info INDEX BY PLS_INTEGER; 207 | 208 | /** Table holding control break offset by SQL row count */ 209 | TYPE t_break_rows IS TABLE OF NUMBER INDEX BY PLS_INTEGER; 210 | 211 | /** 212 | * Holds general information about the opened cursor, including runtime data. 213 | * @param cursor_id ID of opened cursor. 214 | * @param column_count Amount of selected columns. 215 | * @param date_tab Temporary storage for values of DATE columns. 216 | * @param num_tab Temporary storage for values of NUMBER columns. 217 | * @param vc_tab Temporary storage for values of VARCHAR columns. 218 | * @param clob_tab Temporary storage for values of CLOB columns. 219 | * @param break_rows Definition when a control break accours including respective offset for further rows. 220 | * @param prev_break_val Last seen value of break definition column, needed if bulk size matches break. 221 | */ 222 | TYPE t_cursor_info IS RECORD 223 | ( cursor_id PLS_INTEGER 224 | , column_count PLS_INTEGER 225 | , date_tab dbms_sql.date_table 226 | , num_tab dbms_sql.number_table 227 | , vc_tab dbms_sql.varchar2_table 228 | , clob_tab dbms_sql.clob_table 229 | , break_rows t_break_rows 230 | , prev_break_val VARCHAR2(32767) 231 | ); 232 | 233 | /** 234 | * Record used to return file and corresponding data. 235 | * @param file_name The generated file name. 236 | * @param file_content The generated XLSX file. 237 | * @param mime_type MIME type to be used for download. 238 | * @param file_size Size of generated XLSX file. 239 | */ 240 | TYPE t_returnvalue IS RECORD 241 | ( file_name VARCHAR2(255) 242 | , file_content BLOB 243 | , mime_type VARCHAR2(255) 244 | , file_size NUMBER 245 | , error_encountered BOOLEAN := FALSE 246 | ); 247 | 248 | END APEXIR_XLSX_TYPES_PKG; 249 | / -------------------------------------------------------------------------------- /lib/xlsx_builder/lib/zip_util_pkg.pkb: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE package body zip_util_pkg 2 | is 3 | 4 | /** 5 | * Purpose: Package handles zipping and unzipping of files 6 | * 7 | * Remarks: by Anton Scheffer, see http://forums.oracle.com/forums/thread.jspa?messageID=9289744#9289744 8 | * 9 | * for unzipping, see http://technology.amis.nl/blog/8090/parsing-a-microsoft-word-docx-and-unzip-zipfiles-with-plsql 10 | * for zipping, see http://forums.oracle.com/forums/thread.jspa?threadID=1115748&tstart=0 11 | * 12 | * Who Date Description 13 | * ------ ---------- -------------------------------- 14 | * MBR 09.01.2011 Created 15 | * MBR 21.05.2012 Fixed a bug related to use of dbms_lob.substr in get_file (use dbms_lob.copy instead) 16 | * MK 01.07.2014 Added get_file_clob to immediatly retrieve file content as a CLOB 17 | * 18 | * @headcom 19 | */ 20 | 21 | /* Constants */ 22 | c_max_length CONSTANT PLS_INTEGER := 32767; 23 | c_file_comment CONSTANT RAW(32767) := utl_raw.cast_to_raw('Implementation by Anton Scheffer'); 24 | 25 | /** 26 | * Convert to little endian raw 27 | */ 28 | FUNCTION little_endian( p_big IN NUMBER 29 | , p_bytes IN pls_integer := 4 30 | ) 31 | RETURN RAW 32 | AS 33 | BEGIN 34 | RETURN utl_raw.substr( utl_raw.cast_from_binary_integer( p_big 35 | , utl_raw.little_endian 36 | ) 37 | , 1 38 | , p_bytes 39 | ); 40 | END little_endian; 41 | 42 | FUNCTION get_modify_date( p_modify_date IN DATE DEFAULT SYSDATE) 43 | RETURN RAW 44 | AS 45 | BEGIN 46 | RETURN little_endian( to_number( to_char( p_modify_date, 'dd' ) ) 47 | + to_number( to_char( p_modify_date, 'mm' ) ) * 32 48 | + ( to_number( to_char( p_modify_date, 'yyyy' ) ) - 1980 ) * 512 49 | , 2 50 | ); 51 | END get_modify_date; 52 | 53 | FUNCTION get_modify_time( p_modify_date IN DATE DEFAULT SYSDATE) 54 | RETURN RAW 55 | AS 56 | BEGIN 57 | RETURN little_endian( to_number( to_char( p_modify_date, 'ss' ) ) / 2 58 | + to_number( to_char( p_modify_date, 'mi' ) ) * 32 59 | + to_number( to_char( p_modify_date, 'hh24' ) ) * 2048 60 | , 2 61 | ); 62 | END get_modify_time; 63 | 64 | 65 | FUNCTION raw2num( p_value in raw ) 66 | RETURN NUMBER 67 | AS 68 | BEGIN -- note: FFFFFFFF => -1 69 | RETURN utl_raw.cast_to_binary_integer( p_value 70 | , utl_raw.little_endian 71 | ); 72 | 73 | END raw2num; 74 | 75 | FUNCTION raw2varchar2( p_raw IN RAW 76 | , p_encoding IN VARCHAR2 77 | ) 78 | RETURN VARCHAR2 79 | AS 80 | BEGIN 81 | RETURN nvl( utl_i18n.raw_to_char( p_raw 82 | , p_encoding 83 | ) 84 | , utl_i18n.raw_to_char ( p_raw 85 | , utl_i18n.map_charset( p_encoding 86 | , utl_i18n.generic_context 87 | , utl_i18n.iana_to_oracle 88 | ) 89 | ) 90 | ); 91 | END raw2varchar2; 92 | 93 | FUNCTION raw2varchar2( p_zipped_blob IN BLOB 94 | , p_start_index IN NUMBER 95 | , p_end_index IN NUMBER 96 | , p_encoding IN VARCHAR2 97 | ) 98 | RETURN VARCHAR2 99 | AS 100 | BEGIN 101 | RETURN raw2varchar2( dbms_lob.substr( p_zipped_blob 102 | , p_start_index 103 | , p_end_index 104 | ) 105 | , p_encoding 106 | ); 107 | END raw2varchar2; 108 | 109 | 110 | FUNCTION raw2num( p_zipped_blob IN BLOB 111 | , p_start_index IN NUMBER 112 | , p_end_index IN NUMBER 113 | ) 114 | RETURN NUMBER 115 | AS 116 | BEGIN 117 | RETURN raw2num( dbms_lob.substr( p_zipped_blob 118 | , p_start_index 119 | , p_end_index 120 | ) 121 | ); 122 | END raw2num; 123 | 124 | FUNCTION get_file_list( p_zipped_blob IN BLOB 125 | , p_encoding IN VARCHAR2 := NULL 126 | ) 127 | RETURN t_file_list 128 | AS 129 | l_index INTEGER; 130 | l_header_index INTEGER; 131 | l_file_list t_file_list; 132 | BEGIN 133 | l_index := dbms_lob.getlength( p_zipped_blob ) - 21; 134 | LOOP 135 | EXIT WHEN dbms_lob.substr( p_zipped_blob, 4, l_index ) = hextoraw( '504B0506' ) 136 | OR l_index < 1; 137 | l_index := l_index - 1; 138 | END LOOP; 139 | 140 | IF l_index <= 0 THEN 141 | RETURN NULL; 142 | END IF; 143 | 144 | l_header_index := raw2num( p_zipped_blob, 4, l_index + 16 ) + 1; 145 | l_file_list := t_file_list( ); 146 | l_file_list.EXTEND( raw2num( p_zipped_blob, 2, l_index + 10 ) ); 147 | 148 | FOR i IN 1 .. raw2num( p_zipped_blob, 2, l_index + 8 ) 149 | LOOP 150 | l_file_list( i ) := raw2varchar2( p_zipped_blob 151 | , raw2num( p_zipped_blob, 2, l_header_index + 28 ) 152 | , l_header_index + 46 153 | , p_encoding 154 | ); 155 | l_header_index := l_header_index 156 | + 46 157 | + raw2num( dbms_lob.substr( p_zipped_blob, 2, l_header_index + 28 ) ) 158 | + raw2num( dbms_lob.substr( p_zipped_blob, 2, l_header_index + 30 ) ) 159 | + raw2num( dbms_lob.substr( p_zipped_blob, 2, l_header_index + 32 ) ); 160 | END LOOP; 161 | 162 | RETURN l_file_list; 163 | END get_file_list; 164 | 165 | FUNCTION get_file( p_zipped_blob IN BLOB 166 | , p_file_name IN VARCHAR2 167 | , p_encoding IN VARCHAR2 := NULL 168 | ) 169 | RETURN BLOB 170 | AS 171 | l_retval BLOB; 172 | l_index INTEGER; 173 | l_header_index INTEGER; 174 | l_file_index INTEGER; 175 | BEGIN 176 | l_index := dbms_lob.getlength( p_zipped_blob ) - 21; 177 | LOOP 178 | EXIT WHEN dbms_lob.substr( p_zipped_blob, 4, l_index ) = hextoraw( '504B0506' ) 179 | OR l_index < 1; 180 | l_index := l_index - 1; 181 | END LOOP; 182 | 183 | IF l_index <= 0 THEN 184 | RETURN NULL; 185 | END IF; 186 | 187 | l_header_index := raw2num( p_zipped_blob, 4, l_index + 16 ) + 1; 188 | FOR i IN 1 .. raw2num( p_zipped_blob, 2, l_index + 8 ) 189 | LOOP 190 | IF p_file_name = raw2varchar2( p_zipped_blob 191 | , raw2num( p_zipped_blob, 2, l_header_index + 28 ) 192 | , l_header_index + 46 193 | , p_encoding 194 | ) 195 | THEN 196 | IF dbms_lob.substr( p_zipped_blob, 2, l_header_index + 10 ) = hextoraw( '0800' ) -- deflate 197 | THEN 198 | l_file_index := raw2num( p_zipped_blob, 4, l_header_index + 42 ); 199 | l_retval := hextoraw( '1F8B0800000000000003' ); -- gzip header 200 | dbms_lob.copy( l_retval 201 | , p_zipped_blob 202 | , raw2num( p_zipped_blob, 4, l_file_index + 19 ) 203 | , 11 204 | , l_file_index 205 | + 31 206 | + raw2num( p_zipped_blob, 2, l_file_index + 27 ) 207 | + raw2num( p_zipped_blob, 2, l_file_index + 29 ) 208 | ); 209 | dbms_lob.append( l_retval 210 | , dbms_lob.substr( p_zipped_blob, 4, l_file_index + 15 ) 211 | ); 212 | dbms_lob.append( l_retval 213 | , dbms_lob.substr( p_zipped_blob, 4, l_file_index + 23 ) 214 | ); 215 | RETURN utl_compress.lz_uncompress( l_retval ); 216 | END IF; 217 | IF dbms_lob.substr( p_zipped_blob, 2, l_header_index + 10) = hextoraw( '0000' ) -- The file is stored (no compression) 218 | THEN 219 | l_file_index := raw2num( p_zipped_blob, 4, l_header_index + 42 ); 220 | 221 | dbms_lob.createtemporary(l_retval, cache => true); 222 | 223 | dbms_lob.copy(dest_lob => l_retval, 224 | src_lob => p_zipped_blob, 225 | amount => raw2num( p_zipped_blob, 4, l_file_index + 19 ), 226 | dest_offset => 1, 227 | src_offset => l_file_index + 31 + raw2num(dbms_lob.substr(p_zipped_blob, 2, l_file_index + 27)) + raw2num(dbms_lob.substr( p_zipped_blob, 2, l_file_index + 29)) 228 | ); 229 | 230 | RETURN l_retval; 231 | END IF; 232 | END IF; 233 | l_header_index := l_header_index 234 | + 46 235 | + raw2num( p_zipped_blob, 2, l_header_index + 28 ) 236 | + raw2num( p_zipped_blob, 2, l_header_index + 30 ) 237 | + raw2num( p_zipped_blob, 2, l_header_index + 32 ); 238 | END LOOP; 239 | RETURN NULL; 240 | END get_file; 241 | 242 | FUNCTION get_file_clob( p_zipped_blob IN BLOB 243 | , p_file_name IN VARCHAR2 244 | , p_encoding IN VARCHAR2 := NULL 245 | ) 246 | RETURN CLOB 247 | AS 248 | l_file_blob BLOB; 249 | l_return CLOB; 250 | l_dest_offset INTEGER := 1; 251 | l_src_offset INTEGER := 1; 252 | l_warning INTEGER; 253 | l_lang_ctx INTEGER := dbms_lob.DEFAULT_LANG_CTX; 254 | BEGIN 255 | l_file_blob := get_file( p_zipped_blob => p_zipped_blob 256 | , p_file_name => p_file_name 257 | , p_encoding => p_encoding 258 | ); 259 | IF l_file_blob IS NULL THEN 260 | raise_application_error( -20000 261 | , 'File not found...' 262 | ); 263 | END IF; 264 | dbms_lob.createtemporary (l_return, true); 265 | dbms_lob.converttoclob( dest_lob => l_return 266 | , src_blob => l_file_blob 267 | , amount => dbms_lob.lobmaxsize 268 | , dest_offset => l_dest_offset 269 | , src_offset => l_src_offset 270 | , blob_csid => dbms_lob.default_csid 271 | , lang_context =>l_lang_ctx 272 | , warning => l_warning 273 | ); 274 | RETURN l_return; 275 | END get_file_clob; 276 | 277 | PROCEDURE add_file( p_zipped_blob IN OUT NOCOPY BLOB 278 | , p_name IN VARCHAR2 279 | , p_content IN BLOB 280 | ) 281 | AS 282 | l_new_file BLOB; 283 | l_content_length INTEGER; 284 | BEGIN 285 | l_new_file := utl_compress.lz_compress( p_content ); 286 | l_content_length := dbms_lob.getlength( l_new_file ); 287 | 288 | IF p_zipped_blob IS NULL THEN 289 | dbms_lob.createtemporary( p_zipped_blob, true ); 290 | END IF; 291 | dbms_lob.APPEND( p_zipped_blob 292 | , utl_raw.concat ( hextoraw( '504B0304' ) -- Local file header signature 293 | , hextoraw( '1400' ) -- version 2.0 294 | , hextoraw( '0000' ) -- no General purpose bits 295 | , hextoraw( '0800' ) -- deflate 296 | , get_modify_time -- File last modification time 297 | , get_modify_date -- File last modification date 298 | , dbms_lob.substr( l_new_file, 4, l_content_length - 7) -- CRC-321 299 | , little_endian( l_content_length - 18 ) -- compressed size 300 | , little_endian( dbms_lob.getlength( p_content ) ) -- uncompressed size 301 | , little_endian( LENGTH( p_name ), 2 ) -- File name length 302 | , hextoraw( '0000' ) -- Extra field length 303 | , utl_raw.cast_to_raw( p_name ) -- File name 304 | ) 305 | ); 306 | dbms_lob.copy( p_zipped_blob 307 | , l_new_file 308 | , l_content_length - 18 309 | , dbms_lob.getlength( p_zipped_blob ) + 1 310 | , 11 311 | ); -- compressed content 312 | dbms_lob.freetemporary( l_new_file ); 313 | END add_file; 314 | 315 | PROCEDURE add_file( p_zipped_blob IN OUT NOCOPY BLOB 316 | , p_name IN VARCHAR2 317 | , p_content CLOB 318 | ) 319 | AS 320 | l_tmp BLOB; 321 | dest_offset INTEGER := 1; 322 | src_offset INTEGER := 1; 323 | l_warning INTEGER; 324 | l_lang_ctx INTEGER := dbms_lob.DEFAULT_LANG_CTX; 325 | BEGIN 326 | dbms_lob.createtemporary( l_tmp, true ); 327 | dbms_lob.converttoblob( l_tmp 328 | , p_content 329 | , dbms_lob.lobmaxsize 330 | , dest_offset 331 | , src_offset 332 | , nls_charset_id( 'AL32UTF8' ) 333 | , l_lang_ctx 334 | , l_warning 335 | ); 336 | add_file( p_zipped_blob, p_name, l_tmp ); 337 | dbms_lob.freetemporary( l_tmp ); 338 | END add_file; 339 | 340 | PROCEDURE finish_zip( p_zipped_blob IN OUT NOCOPY BLOB ) 341 | AS 342 | l_cnt pls_integer := 0; 343 | l_offset INTEGER; 344 | l_offset_directory INTEGER; 345 | l_offset_header INTEGER; 346 | BEGIN 347 | l_offset_directory := dbms_lob.getlength( p_zipped_blob ); 348 | l_offset := dbms_lob.instr( p_zipped_blob 349 | , hextoraw( '504B0304' ) 350 | , 1 351 | ); 352 | WHILE l_offset > 0 LOOP 353 | l_cnt := l_cnt + 1; 354 | dbms_lob.APPEND( p_zipped_blob 355 | , utl_raw.concat( hextoraw( '504B0102' ) -- Central directory file header signature 356 | , hextoraw( '1400' ) -- version 2.0 357 | , dbms_lob.substr( p_zipped_blob, 26, l_offset + 4 ) 358 | , hextoraw( '0000' ) -- File comment length 359 | , hextoraw( '0000' ) -- Disk number where file starts 360 | , hextoraw( '0100' ) -- Internal file attributes 361 | , hextoraw( '2000B681' ) -- External file attributes 362 | , little_endian( l_offset - 1 ) -- Relative offset of local file header 363 | , dbms_lob.substr( p_zipped_blob 364 | , utl_raw.cast_to_binary_integer( dbms_lob.substr( p_zipped_blob 365 | , 2 366 | , l_offset + 26 367 | ) 368 | , utl_raw.little_endian 369 | ) 370 | , l_offset + 30 371 | ) -- File name 372 | ) 373 | ); 374 | l_offset := dbms_lob.instr( p_zipped_blob 375 | , hextoraw( '504B0304' ) 376 | , l_offset + 32 377 | ); 378 | END LOOP; 379 | 380 | l_offset_header := dbms_lob.getlength( p_zipped_blob ); 381 | dbms_lob.APPEND( p_zipped_blob 382 | , utl_raw.concat( hextoraw( '504B0506' ) -- End of central directory signature 383 | , hextoraw( '0000' ) -- Number of this disk 384 | , hextoraw( '0000' ) -- Disk where central directory starts 385 | , little_endian( l_cnt, 2 ) -- Number of central directory records on this disk 386 | , little_endian( l_cnt, 2 ) -- Total number of central directory records 387 | , little_endian( l_offset_header - l_offset_directory ) -- Size of central directory 388 | , little_endian( l_offset_directory ) -- Relative offset of local file header 389 | , little_endian( nvl( utl_raw.length( c_file_comment ), 0 ), 2) -- ZIP file comment length 390 | , c_file_comment 391 | ) 392 | ); 393 | END finish_zip; 394 | 395 | end zip_util_pkg; 396 | / 397 | 398 | -------------------------------------------------------------------------------- /lib/xlsx_builder/xlsx_builder_pkg.pks: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE 2 | PACKAGE xlsx_builder_pkg 3 | AUTHID CURRENT_USER 4 | IS 5 | /********************************************** 6 | ** 7 | ** Author: Anton Scheffer 8 | ** Date: 19-02-2011 9 | ** Website: http://technology.amis.nl/blog 10 | ** See also: http://technology.amis.nl/blog/?p=10995 11 | ** 12 | ** Changelog: 13 | ** Date: 21-02-2011 14 | ** Added Aligment, horizontal, vertical, wrapText 15 | ** Date: 06-03-2011 16 | ** Added Comments, MergeCells, fixed bug for dependency on NLS-settings 17 | ** Date: 16-03-2011 18 | ** Added bold and italic fonts 19 | ** Date: 22-03-2011 20 | ** Fixed issue with timezone's set to a region(name) instead of a offset 21 | ** Date: 08-04-2011 22 | ** Fixed issue with XML-escaping from text 23 | ** Date: 27-05-2011 24 | ** Added MIT-license 25 | ** Date: 11-08-2011 26 | ** Fixed NLS-issue with column width 27 | ** Date: 29-09-2011 28 | ** Added font color 29 | ** Date: 16-10-2011 30 | ** fixed bug in add_string 31 | ** Date: 26-04-2012 32 | ** Fixed set_autofilter (only one autofilter per sheet, added _xlnm._FilterDatabase) 33 | ** Added list_validation = drop-down 34 | ** Date: 27-08-2013 35 | ** Added freeze_pane 36 | ** Date: 01-03-2014 (MK) 37 | ** Changed new_sheet to function returning sheet id 38 | ** Date: 22-03-2014 (MK) 39 | ** Added function to convert Oracle Number Format to Excel Format 40 | ** Date: 07-04-2014 (MK) 41 | ** Removed references to UTL_FILE 42 | ** query2sheet is now function returning BLOB 43 | ** changed date handling to be based on 01-01-1900 44 | ** Date: 08-04-2014 (MK) 45 | ** internal function for date to excel serial conversion added 46 | ** Date: 01-12-2014 (AMEI) 47 | ** Some Naming-conventions (and renaming of elements accordingly), new FUNCTION get_sheet_id 48 | ** Triggered by: @SEE AMEI, 20141129 Bugfix: 49 | ** For concatenation operations (in particular where record fields are involved) added a lot of TO_CHAR (...) 50 | ** to make sure correct explicit conversion (mayby not all caught where necessary) 51 | ** To make this easier to recognize, inducted some naming conventions and renamed some elements. 52 | ** Date: 26-04-2017 (MP) 53 | ** Added new function "query2sheet2" which is faster. 54 | ** For dates used following logic: 55 | ** - if trunc([column])=[column], then outputed cell value is formatted to format YYYYMMDD; 56 | ** - otherwise, outputted cell value is formatted to format YYYYMMDDTHH24MISS; 57 | ****************************************************************************** 58 | ****************************************************************************** 59 | Copyright (C) 2011, 2012 by Anton Scheffer 60 | 61 | Permission is hereby granted, free of charge, to any person obtaining a copy 62 | of this software and associated documentation files (the "Software"), to deal 63 | in the Software without restriction, including without limitation the rights 64 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 65 | copies of the Software, and to permit persons to whom the Software is 66 | furnished to do so, subject to the following conditions: 67 | 68 | The above copyright notice and this permission notice shall be included in 69 | all copies or substantial portions of the Software. 70 | 71 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 72 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 73 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 74 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 75 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 76 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN 77 | THE SOFTWARE. 78 | 79 | ****************************************************************************** 80 | ****************************************************************************** 81 | * @headcom 82 | */ 83 | 84 | /** 85 | * Record with data about column alignment. 86 | * @param vertical Vertical alignment. 87 | * @param horizontal Horizontal alignment. 88 | * @param wrapText Switch to allow or disallow word wrap. 89 | */ 90 | TYPE t_alignment_rec IS RECORD 91 | ( 92 | vc_vertical VARCHAR2 (11), 93 | vc_horizontal VARCHAR2 (16), 94 | bo_wraptext BOOLEAN 95 | ); 96 | 97 | /** 98 | * Clears the whole workbook to start fresh. 99 | */ 100 | PROCEDURE clear_workbook; 101 | 102 | /** 103 | * Create a new sheet in the workbook. 104 | * @param p_sheetname Name Excel should display for the new worksheet. 105 | * @return ID of newly created worksheet. 106 | */ 107 | FUNCTION new_sheet (p_sheetname VARCHAR2 := NULL) 108 | RETURN PLS_INTEGER; 109 | 110 | /** 111 | * Converts an Oracle date format to the corresponding Excel date format. 112 | * @param p_format The Oracle date format to convert. 113 | * @return Corresponding Excel date format. 114 | */ 115 | FUNCTION orafmt2excel (p_format VARCHAR2 := NULL) 116 | RETURN VARCHAR2; 117 | 118 | /** 119 | * Converts an Oracle number format to the corresponding Excel number format. 120 | * @param The Oracle number format to convert. 121 | * @return Corresponding Excel number format. 122 | */ 123 | FUNCTION oranumfmt2excel (p_format VARCHAR2) 124 | RETURN VARCHAR2; 125 | 126 | /** 127 | * Get ID for given number format. 128 | * @param p_format Wanted number formatting using Excle number format. 129 | * Use OraNumFmt2Excel to convert from Oracle to Excel. 130 | * @return ID for given number format. 131 | */ 132 | FUNCTION get_numfmt (p_format VARCHAR2 := NULL) 133 | RETURN PLS_INTEGER; 134 | 135 | /** 136 | * Get ID for given font settings. 137 | * @param p_name 138 | * @param p_family 139 | * @param p_fontsize 140 | * @param p_theme 141 | * @param p_underline 142 | * @param p_italic 143 | * @param p_bold 144 | * @param p_rgb 145 | * @return ID for given font definition 146 | */ 147 | FUNCTION get_font (p_name VARCHAR2, 148 | p_family PLS_INTEGER := 2, 149 | p_fontsize NUMBER := 8, 150 | p_theme PLS_INTEGER := 1, 151 | p_underline BOOLEAN := FALSE, 152 | p_italic BOOLEAN := FALSE, 153 | p_bold BOOLEAN := FALSE, 154 | p_rgb VARCHAR2 := NULL -- this is a hex ALPHA Red Green Blue value, but RGB works also 155 | ) 156 | RETURN PLS_INTEGER; 157 | 158 | /** 159 | * Get ID for given cell fill 160 | * @param p_patternType Pattern for the fill. 161 | * @param p_fgRGB Color using an ARGB or RGB hex value 162 | * @return ID for given cell fill. 163 | */ 164 | FUNCTION get_fill (p_patterntype VARCHAR2, p_fgrgb VARCHAR2 := NULL) 165 | RETURN PLS_INTEGER; 166 | 167 | /** 168 | * Get ID for given border definition. 169 | * Possible values for all parameters: 170 | * none, thin, medium, dashed, dotted, thick, double, hair, mediumDashed, 171 | * dashDot, mediumDashDot, dashDotDot, mediumDashDotDot, slantDashDot 172 | * @param p_top Style for top border 173 | * @param p_bottom Style for bottom border 174 | * @param p_left Style for left border 175 | * @param p_right Style for right border 176 | * @return ID for given border definition 177 | */ 178 | FUNCTION get_border (p_top VARCHAR2 := 'thin', 179 | p_bottom VARCHAR2 := 'thin', 180 | p_left VARCHAR2 := 'thin', 181 | p_right VARCHAR2 := 'thin') 182 | RETURN PLS_INTEGER; 183 | 184 | /** 185 | * Function to get a record holding alignment data. 186 | * @param p_vertical Vertical alignment. 187 | * (bottom, center, distributed, justify, top) 188 | * @param p_horizontal Horizontal alignment. 189 | * (center, centerContinuous, distributed, fill, general, justify, left, right) 190 | * @param p_wraptext Switch to allow or disallow text wrapping. 191 | * @return Record with alignment data. 192 | */ 193 | FUNCTION get_alignment (p_vertical VARCHAR2 := NULL, p_horizontal VARCHAR2 := NULL, p_wraptext BOOLEAN := NULL) 194 | RETURN t_alignment_rec; 195 | 196 | /** 197 | * Puts a number value into a cell of the spreadsheet. 198 | * @param p_col Column number where the cell is located 199 | * @param p_row Row number where the cell is located 200 | * @param p_value The value to put into the cell 201 | * @param p_numFmtId ID of number format 202 | * @param p_fontId ID of font defintion 203 | * @param p_fillId ID of fill definition 204 | * @param p_borderId ID of border definition 205 | * @param p_alignment The wanted alignment 206 | * @param p_sheet Worksheet the cell is located, if omitted last worksheet is used 207 | */ 208 | PROCEDURE cell (p_col PLS_INTEGER, 209 | p_row PLS_INTEGER, 210 | p_value NUMBER, 211 | p_numfmtid PLS_INTEGER := NULL, 212 | p_fontid PLS_INTEGER := NULL, 213 | p_fillid PLS_INTEGER := NULL, 214 | p_borderid PLS_INTEGER := NULL, 215 | p_alignment t_alignment_rec := NULL, 216 | p_sheet PLS_INTEGER := NULL); 217 | 218 | /** 219 | * Puts a character value into a cell of the spreadsheet. 220 | * @param p_col Column number where the cell is located 221 | * @param p_row Row number where the cell is located 222 | * @param p_value The value to put into the cell 223 | * @param p_numFmtId ID of formatting definition 224 | * @param p_fontId ID of font defintion 225 | * @param p_fillId ID of fill definition 226 | * @param p_borderId ID of border definition 227 | * @param p_alignment The wanted alignment 228 | * @param p_sheet Worksheet the cell is located, if omitted last worksheet is used 229 | */ 230 | PROCEDURE cell (p_col PLS_INTEGER, 231 | p_row PLS_INTEGER, 232 | p_value VARCHAR2, 233 | p_numfmtid PLS_INTEGER := NULL, 234 | p_fontid PLS_INTEGER := NULL, 235 | p_fillid PLS_INTEGER := NULL, 236 | p_borderid PLS_INTEGER := NULL, 237 | p_alignment t_alignment_rec := NULL, 238 | p_sheet PLS_INTEGER := NULL); 239 | 240 | /** 241 | * Puts a date value into a cell of the spreadsheet. 242 | * @param p_col Column number where the cell is located 243 | * @param p_row Row number where the cell is located 244 | * @param p_value The value to put into the cell 245 | * @param p_numFmtId ID of format definition 246 | * @param p_fontId ID of font defintion 247 | * @param p_fillId ID of fill definition 248 | * @param p_borderId ID of border definition 249 | * @param p_alignment The wanted alignment 250 | * @param p_sheet Worksheet the cell is located, if omitted last worksheet is used 251 | */ 252 | PROCEDURE cell (p_col PLS_INTEGER, 253 | p_row PLS_INTEGER, 254 | p_value DATE, 255 | p_numfmtid PLS_INTEGER := NULL, 256 | p_fontid PLS_INTEGER := NULL, 257 | p_fillid PLS_INTEGER := NULL, 258 | p_borderid PLS_INTEGER := NULL, 259 | p_alignment t_alignment_rec := NULL, 260 | p_sheet PLS_INTEGER := NULL); 261 | 262 | PROCEDURE hyperlink (p_col PLS_INTEGER, 263 | p_row PLS_INTEGER, 264 | p_url VARCHAR2, 265 | p_value VARCHAR2 := NULL, 266 | p_sheet PLS_INTEGER := NULL); 267 | 268 | PROCEDURE comment (p_col PLS_INTEGER, 269 | p_row PLS_INTEGER, 270 | p_text VARCHAR2, 271 | p_author VARCHAR2 := NULL, 272 | p_width PLS_INTEGER := 150 -- pixels 273 | , 274 | p_height PLS_INTEGER := 100 -- pixels 275 | , 276 | p_sheet PLS_INTEGER := NULL); 277 | 278 | PROCEDURE mergecells (p_tl_col PLS_INTEGER -- top left 279 | , 280 | p_tl_row PLS_INTEGER, 281 | p_br_col PLS_INTEGER -- bottom right 282 | , 283 | p_br_row PLS_INTEGER, 284 | p_sheet PLS_INTEGER := NULL); 285 | 286 | PROCEDURE list_validation (p_sqref_col PLS_INTEGER, 287 | p_sqref_row PLS_INTEGER, 288 | p_tl_col PLS_INTEGER -- top left 289 | , 290 | p_tl_row PLS_INTEGER, 291 | p_br_col PLS_INTEGER -- bottom right 292 | , 293 | p_br_row PLS_INTEGER, 294 | p_style VARCHAR2 := 'stop' -- stop, warning, information 295 | , 296 | p_title VARCHAR2 := NULL, 297 | p_prompt VARCHAR2 := NULL, 298 | p_show_error BOOLEAN := FALSE, 299 | p_error_title VARCHAR2 := NULL, 300 | p_error_txt VARCHAR2 := NULL, 301 | p_sheet PLS_INTEGER := NULL); 302 | 303 | PROCEDURE list_validation (p_sqref_col PLS_INTEGER, 304 | p_sqref_row PLS_INTEGER, 305 | p_defined_name VARCHAR2, 306 | p_style VARCHAR2 := 'stop' -- stop, warning, information 307 | , 308 | p_title VARCHAR2 := NULL, 309 | p_prompt VARCHAR2 := NULL, 310 | p_show_error BOOLEAN := FALSE, 311 | p_error_title VARCHAR2 := NULL, 312 | p_error_txt VARCHAR2 := NULL, 313 | p_sheet PLS_INTEGER := NULL); 314 | 315 | PROCEDURE defined_name (p_tl_col PLS_INTEGER -- top left 316 | , 317 | p_tl_row PLS_INTEGER, 318 | p_br_col PLS_INTEGER -- bottom right 319 | , 320 | p_br_row PLS_INTEGER, 321 | p_name VARCHAR2, 322 | p_sheet PLS_INTEGER := NULL, 323 | p_localsheet PLS_INTEGER := NULL); 324 | 325 | PROCEDURE set_column_width (p_col PLS_INTEGER, p_width NUMBER, p_sheet PLS_INTEGER := NULL); 326 | 327 | PROCEDURE set_column (p_col PLS_INTEGER, 328 | p_numfmtid PLS_INTEGER := NULL, 329 | p_fontid PLS_INTEGER := NULL, 330 | p_fillid PLS_INTEGER := NULL, 331 | p_borderid PLS_INTEGER := NULL, 332 | p_alignment t_alignment_rec := NULL, 333 | p_sheet PLS_INTEGER := NULL); 334 | 335 | PROCEDURE set_row (p_row PLS_INTEGER, 336 | p_numfmtid PLS_INTEGER := NULL, 337 | p_fontid PLS_INTEGER := NULL, 338 | p_fillid PLS_INTEGER := NULL, 339 | p_borderid PLS_INTEGER := NULL, 340 | p_alignment t_alignment_rec := NULL, 341 | p_sheet PLS_INTEGER := NULL); 342 | 343 | PROCEDURE freeze_rows (p_nr_rows PLS_INTEGER := 1, p_sheet PLS_INTEGER := NULL); 344 | 345 | PROCEDURE freeze_cols (p_nr_cols PLS_INTEGER := 1, p_sheet PLS_INTEGER := NULL); 346 | 347 | PROCEDURE freeze_pane (p_col PLS_INTEGER, p_row PLS_INTEGER, p_sheet PLS_INTEGER := NULL); 348 | 349 | PROCEDURE set_autofilter (p_column_start PLS_INTEGER := NULL, 350 | p_column_end PLS_INTEGER := NULL, 351 | p_row_start PLS_INTEGER := NULL, 352 | p_row_end PLS_INTEGER := NULL, 353 | p_sheet PLS_INTEGER := NULL); 354 | 355 | FUNCTION finish 356 | RETURN BLOB; 357 | 358 | FUNCTION query2sheet (p_sql VARCHAR2, p_column_headers BOOLEAN := TRUE, p_sheet PLS_INTEGER := NULL) 359 | RETURN BLOB; 360 | 361 | FUNCTION finish2 (p_clob IN OUT NOCOPY CLOB, 362 | p_columns PLS_INTEGER, 363 | p_rows PLS_INTEGER, 364 | p_XLSX_date_format VARCHAR2, 365 | p_XLSX_datetime_format VARCHAR2) 366 | RETURN BLOB; 367 | 368 | FUNCTION query2sheet2(p_sql VARCHAR2, 369 | p_XLSX_date_format VARCHAR2 := 'dd/mm/yyyy', 370 | p_XLSX_datetime_format VARCHAR2 := 'dd/mm/yyyy hh24:mi:ss') 371 | RETURN BLOB; 372 | END; 373 | / 374 | -------------------------------------------------------------------------------- /ora/apexir_xlsx_pkg.pkb: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE PACKAGE BODY "APEXIR_XLSX_PKG" 2 | AS 3 | 4 | c_version CONSTANT VARCHAR2(6) := '1.3.1b'; 5 | 6 | /** Named exceptions for identified restrictions */ 7 | column_not_found EXCEPTION; 8 | ir_region_not_found EXCEPTION; 9 | multiple_ir_regions EXCEPTION; 10 | ir_def_not_found EXCEPTION; 11 | 12 | /** Additional Exception Info */ 13 | c_column_not_found CONSTANT VARCHAR2(4000) := 14 | 'Error: Column "#COL#" is used in a highlight condition but not in the displayed columns. 15 | If you add the highlight condition column to the displayed columns, then the Excel file will download properly. 16 | You would then have the option to exclude that column in your Excel reporting.'; 17 | g_exception_info VARCHAR2(4000); 18 | 19 | /** Defines the bulk fetch size used by DBMS_SQL */ 20 | c_bulk_size CONSTANT pls_integer := 200; 21 | 22 | c_col_data_type_vc CONSTANT VARCHAR2(30) := 'VARCHAR'; 23 | c_col_data_type_num CONSTANT VARCHAR2(30) := 'NUMBER'; 24 | c_col_data_type_date CONSTANT VARCHAR2(30) := 'DATE'; 25 | c_col_data_type_clob CONSTANT VARCHAR2(30) := 'CLOB'; 26 | 27 | c_ir_group_by_view CONSTANT VARCHAR2(8) := 'GROUP_BY'; 28 | c_ir_standard_view CONSTANT VARCHAR2(6) := 'REPORT'; 29 | 30 | /** Column type if column is normal display column */ 31 | c_display_column CONSTANT VARCHAR2(30) := 'DISPLAY'; 32 | /** Column type if column is used to check for row highlight */ 33 | c_row_highlight CONSTANT VARCHAR2(30) := 'ROW_HIGHLIGHT'; 34 | /** Column type if column is used to check for column highlight */ 35 | c_column_highlight CONSTANT VARCHAR2(30) := 'COLUMN_HIGHLIGHT'; 36 | /** Column type if column is used as control break definition */ 37 | c_break_definition CONSTANT VARCHAR2(30) := 'BREAK_DEF'; 38 | /** Column type if column is holding the value of an aggregation */ 39 | c_aggregate_column CONSTANT VARCHAR2(30) := 'AGGREGATE'; 40 | 41 | /* 42 | * Standard internal APEX date format. 43 | * Used to convert condition expression. 44 | */ 45 | c_apex_date_fmt CONSTANT VARCHAR2(30) := 'YYYYMMDDHH24MISS'; 46 | 47 | 48 | /** Runtime Variables */ 49 | 50 | /** Holds general info on the IR */ 51 | g_apex_ir_info apexir_xlsx_types_pkg.t_apex_ir_info; 52 | /** Holds the file generation options */ 53 | g_xlsx_options apexir_xlsx_types_pkg.t_xlsx_options; 54 | /** Holds APEX IR column settings */ 55 | g_col_settings apexir_xlsx_types_pkg.t_apex_ir_cols; 56 | /** Holds defined row highlights */ 57 | g_row_highlights apexir_xlsx_types_pkg.t_apex_ir_highlights; 58 | /** Holds all defined column highlights */ 59 | g_col_highlights apexir_xlsx_types_pkg.t_apex_ir_highlights; 60 | /** Row number of first sql row for current fetch */ 61 | g_current_sql_row PLS_INTEGER := 1; 62 | /** Row number in spreadsheet to start with for current fetch */ 63 | g_current_disp_row PLS_INTEGER := 1; 64 | /** General info about used cursor */ 65 | g_cursor_info apexir_xlsx_types_pkg.t_cursor_info; 66 | /** All SQL columns of cursor */ 67 | g_sql_columns apexir_xlsx_types_pkg.t_sql_col_infos; 68 | /** NLS Numeric Characters derived from database session */ 69 | g_nls_numeric_characters VARCHAR2(2); 70 | 71 | TYPE t_report_cols IS TABLE OF PLS_INTEGER INDEX BY VARCHAR2(4000); 72 | g_report_cols t_report_cols; 73 | 74 | /** Support Procedures */ 75 | 76 | /** 77 | * Wraps a column alias with double quotes. 78 | */ 79 | FUNCTION wrap_col (p_column IN VARCHAR2) 80 | RETURN VARCHAR2 81 | AS 82 | BEGIN 83 | RETURN '"' || p_column || '"'; 84 | END wrap_col; 85 | 86 | 87 | /** 88 | * Retrieve report title and populate global variable. 89 | */ 90 | PROCEDURE get_report_title_type 91 | AS 92 | l_report_columns apex_application_page_ir_rpt.report_columns%TYPE; 93 | PROCEDURE transform_rpt_cols 94 | AS 95 | l_vc_arr2 apex_application_global.vc_arr2; 96 | l_null_index_found BOOLEAN := FALSE; 97 | BEGIN 98 | l_vc_arr2 := apex_util.string_to_table(l_report_columns); 99 | FOR i IN 1..l_vc_arr2.COUNT 100 | LOOP 101 | IF l_vc_arr2(i) IS NOT NULL 102 | THEN 103 | g_report_cols(l_vc_arr2(i)) := i; 104 | ELSE 105 | l_null_index_found := TRUE; 106 | END IF; 107 | END LOOP; 108 | 109 | IF l_null_index_found 110 | THEN 111 | apex_debug.warn( 'Report Columns inconsistent. Check APEX_APPLICATION_PAGE_IR_RPT.REPORT_COLUMNS for this IR.' ); 112 | END IF; 113 | END transform_rpt_cols; 114 | BEGIN 115 | /* Could raise no data found. Check out why... */ 116 | SELECT CASE 117 | WHEN rpt.report_name IS NOT NULL THEN 118 | ir.region_name || ' - ' || rpt.report_name 119 | ELSE 120 | ir.region_name 121 | END report_title 122 | , COALESCE( g_apex_ir_info.view_mode, report_view_mode, c_ir_standard_view ) report_view_mode 123 | , RTRIM(report_columns, ':') 124 | INTO g_apex_ir_info.report_title 125 | , g_apex_ir_info.view_mode 126 | , l_report_columns 127 | FROM apex_application_page_ir ir JOIN apex_application_page_ir_rpt rpt 128 | ON ir.application_id = rpt.application_id 129 | AND ir.page_id = rpt.page_id 130 | AND ir.interactive_report_id = rpt.interactive_report_id 131 | WHERE ir.application_id = g_apex_ir_info.application_id 132 | AND ir.page_id = g_apex_ir_info.page_id 133 | AND rpt.base_report_id = g_apex_ir_info.base_report_id 134 | AND rpt.session_id = g_apex_ir_info.session_id 135 | ; 136 | transform_rpt_cols; 137 | EXCEPTION 138 | WHEN NO_DATA_FOUND THEN 139 | apex_debug.error( p_message => 'Could not find IR runtime definition.' ); 140 | apex_debug.error( p_message => 'Application ID: %s', p0 => g_apex_ir_info.application_id ); 141 | apex_debug.error( p_message => 'Page ID: %s', p0 => g_apex_ir_info.page_id ); 142 | apex_debug.error( p_message => 'Base Report ID: %s', p0 => g_apex_ir_info.base_report_id ); 143 | apex_debug.error( p_message => 'Session ID: %s', p0 => g_apex_ir_info.session_id ); 144 | g_exception_info := 'IR definition not found. Please contact your application administrator.'; 145 | RAISE ir_def_not_found; 146 | END get_report_title_type; 147 | 148 | /** 149 | * Performs a substitution similar to APEX. 150 | * Candidate to be replaced by APEX standard function. 151 | * @param p_data The original data. 152 | * @param p_substitution The APEX variable to be used. 153 | * @return Original data with substitution performed. 154 | */ 155 | FUNCTION replace_substitutions(p_data IN VARCHAR2, p_substitution IN VARCHAR2) 156 | RETURN VARCHAR2 157 | AS 158 | l_retval VARCHAR2(4000) := p_data; 159 | l_full_sub VARCHAR2(4000) := '&' || p_substitution || '.'; 160 | BEGIN 161 | IF INSTR(p_data, l_full_sub) > 0 THEN 162 | l_retval := REPLACE(l_retval, l_full_sub, v(p_substitution)); 163 | END IF; 164 | RETURN l_retval; 165 | END replace_substitutions; 166 | 167 | /** 168 | * Retrieve the defined IR columns from APEX dictionary 169 | * and store in global variable. 170 | */ 171 | PROCEDURE get_std_columns 172 | AS 173 | col_rec apexir_xlsx_types_pkg.t_apex_ir_col; 174 | BEGIN 175 | -- These column names are static defined, used as reference 176 | FOR rec IN ( SELECT column_alias 177 | , report_label 178 | , display_text_as 179 | , format_mask 180 | , CASE WHEN display_order > 26 181 | THEN chr(trunc((display_order - 1) / 26) + 64) 182 | ELSE NULL END 183 | || chr(display_order - (trunc((display_order - 1) / 26) * 26) + 64) 184 | AS ident 185 | , help_text 186 | FROM APEX_APPLICATION_PAGE_IR_COL 187 | WHERE page_id = g_apex_ir_info.page_id 188 | AND application_id = g_apex_ir_info.application_id 189 | AND region_id = g_apex_ir_info.region_id ) 190 | LOOP 191 | -- Always take all fields, even if not displayed might be used in filters 192 | col_rec.report_label := rec.report_label; 193 | col_rec.ident := rec.ident; 194 | col_rec.is_visible := (rec.display_text_as != 'HIDDEN' AND g_report_cols.exists(rec.column_alias)); 195 | col_rec.format_mask := replace_substitutions(rec.format_mask, 'APP_DATE_TIME_FORMAT'); 196 | col_rec.help_text := rec.help_text; 197 | g_col_settings(rec.column_alias) := col_rec; 198 | END LOOP; 199 | END get_std_columns; 200 | 201 | /** 202 | * Retrieve column definitions for Group By Mode 203 | * and store in gloabl variable 204 | */ 205 | PROCEDURE get_group_by_def 206 | AS 207 | col_rec apexir_xlsx_types_pkg.t_apex_ir_col; 208 | FUNCTION get_sql( p_function IN VARCHAR2, p_column IN VARCHAR2 ) 209 | RETURN VARCHAR2 210 | AS 211 | BEGIN 212 | RETURN 213 | CASE p_function 214 | WHEN 'COUNT_DISTINCT' THEN 'count(distinct ' 215 | WHEN 'RATIO_TO_REPORT_SUM' THEN 'ratio_to_report(sum(' 216 | WHEN 'RATIO_TO_REPORT_COUNT' THEN 'ratio_to_report(count(' 217 | ELSE p_function || '(' 218 | END || wrap_col(p_column) || ')' || 219 | CASE 220 | WHEN p_function IN ('RATIO_TO_REPORT_SUM','RATIO_TO_REPORT_COUNT') THEN ') OVER () * 100' 221 | END; 222 | END get_sql; 223 | 224 | FUNCTION get_label( p_function IN VARCHAR2, p_column IN VARCHAR2 ) 225 | RETURN VARCHAR2 226 | AS 227 | BEGIN 228 | RETURN 229 | CASE p_function 230 | WHEN 'COUNT_DISTINCT' THEN 'Unique Count' 231 | WHEN 'RATIO_TO_REPORT_SUM' THEN 'Percent of Total Sum' 232 | WHEN 'RATIO_TO_REPORT_COUNT' THEN 'Percent of Total Count' 233 | WHEN 'AVG' THEN 'Average' 234 | WHEN 'MAX' THEN 'Maximum' 235 | WHEN 'MIN' THEN 'Minimum' 236 | ELSE INITCAP(p_function) 237 | END || ' ' || g_col_settings(p_column).report_label; 238 | END get_label; 239 | BEGIN 240 | FOR rec IN ( SELECT REPLACE(group_by_columns, ':', ', ') group_by_cols 241 | , function_01 242 | , function_column_01 243 | , function_db_column_name_01 244 | , function_label_01 245 | , function_format_mask_01 246 | , function_sum_01 247 | , function_02 248 | , function_column_02 249 | , function_db_column_name_02 250 | , function_label_02 251 | , function_format_mask_02 252 | , function_sum_02 253 | , function_03 254 | , function_column_03 255 | , function_db_column_name_03 256 | , function_label_03 257 | , function_format_mask_03 258 | , function_sum_03 259 | , rtrim( CASE WHEN sort_column_01 IS NOT NULL 260 | THEN sort_column_01 || ' ' || sort_direction_01 || ', ' 261 | ELSE NULL 262 | END || 263 | CASE WHEN sort_column_02 IS NOT NULL 264 | THEN sort_column_02 || ' ' || sort_direction_02 || ', ' 265 | ELSE NULL 266 | END || 267 | CASE WHEN sort_column_03 IS NOT NULL 268 | THEN sort_column_03 || ' ' || sort_direction_03 || ', ' 269 | ELSE NULL 270 | END || 271 | CASE WHEN sort_column_04 IS NOT NULL 272 | THEN sort_column_04 || ' ' || sort_direction_04 273 | ELSE NULL 274 | END 275 | , ', ' 276 | ) grp_sort 277 | FROM apex_application_page_ir_grpby grpby JOIN apex_application_page_ir_rpt rpt 278 | ON grpby.report_id = rpt.report_id 279 | AND grpby.application_id = rpt.application_id 280 | AND grpby.page_id = rpt.page_id 281 | WHERE rpt.page_id = g_apex_ir_info.page_id 282 | AND rpt.application_id = g_apex_ir_info.application_id 283 | AND rpt.base_report_id = g_apex_ir_info.base_report_id 284 | AND rpt.session_id = g_apex_ir_info.session_id 285 | ) 286 | LOOP 287 | -- Add generated column names to column array 288 | -- (Manual loop, can this be areal one?) 289 | IF rec.function_01 IS NOT NULL THEN 290 | col_rec.report_label := COALESCE( rec.function_label_01 291 | , get_label( p_function => rec.function_01 292 | , p_column => rec.function_column_01 293 | ) 294 | ); 295 | col_rec.group_by_function := get_sql( rec.function_01, rec.function_column_01); 296 | col_rec.format_mask := rec.function_format_mask_01; 297 | col_rec.is_visible := TRUE; 298 | g_col_settings(rec.function_db_column_name_01) := col_rec; 299 | g_apex_ir_info.group_by_funcs := ', ' || g_apex_ir_info.group_by_funcs 300 | || col_rec.group_by_function 301 | || ' AS ' || rec.function_db_column_name_01; 302 | END IF; 303 | 304 | IF rec.function_02 IS NOT NULL THEN 305 | col_rec.report_label := COALESCE( rec.function_label_02 306 | , get_label( p_function => rec.function_02 307 | , p_column => rec.function_column_02 308 | ) 309 | ); 310 | col_rec.group_by_function := get_sql( rec.function_02, rec.function_column_02); 311 | col_rec.format_mask := rec.function_format_mask_02; 312 | col_rec.is_visible := TRUE; 313 | g_col_settings(rec.function_db_column_name_02) := col_rec; 314 | g_apex_ir_info.group_by_funcs := g_apex_ir_info.group_by_funcs || ', ' 315 | || col_rec.group_by_function 316 | || ' AS ' || rec.function_db_column_name_02; 317 | END IF; 318 | 319 | IF rec.function_03 IS NOT NULL THEN 320 | col_rec.report_label := COALESCE( rec.function_label_03 321 | , get_label( p_function => rec.function_03 322 | , p_column => rec.function_column_03 323 | ) 324 | ); 325 | col_rec.group_by_function := get_sql( rec.function_03, rec.function_column_03); 326 | col_rec.format_mask := rec.function_format_mask_03; 327 | col_rec.is_visible := TRUE; 328 | g_col_settings(rec.function_db_column_name_03) := col_rec; 329 | g_apex_ir_info.group_by_funcs := g_apex_ir_info.group_by_funcs || ', ' 330 | || col_rec.group_by_function 331 | || ' AS ' || rec.function_db_column_name_03; 332 | END IF; 333 | 334 | -- Put the sort into global variable 335 | IF rec.grp_sort IS NOT NULL THEN 336 | g_apex_ir_info.group_by_sort := 'ORDER BY ' || rec.grp_sort; 337 | END IF; 338 | g_apex_ir_info.group_by_cols := rec.group_by_cols; 339 | END LOOP; 340 | END get_group_by_def; 341 | 342 | /** 343 | * Retrieve currently defined computations from APEX dictionary 344 | * and store in global variable. 345 | */ 346 | PROCEDURE get_computations 347 | AS 348 | col_rec apexir_xlsx_types_pkg.t_apex_ir_col; 349 | BEGIN 350 | -- computations are run-time data, therefore need base report ID and session 351 | FOR rec IN (SELECT computation_column_alias,computation_report_label, computation_format_mask 352 | FROM apex_application_page_ir_comp comp JOIN apex_application_page_ir_rpt rpt 353 | ON rpt.application_id = comp.application_id 354 | AND rpt.page_id = comp.page_id 355 | AND rpt.report_id = comp.report_id 356 | WHERE rpt.application_id = g_apex_ir_info.application_id 357 | AND rpt.page_id = g_apex_ir_info.page_id 358 | AND rpt.base_report_id = g_apex_ir_info.base_report_id 359 | AND rpt.session_id = g_apex_ir_info.session_id) 360 | LOOP 361 | col_rec.report_label := rec.computation_report_label; 362 | col_rec.is_visible := TRUE; 363 | col_rec.format_mask := replace_substitutions(rec.computation_format_mask, 'APP_DATE_TIME_FORMAT'); 364 | g_col_settings(rec.computation_column_alias) := col_rec; 365 | END LOOP; 366 | END get_computations; 367 | 368 | /** 369 | * Flags an aggregation as active and converts column delimited list to array. 370 | * @param p_column_value Column value retrieved for aggregation 371 | * @param p_aggregate_name Defined name of aggregation 372 | * @return Array with aggregates indexed by column alias 373 | */ 374 | FUNCTION transform_aggregate (p_column_value IN VARCHAR2, p_aggregate_name IN VARCHAR2) 375 | RETURN apexir_xlsx_types_pkg.t_apex_ir_aggregate 376 | AS 377 | l_retval apexir_xlsx_types_pkg.t_apex_ir_aggregate; 378 | l_vc_arr2 apex_application_global.vc_arr2; 379 | BEGIN 380 | IF p_column_value IS NOT NULL THEN 381 | g_apex_ir_info.active_aggregates(p_aggregate_name) := TRUE; 382 | l_vc_arr2 := apex_util.string_to_table(p_column_value); 383 | FOR i IN 1..l_vc_arr2.COUNT LOOP 384 | l_retval(l_vc_arr2(i)) := i; 385 | END LOOP; 386 | END IF; 387 | RETURN l_retval; 388 | END transform_aggregate; 389 | 390 | /** 391 | * Retrieves aggregates and control break from APEX dictionary 392 | * and stores in global variables. 393 | */ 394 | PROCEDURE get_aggregates 395 | AS 396 | l_avg_cols apex_application_page_ir_rpt.avg_columns_on_break%TYPE; 397 | l_break_on apex_application_page_ir_rpt.break_enabled_on%TYPE; 398 | l_count_cols apex_application_page_ir_rpt.count_columns_on_break%TYPE; 399 | l_count_distinct_cols apex_application_page_ir_rpt.count_distnt_col_on_break%TYPE; 400 | l_max_cols apex_application_page_ir_rpt.max_columns_on_break%TYPE; 401 | l_median_cols apex_application_page_ir_rpt.median_columns_on_break%TYPE; 402 | l_min_cols apex_application_page_ir_rpt.min_columns_on_break%TYPE; 403 | l_sum_cols apex_application_page_ir_rpt.sum_columns_on_break%TYPE; 404 | l_all_aggregates VARCHAR2(32767); 405 | 406 | l_cur_col VARCHAR2(30); 407 | l_aggregates apexir_xlsx_types_pkg.t_apex_ir_aggregates; 408 | l_aggregate_col_offset PLS_INTEGER; 409 | l_col_aggregates apexir_xlsx_types_pkg.t_apex_ir_col_aggregates; 410 | l_tmp apex_application_global.vc_arr2; 411 | l_break_cols apexir_xlsx_types_pkg.t_apex_ir_aggregate; 412 | l_break_enabled BOOLEAN := FALSE; 413 | PROCEDURE add_to_offset (l_addition IN PLS_INTEGER) 414 | AS 415 | BEGIN 416 | l_aggregate_col_offset := l_aggregate_col_offset + l_addition; 417 | END add_to_offset; 418 | BEGIN 419 | -- First get run-time settings for aggregate infos 420 | SELECT break_enabled_on, 421 | sum_columns_on_break, 422 | avg_columns_on_break, 423 | max_columns_on_break, 424 | min_columns_on_break, 425 | median_columns_on_break, 426 | count_columns_on_break, 427 | count_distnt_col_on_break, 428 | sum_columns_on_break || 429 | avg_columns_on_break || 430 | max_columns_on_break || 431 | min_columns_on_break || 432 | median_columns_on_break || 433 | count_columns_on_break || 434 | count_distnt_col_on_break AS all_aggregates 435 | INTO l_break_on, 436 | l_sum_cols, 437 | l_avg_cols, 438 | l_max_cols, 439 | l_min_cols, 440 | l_median_cols, 441 | l_count_cols, 442 | l_count_distinct_cols, 443 | l_all_aggregates 444 | FROM apex_application_page_ir_rpt 445 | WHERE application_id = g_apex_ir_info.application_id 446 | AND page_id = g_apex_ir_info.page_id 447 | AND base_report_id = g_apex_ir_info.base_report_id 448 | AND session_id = g_apex_ir_info.session_id; 449 | 450 | IF l_break_on IS NOT NULL THEN 451 | l_tmp := apex_util.string_to_table(l_break_on); 452 | FOR i IN 1..l_tmp.COUNT LOOP 453 | l_break_cols(l_tmp(i)) := i; 454 | END LOOP; 455 | END IF; 456 | 457 | IF l_all_aggregates IS NOT NULL THEN 458 | l_aggregates.sum_cols := transform_aggregate(l_sum_cols, 'Sum'); 459 | l_aggregates.avg_cols := transform_aggregate(l_avg_cols, 'Average'); 460 | l_aggregates.max_cols := transform_aggregate(l_max_cols, 'Maximum'); 461 | l_aggregates.min_cols := transform_aggregate(l_min_cols, 'Minimum'); 462 | l_aggregates.median_cols := transform_aggregate(l_median_cols, 'Median'); 463 | l_aggregates.count_cols := transform_aggregate(l_count_cols, 'Count'); 464 | l_aggregates.count_distinct_cols := transform_aggregate(l_count_distinct_cols, 'Unique Count'); 465 | 466 | -- Loop through all selected columns and apply settings 467 | l_cur_col := g_col_settings.FIRST(); 468 | WHILE (l_cur_col IS NOT NULL) 469 | LOOP 470 | IF l_break_on IS NOT NULL AND l_break_cols.EXISTS(l_cur_col) THEN 471 | IF NOT l_break_enabled THEN l_break_enabled := TRUE; END IF; 472 | g_col_settings(l_cur_col).is_break_col := TRUE; 473 | IF g_col_settings(l_cur_col).is_visible THEN 474 | g_apex_ir_info.aggregate_type_disp_column := g_apex_ir_info.aggregate_type_disp_column + 1; 475 | g_apex_ir_info.final_sql := g_apex_ir_info.final_sql || 'to_char(' || wrap_col(l_cur_col) || ') || '; 476 | END IF; 477 | END IF; 478 | l_aggregate_col_offset := g_apex_ir_info.aggregates_offset; -- reset offset to global offset for every new column 479 | l_col_aggregates.DELETE; 480 | IF NOT g_col_settings(l_cur_col).is_break_col THEN 481 | IF INSTR(l_all_aggregates, l_cur_col) > 0 THEN 482 | IF l_aggregates.sum_cols.EXISTS(l_cur_col) THEN 483 | l_col_aggregates('Sum').col_num := l_aggregate_col_offset + l_aggregates.sum_cols(l_cur_col); 484 | END IF; 485 | add_to_offset(l_aggregates.sum_cols.count); 486 | 487 | IF l_aggregates.avg_cols.EXISTS(l_cur_col) THEN 488 | l_col_aggregates('Average').col_num := l_aggregate_col_offset + l_aggregates.avg_cols(l_cur_col); 489 | END IF; 490 | add_to_offset(l_aggregates.avg_cols.count); 491 | 492 | IF l_aggregates.max_cols.EXISTS(l_cur_col) THEN 493 | l_col_aggregates('Maximum').col_num := l_aggregate_col_offset + l_aggregates.max_cols(l_cur_col); 494 | END IF; 495 | add_to_offset(l_aggregates.max_cols.count); 496 | 497 | IF l_aggregates.min_cols.EXISTS(l_cur_col) THEN 498 | l_col_aggregates('Minimum').col_num := l_aggregate_col_offset + l_aggregates.min_cols(l_cur_col); 499 | END IF; 500 | add_to_offset(l_aggregates.min_cols.count); 501 | 502 | IF l_aggregates.median_cols.EXISTS(l_cur_col) THEN 503 | l_col_aggregates('Median').col_num := l_aggregate_col_offset + l_aggregates.median_cols(l_cur_col); 504 | END IF; 505 | add_to_offset(l_aggregates.median_cols.count); 506 | 507 | IF l_aggregates.count_cols.EXISTS(l_cur_col) THEN 508 | l_col_aggregates('Count').col_num := l_aggregate_col_offset + l_aggregates.count_cols(l_cur_col); 509 | END IF; 510 | add_to_offset(l_aggregates.count_cols.count); 511 | IF l_aggregates.count_distinct_cols.EXISTS(l_cur_col) THEN 512 | l_col_aggregates('Unique Count').col_num := l_aggregate_col_offset + l_aggregates.count_distinct_cols(l_cur_col); 513 | END IF; 514 | add_to_offset(l_aggregates.count_distinct_cols.count); 515 | END IF; 516 | END IF; 517 | g_col_settings(l_cur_col).aggregates := l_col_aggregates; 518 | l_cur_col := g_col_settings.next(l_cur_col); 519 | END LOOP; 520 | ELSE 521 | g_xlsx_options.show_aggregates := FALSE; 522 | END IF; 523 | IF l_break_enabled THEN 524 | g_apex_ir_info.final_sql := ', ' || RTRIM(g_apex_ir_info.final_sql, '|| ') || ' AS ' || c_break_definition; 525 | END IF; 526 | END get_aggregates; 527 | 528 | FUNCTION display_for_condition ( p_column_name IN VARCHAR2 529 | , p_display IN VARCHAR2 530 | , p_operator IN VARCHAR2 531 | , p_exp_1 IN VARCHAR2 532 | , p_exp_2 IN VARCHAR2 533 | ) 534 | RETURN VARCHAR2 535 | AS 536 | l_retval VARCHAR2(4000) := p_display; 537 | BEGIN 538 | l_retval := REPLACE( l_retval 539 | , '#APXWS_COL_NAME#' 540 | , REPLACE( g_col_settings(p_column_name).report_label 541 | , g_xlsx_options.original_line_break 542 | , g_xlsx_options.filter_replacement 543 | ) 544 | ); 545 | l_retval := REPLACE( l_retval, '#APXWS_OP_NAME#', p_operator ); 546 | l_retval := REPLACE( l_retval, '#APXWS_AND#', 'and' ); 547 | IF INSTR( l_retval, '#APXWS_EXPR_DATE#') > 0 OR INSTR(l_retval, '#APXWS_EXPR2_DATE#' ) > 0 THEN 548 | l_retval := REPLACE( l_retval, '#APXWS_EXPR_DATE#', TO_CHAR( TO_DATE( p_exp_1, c_apex_date_fmt ) ) ); 549 | l_retval := REPLACE( l_retval, '#APXWS_EXPR2_DATE#', TO_CHAR( TO_DATE( p_exp_2, c_apex_date_fmt ) ) ); 550 | END IF; 551 | l_retval := REPLACE( l_retval, '#APXWS_EXPR#', p_exp_1); 552 | l_retval := REPLACE( l_retval, '#APXWS_EXPR_NAME#', p_exp_1); 553 | l_retval := REPLACE( l_retval, '#APXWS_EXPR_NUMBER#', p_exp_1); 554 | l_retval := REPLACE( l_retval, '#APXWS_EXPR2#', p_exp_2); 555 | l_retval := REPLACE( l_retval, '#APXWS_EXPR2_NAME#', p_exp_2); 556 | RETURN l_retval; 557 | END display_for_condition; 558 | 559 | /** 560 | * Retrieves all row and column highlights 561 | * and stores in global variables. 562 | */ 563 | PROCEDURE get_highlights 564 | AS 565 | col_rec apexir_xlsx_types_pkg.t_apex_ir_highlight; 566 | hl_num NUMBER := 0; 567 | l_apxws_expr_vals apex_application_global.vc_arr2; 568 | 569 | FUNCTION wrap_exp (p_exp IN VARCHAR2) 570 | RETURN VARCHAR2 571 | AS 572 | BEGIN 573 | RETURN '''' || p_exp || ''''; 574 | END wrap_exp; 575 | 576 | BEGIN 577 | FOR rec IN (SELECT condition_name, 578 | CASE 579 | WHEN cond.highlight_row_color IS NOT NULL OR cond.highlight_row_font_color IS NOT NULL 580 | THEN 'ROW' 581 | ELSE 'COLUMN' 582 | END highlight_type, 583 | condition_column_name, 584 | condition_operator, 585 | condition_expression, 586 | condition_expression2, 587 | cond.condition_sql, 588 | cond.condition_display, 589 | REPLACE(COALESCE(cond.highlight_row_color, cond.highlight_cell_color), '#') bg_color, 590 | REPLACE(COALESCE(cond.highlight_row_font_color, cond.highlight_cell_font_color), '#') font_color 591 | FROM apex_application_page_ir_cond cond JOIN apex_application_page_ir_rpt r 592 | ON r.application_id = cond.application_id 593 | AND r.page_id = cond.page_id 594 | AND r.report_id = cond.report_id 595 | WHERE cond.application_id = g_apex_ir_info.application_id 596 | AND cond.page_id = g_apex_ir_info.page_id 597 | AND cond.condition_type = 'Highlight' 598 | AND cond.condition_enabled = 'Yes' 599 | AND r.base_report_id = g_apex_ir_info.base_report_id 600 | AND r.session_id = g_apex_ir_info.session_id 601 | AND ( cond.highlight_row_color IS NOT NULL 602 | OR cond.highlight_row_font_color IS NOT NULL 603 | OR cond.highlight_cell_color IS NOT NULL 604 | OR cond.highlight_cell_font_color IS NOT NULL 605 | ) 606 | ORDER BY cond.condition_column_name, cond.highlight_sequence 607 | ) 608 | LOOP 609 | IF NOT g_report_cols.exists(rec.condition_column_name) THEN 610 | g_exception_info := REPLACE( c_column_not_found 611 | , '#COL#' 612 | , CASE WHEN g_col_settings.exists(rec.condition_column_name) 613 | THEN g_col_settings(rec.condition_column_name).report_label 614 | ELSE rec.condition_column_name 615 | END 616 | ); 617 | RAISE column_not_found; 618 | END IF; 619 | IF g_col_settings.EXISTS(rec.condition_column_name) THEN 620 | hl_num := hl_num + 1; 621 | col_rec.bg_color := rec.bg_color; 622 | col_rec.font_color := rec.font_color; 623 | IF rec.condition_name IS NOT NULL THEN 624 | col_rec.highlight_name := rec.condition_name; 625 | ELSE 626 | col_rec.highlight_name := display_for_condition( p_column_name => rec.condition_column_name 627 | , p_display => rec.condition_display 628 | , p_operator => rec.condition_operator 629 | , p_exp_1 => rec.condition_expression 630 | , p_exp_2 => rec.condition_expression2 631 | ); 632 | END IF; 633 | -- Store and replace static part 634 | col_rec.highlight_sql := REPLACE(rec.condition_sql, '#APXWS_HL_ID#', 1); 635 | col_rec.highlight_sql := REPLACE(col_rec.highlight_sql, '#APXWS_CC_EXPR#', wrap_col(rec.condition_column_name) ); 636 | 637 | IF LOWER(rec.condition_operator) IN ('in', 'not in') 638 | THEN -- IN and NOT IN need special handling as the amount of values is unclear 639 | l_apxws_expr_vals := apex_util.string_to_table(rec.condition_expression, ','); 640 | FOR i IN 1..l_apxws_expr_vals.COUNT LOOP 641 | l_apxws_expr_vals(i) := wrap_exp(TRIM(l_apxws_expr_vals(i))); 642 | col_rec.highlight_sql := REPLACE(col_rec.highlight_sql, '#APXWS_EXPR_VAL' || to_char(i, 'FM9999') || '#', l_apxws_expr_vals(i)); 643 | END LOOP; 644 | ELSE --Operators which do not require special handling 645 | col_rec.highlight_sql := REPLACE(col_rec.highlight_sql, '#APXWS_EXPR#', wrap_exp(rec.condition_expression)); 646 | col_rec.highlight_sql := REPLACE(col_rec.highlight_sql, '#APXWS_EXPR2#', wrap_exp(rec.condition_expression2)); 647 | END IF; 648 | 649 | IF rec.highlight_type = 'COLUMN' THEN 650 | col_rec.affected_column := rec.condition_column_name; 651 | g_col_highlights('HL_' || to_char(hl_num)) := col_rec; 652 | ELSE 653 | g_row_highlights('HL_' || to_char(hl_num)) := col_rec; 654 | END IF; 655 | g_apex_ir_info.final_sql := g_apex_ir_info.final_sql || ', ' || col_rec.highlight_sql || ' AS HL_' || to_char(hl_num); 656 | END IF; 657 | END LOOP; 658 | END get_highlights; 659 | 660 | /** 661 | * Loops through all row highlights for current fetch 662 | * and sets row style if highlight condition is met. 663 | * @param p_fetched_row_cnt Amount of rows fetched 664 | */ 665 | PROCEDURE process_row_highlights (p_fetched_row_cnt IN PLS_INTEGER) 666 | AS 667 | l_cur_highlight VARCHAR2(30); 668 | l_highlight_values dbms_sql.number_table; 669 | BEGIN 670 | l_cur_highlight := g_row_highlights.FIRST(); 671 | WHILE l_cur_highlight IS NOT NULL LOOP 672 | dbms_sql.COLUMN_VALUE( g_cursor_info.cursor_id, g_row_highlights(l_cur_highlight).col_num, l_highlight_values ); 673 | FOR i IN 0 .. p_fetched_row_cnt - 1 LOOP 674 | IF (l_highlight_values(i + l_highlight_values.FIRST()) IS NOT NULL) THEN 675 | xlsx_builder_pkg.set_row( p_row => g_current_disp_row + i + g_cursor_info.break_rows(g_current_sql_row + i) 676 | , p_fontId => xlsx_builder_pkg.get_font( p_name => g_xlsx_options.default_font 677 | , p_rgb => g_row_highlights(l_cur_highlight).font_color 678 | ) 679 | , p_fillId => xlsx_builder_pkg.get_fill( p_patternType => 'solid' 680 | , p_fgRGB => g_row_highlights(l_cur_highlight).bg_color 681 | ) 682 | ); 683 | END IF; 684 | END LOOP; 685 | l_highlight_values.DELETE; 686 | l_cur_highlight := g_row_highlights.next(l_cur_highlight); 687 | END LOOP; 688 | END process_row_highlights; 689 | 690 | /** 691 | * Wrapper calling all procedures retrieving settings. 692 | * E.g. report title, computations 693 | */ 694 | PROCEDURE get_settings 695 | AS 696 | BEGIN 697 | SELECT VALUE 698 | INTO g_nls_numeric_characters 699 | FROM v$nls_parameters 700 | where parameter = 'NLS_NUMERIC_CHARACTERS'; 701 | 702 | SELECT VALUE 703 | INTO g_xlsx_options.default_date_format 704 | FROM v$nls_parameters 705 | WHERE parameter = 'NLS_DATE_FORMAT'; 706 | 707 | 708 | get_report_title_type; 709 | get_std_columns; 710 | get_computations; 711 | 712 | IF g_apex_ir_info.view_mode = c_ir_group_by_view THEN 713 | get_group_by_def; 714 | -- Disable everything not applicable for Group By View 715 | g_xlsx_options.show_aggregates := FALSE; 716 | g_xlsx_options.process_highlights := FALSE; 717 | END IF; 718 | 719 | IF g_xlsx_options.show_aggregates THEN 720 | get_aggregates; 721 | END IF; 722 | IF g_xlsx_options.process_highlights THEN 723 | get_highlights; 724 | END IF; 725 | END get_settings; 726 | 727 | /** 728 | * Loops through all cells in current display row starting from second 729 | * and applies a thin border to fix missing borders with merged cells. 730 | */ 731 | PROCEDURE fix_borders 732 | AS 733 | BEGIN 734 | FOR i IN 2..g_xlsx_options.display_column_count LOOP 735 | /* strange fix for borders... */ 736 | xlsx_builder_pkg.cell( p_col => i 737 | , p_row => g_current_disp_row 738 | , p_value => to_char(NULL) 739 | , p_borderId => xlsx_builder_pkg.get_border('thin', 'thin', 'thin', 'thin') 740 | , p_sheet => g_xlsx_options.sheet 741 | ); 742 | END LOOP; 743 | END fix_borders; 744 | 745 | PROCEDURE print_header_row( p_value IN VARCHAR2 ) 746 | AS 747 | BEGIN 748 | xlsx_builder_pkg.mergecells( p_tl_col => 1 749 | , p_tl_row => g_current_disp_row 750 | , p_br_col => g_xlsx_options.display_column_count 751 | , p_br_row => g_current_disp_row 752 | , p_sheet => g_xlsx_options.sheet 753 | ); 754 | xlsx_builder_pkg.cell( p_col => 1 755 | , p_row => g_current_disp_row 756 | , p_value => p_value 757 | , p_fillId => xlsx_builder_pkg.get_fill( p_patternType => 'solid' 758 | , p_fgRGB => 'FFF8DC' 759 | ) 760 | , p_alignment => xlsx_builder_pkg.get_alignment( p_vertical => 'center' 761 | , p_horizontal => 'center' 762 | ) 763 | , p_borderId => xlsx_builder_pkg.get_border('thin', 'thin', 'thin', 'thin') 764 | , p_sheet => g_xlsx_options.sheet ); 765 | fix_borders; 766 | g_current_disp_row := g_current_disp_row + 1; 767 | END print_header_row; 768 | /** 769 | * Prints the filter definitions to the spreadsheet. 770 | */ 771 | PROCEDURE print_filter_header 772 | AS 773 | l_condition_display VARCHAR2(4100); 774 | BEGIN 775 | FOR rec IN (SELECT condition_type, 776 | cond.condition_name, 777 | condition_column_name, 778 | cond.condition_operator, 779 | cond.condition_expression, 780 | cond.condition_expression2, 781 | cond.condition_display, 782 | r.base_report_id, r.report_id 783 | FROM apex_application_page_ir_cond cond JOIN apex_application_page_ir_rpt r 784 | ON r.application_id = cond.application_id 785 | AND r.page_id = cond.page_id 786 | AND r.report_id = cond.report_id 787 | WHERE cond.application_id = g_apex_ir_info.application_id 788 | AND cond.page_id = g_apex_ir_info.page_id 789 | AND r.base_report_id = g_apex_ir_info.base_report_id 790 | AND r.session_id = g_apex_ir_info.session_id 791 | AND cond.condition_type IN ('Search', 'Filter') 792 | AND cond.condition_enabled = 'Yes' 793 | ) 794 | LOOP 795 | IF rec.condition_type = 'Search' OR 796 | (rec.condition_type = 'Filter' AND rec.condition_column_name IS NULL) 797 | THEN 798 | l_condition_display := rec.condition_name; 799 | ELSE 800 | -- Filters for removed columns can still exist, skip if column not defined in IR 801 | /* !TODO: Think about logic again... */ 802 | IF g_col_settings.EXISTS(rec.condition_column_name) THEN 803 | l_condition_display := display_for_condition( p_column_name => rec.condition_column_name 804 | , p_display => rec.condition_display 805 | , p_operator => rec.condition_operator 806 | , p_exp_1 => rec.condition_expression 807 | , p_exp_2 => rec.condition_expression2 808 | ); 809 | ELSE 810 | CONTINUE; -- skip filter if column isn't existing anymore 811 | END IF; 812 | END IF; 813 | print_header_row( p_value => l_condition_display ); 814 | END LOOP; 815 | END print_filter_header; 816 | 817 | PROCEDURE print_page_items 818 | AS 819 | TYPE t_page_items IS TABLE OF apex_application_page_items.label%TYPE INDEX BY apex_application_page_items.item_name%TYPE; 820 | l_page_items t_page_items; 821 | FUNCTION format_value( p_item_label IN VARCHAR2, p_bind_value IN VARCHAR2) 822 | RETURN VARCHAR2 823 | AS 824 | BEGIN 825 | RETURN p_item_label || ' = ' || p_bind_value; 826 | END format_value; 827 | BEGIN 828 | FOR rec IN ( SELECT item_name, label 829 | FROM apex_application_page_items 830 | WHERE application_id = g_apex_ir_info.application_id 831 | AND page_id = g_apex_ir_info.page_id 832 | ) 833 | LOOP 834 | l_page_items(rec.item_name) := rec.label; 835 | END LOOP; 836 | 837 | FOR i IN 1..g_apex_ir_info.report_definition.binds.count LOOP 838 | IF l_page_items.exists(g_apex_ir_info.report_definition.binds(i).name) THEN 839 | print_header_row( p_value => format_value(l_page_items(g_apex_ir_info.report_definition.binds(i).name), g_apex_ir_info.report_definition.binds(i).value) ); 840 | END IF; 841 | END LOOP; 842 | END print_page_items; 843 | 844 | /** 845 | * Prints the header parts. 846 | * Title, filters and highlights 847 | */ 848 | PROCEDURE print_header 849 | AS 850 | l_cur_hl_name VARCHAR2(30); 851 | BEGIN 852 | IF g_xlsx_options.show_title THEN 853 | xlsx_builder_pkg.mergecells( p_tl_col => 1 854 | , p_tl_row => g_current_disp_row 855 | , p_br_col => g_xlsx_options.display_column_count 856 | , p_br_row => g_current_disp_row 857 | , p_sheet => g_xlsx_options.sheet 858 | ); 859 | xlsx_builder_pkg.cell( p_col => 1 860 | , p_row => g_current_disp_row 861 | , p_value => g_apex_ir_info.report_title 862 | , p_fontId => xlsx_builder_pkg.get_font( p_name => g_xlsx_options.default_font 863 | , p_fontsize => 14 864 | , p_bold => TRUE 865 | ) 866 | , p_fillId => xlsx_builder_pkg.get_fill( p_patterntype => 'solid' 867 | , p_fgRGB => 'FFF8DC' 868 | ) 869 | , p_alignment => xlsx_builder_pkg.get_alignment( p_vertical => 'center' 870 | , p_horizontal => 'center' 871 | ) 872 | , p_borderId => xlsx_builder_pkg.get_border('thin', 'thin', 'thin', 'thin') 873 | , p_sheet => g_xlsx_options.sheet 874 | ); 875 | fix_borders; 876 | g_current_disp_row := g_current_disp_row + 1; 877 | END IF; 878 | IF g_xlsx_options.show_filters THEN 879 | print_filter_header; 880 | END IF; 881 | IF g_xlsx_options.include_page_items THEN 882 | print_page_items; 883 | END IF; 884 | IF g_xlsx_options.show_highlights THEN 885 | l_cur_hl_name := g_row_highlights.FIRST(); 886 | WHILE (l_cur_hl_name IS NOT NULL) LOOP 887 | xlsx_builder_pkg.mergecells( p_tl_col => 1 888 | , p_tl_row => g_current_disp_row 889 | , p_br_col => g_xlsx_options.display_column_count 890 | , p_br_row => g_current_disp_row 891 | , p_sheet => g_xlsx_options.sheet 892 | ); 893 | xlsx_builder_pkg.cell( p_col => 1 894 | , p_row => g_current_disp_row 895 | , p_value => g_row_highlights(l_cur_hl_name).highlight_name 896 | , p_fontId => xlsx_builder_pkg.get_font( p_name => g_xlsx_options.default_font 897 | , p_rgb => g_row_highlights(l_cur_hl_name).font_color 898 | ) 899 | , p_fillId => xlsx_builder_pkg.get_fill( p_patternType => 'solid' 900 | , p_fgRGB => g_row_highlights(l_cur_hl_name).bg_color 901 | ) 902 | , p_alignment => xlsx_builder_pkg.get_alignment( p_vertical => 'center' 903 | , p_horizontal => 'center' 904 | ) 905 | , p_borderId => xlsx_builder_pkg.get_border('thin', 'thin', 'thin', 'thin') 906 | , p_sheet => g_xlsx_options.sheet ); 907 | fix_borders; 908 | g_current_disp_row := g_current_disp_row + 1; 909 | l_cur_hl_name := g_row_highlights.next(l_cur_hl_name); 910 | END LOOP; 911 | l_cur_hl_name := g_col_highlights.FIRST(); 912 | WHILE (l_cur_hl_name IS NOT NULL) LOOP 913 | xlsx_builder_pkg.mergecells( p_tl_col => 1 914 | , p_tl_row => g_current_disp_row 915 | , p_br_col => g_xlsx_options.display_column_count 916 | , p_br_row => g_current_disp_row 917 | , p_sheet => g_xlsx_options.sheet 918 | ); 919 | xlsx_builder_pkg.cell( p_col => 1 920 | , p_row => g_current_disp_row 921 | , p_value => g_col_highlights(l_cur_hl_name).highlight_name 922 | , p_fontId => xlsx_builder_pkg.get_font( p_name => g_xlsx_options.default_font 923 | , p_rgb => g_col_highlights(l_cur_hl_name).font_color 924 | ) 925 | , p_fillId => xlsx_builder_pkg.get_fill( p_patternType => 'solid' 926 | , p_fgRGB => g_col_highlights(l_cur_hl_name).bg_color 927 | ) 928 | , p_alignment => xlsx_builder_pkg.get_alignment( p_vertical => 'center' 929 | , p_horizontal => 'center' 930 | ) 931 | , p_borderId => xlsx_builder_pkg.get_border('thin', 'thin', 'thin', 'thin') 932 | , p_sheet => g_xlsx_options.sheet 933 | ); 934 | fix_borders; 935 | g_current_disp_row := g_current_disp_row + 1; 936 | l_cur_hl_name := g_col_highlights.next(l_cur_hl_name); 937 | END LOOP; 938 | END IF; 939 | g_current_disp_row := g_current_disp_row + 1; --add additional row 940 | END print_header; 941 | 942 | /** 943 | * Prepare the cursor and pull column information from it. 944 | */ 945 | PROCEDURE prepare_cursor 946 | AS 947 | l_desc_tab dbms_sql.desc_tab2; 948 | l_cur_col_highlight apexir_xlsx_types_pkg.t_apex_ir_highlight; 949 | BEGIN 950 | IF g_apex_ir_info.view_mode = c_ir_group_by_view THEN 951 | g_apex_ir_info.final_sql := 'SELECT * FROM ( SELECT ' 952 | || g_apex_ir_info.group_by_cols 953 | || g_apex_ir_info.group_by_funcs || ' FROM ( ' 954 | || g_apex_ir_info.report_definition.sql_query ||' ) ' 955 | || CASE WHEN g_apex_ir_info.group_by_cols IS NOT NULL 956 | THEN 'GROUP BY ' || g_apex_ir_info.group_by_cols 957 | END 958 | || ' ) ' || g_apex_ir_info.group_by_sort; 959 | ELSE 960 | -- Totally new because of highlights on computed columns 961 | 962 | g_apex_ir_info.final_sql := 'SELECT orig.*' 963 | || g_apex_ir_info.final_sql 964 | || ' FROM ( ' 965 | || g_apex_ir_info.report_definition.sql_query 966 | || ' ) orig' 967 | ; 968 | 969 | -- Split sql query on first from and inject highlight conditions 970 | /* g_apex_ir_info.final_sql := SUBSTR(g_apex_ir_info.report_definition.sql_query, 1, INSTR(UPPER(g_apex_ir_info.report_definition.sql_query), 'FROM') - 1) || ' ' 971 | || g_apex_ir_info.final_sql || ' ' 972 | || SUBSTR(apex_plugin_util.replace_substitutions(g_apex_ir_info.report_definition.sql_query), INSTR(UPPER(g_apex_ir_info.report_definition.sql_query), 'FROM')); 973 | */ 974 | END IF; 975 | g_cursor_info.cursor_id := dbms_sql.open_cursor; 976 | dbms_sql.parse( g_cursor_info.cursor_id, g_apex_ir_info.final_sql, dbms_sql.NATIVE ); 977 | dbms_sql.describe_columns2( g_cursor_info.cursor_id, g_cursor_info.column_count, l_desc_tab ); 978 | 979 | apex_debug.message( p_message => 'Cursor Describe Result' ); 980 | FOR i IN 1..l_desc_tab.count LOOP 981 | apex_debug.message( p_message => 'Column: %s -> Data Type: %s' 982 | , p0 => l_desc_tab(i).col_name 983 | , p1 => l_desc_tab(i).col_type 984 | , p_force => TRUE 985 | ); 986 | END LOOP; 987 | 988 | /* Bind values from IR structure*/ 989 | FOR i IN 1..g_apex_ir_info.report_definition.binds.count LOOP 990 | IF g_apex_ir_info.report_definition.binds(i).NAME = 'REQUEST' THEN 991 | dbms_sql.bind_variable( g_cursor_info.cursor_id, g_apex_ir_info.report_definition.binds(i).NAME, g_apex_ir_info.request); 992 | ELSE 993 | dbms_sql.bind_variable( g_cursor_info.cursor_id, g_apex_ir_info.report_definition.binds(i).name, g_apex_ir_info.report_definition.binds(i).value); 994 | END IF; 995 | END LOOP; 996 | 997 | /* Amend column settings*/ 998 | FOR c IN 1 .. g_cursor_info.column_count LOOP 999 | BEGIN 1000 | g_sql_columns(c).col_name := l_desc_tab(c).col_name; 1001 | CASE 1002 | WHEN l_desc_tab( c ).col_type IN ( 2, 100, 101 ) THEN 1003 | dbms_sql.define_array( g_cursor_info.cursor_id, c, g_cursor_info.num_tab, c_bulk_size, 1 ); 1004 | g_sql_columns(c).col_data_type := c_col_data_type_num; 1005 | WHEN l_desc_tab( c ).col_type IN ( 12, 178, 179, 180, 181 , 231 ) THEN 1006 | dbms_sql.define_array( g_cursor_info.cursor_id, c, g_cursor_info.date_tab, c_bulk_size, 1 ); 1007 | g_sql_columns(c).col_data_type := c_col_data_type_date; 1008 | WHEN l_desc_tab( c ).col_type IN ( 1, 8, 9, 96 ) THEN 1009 | dbms_sql.define_array( g_cursor_info.cursor_id, c, g_cursor_info.vc_tab, c_bulk_size, 1 ); 1010 | g_sql_columns(c).col_data_type := c_col_data_type_vc; 1011 | WHEN l_desc_tab( c ).col_type = 112 THEN 1012 | dbms_sql.define_array( g_cursor_info.cursor_id, c, g_cursor_info.clob_tab, c_bulk_size, 1 ); 1013 | g_sql_columns(c).col_data_type := c_col_data_type_clob; 1014 | ELSE 1015 | NULL; 1016 | END CASE; 1017 | 1018 | IF g_col_settings.exists(l_desc_tab(c).col_name) THEN 1019 | IF g_col_settings(l_desc_tab(c).col_name).is_visible THEN -- remove hidden cols 1020 | g_xlsx_options.display_column_count := g_xlsx_options.display_column_count + 1; -- count number of displayed columns 1021 | g_sql_columns(c).is_displayed := TRUE; 1022 | g_sql_columns(c).col_type := c_display_column; 1023 | g_col_settings(l_desc_tab(c).col_name).sql_col_num := c; -- column in SQL 1024 | g_col_settings(l_desc_tab(c).col_name).display_column := g_xlsx_options.display_column_count; -- column in spreadsheet 1025 | END IF; 1026 | ELSIF g_row_highlights.EXISTS(l_desc_tab(c).col_name) THEN 1027 | g_row_highlights(l_desc_tab(c).col_name).col_num := c; 1028 | g_sql_columns(c).col_type := c_row_highlight; 1029 | ELSIF g_col_highlights.EXISTS(l_desc_tab(c).col_name) THEN 1030 | g_col_highlights(l_desc_tab(c).col_name).col_num := c; 1031 | g_sql_columns(c).col_type := c_column_highlight; 1032 | l_cur_col_highlight := g_col_highlights(l_desc_tab(c).col_name); 1033 | g_col_settings(l_cur_col_highlight.affected_column).highlight_conds(l_desc_tab(c).col_name) := l_cur_col_highlight; 1034 | ELSIF l_desc_tab(c).col_name = c_break_definition THEN 1035 | g_sql_columns(c).col_type := c_break_definition; 1036 | g_apex_ir_info.break_def_column := c; 1037 | END IF; 1038 | $IF NOT $$PLSQL_DEBUG $THEN 1039 | EXCEPTION 1040 | WHEN OTHERS THEN 1041 | apex_debug.error(p_message => 'Error for column: %s', p0 => l_desc_tab(c).col_name); 1042 | apex_debug.error(p_message => 'Backtrace: %s', p0 => dbms_utility.format_error_backtrace); 1043 | RAISE; 1044 | $END 1045 | END; 1046 | END LOOP; 1047 | END prepare_cursor; 1048 | 1049 | /** 1050 | * Prints the column headings. 1051 | */ 1052 | PROCEDURE print_column_headers 1053 | AS 1054 | BEGIN 1055 | xlsx_builder_pkg.set_row( p_row => g_current_disp_row 1056 | , p_alignment => xlsx_builder_pkg.get_alignment( p_vertical => 'center' 1057 | , p_horizontal => 'center' 1058 | , p_wrapText => NULLIF(g_xlsx_options.allow_wrap_text, TRUE) 1059 | ) 1060 | , p_fontId => xlsx_builder_pkg.get_font( p_name => g_xlsx_options.default_font 1061 | , p_bold => TRUE 1062 | ) 1063 | , p_fillId => xlsx_builder_pkg.get_fill( p_patterntype => 'solid' 1064 | , p_fgRGB => 'FFF8DC' 1065 | ) 1066 | , p_borderId => xlsx_builder_pkg.get_border('thin', 'thin', 'thin', 'thin') 1067 | , p_sheet => g_xlsx_options.sheet 1068 | ); 1069 | FOR c IN 1..g_cursor_info.column_count LOOP 1070 | IF g_sql_columns(c).is_displayed THEN 1071 | xlsx_builder_pkg.cell( p_col => g_col_settings(g_sql_columns(c).col_name).display_column 1072 | , p_row => g_current_disp_row 1073 | , p_value => REPLACE(g_col_settings(g_sql_columns(c).col_name).report_label, g_xlsx_options.original_line_break, g_xlsx_options.replace_line_break) 1074 | , p_sheet => g_xlsx_options.sheet 1075 | ); 1076 | IF g_xlsx_options.col_hdr_help THEN 1077 | IF g_col_settings(g_sql_columns(c).col_name).help_text IS NOT NULL THEN 1078 | xlsx_builder_pkg.COMMENT( p_col => g_col_settings(g_sql_columns(c).col_name).display_column 1079 | , p_row => g_current_disp_row 1080 | , p_text => REPLACE(g_col_settings(g_sql_columns(c).col_name).help_text, g_xlsx_options.original_line_break, g_xlsx_options.replace_line_break) 1081 | , p_author => 'Help' 1082 | , p_sheet => g_xlsx_options.sheet 1083 | ); 1084 | END IF; 1085 | END IF; 1086 | END IF; 1087 | END LOOP; 1088 | g_current_disp_row := g_current_disp_row + 1; 1089 | END print_column_headers; 1090 | 1091 | /** 1092 | * Checks column highlights for specified column and marks them active if condition is met. 1093 | * @param p_column_name The current column to check 1094 | * @param p_fetched_row_cnt Amount of rows fetched 1095 | */ 1096 | FUNCTION process_col_highlights ( p_column_name IN VARCHAR2 1097 | , p_fetched_row_cnt IN PLS_INTEGER 1098 | ) 1099 | RETURN apexir_xlsx_types_pkg.t_apex_ir_active_hl 1100 | AS 1101 | l_cur_hl_name VARCHAR2(30); 1102 | l_cur_col_highlight apexir_xlsx_types_pkg.t_apex_ir_highlight; 1103 | retval apexir_xlsx_types_pkg.t_apex_ir_active_hl; 1104 | l_col_hl_value dbms_sql.number_table; 1105 | BEGIN 1106 | l_cur_hl_name := g_col_settings(p_column_name).highlight_conds.FIRST; 1107 | WHILE (l_cur_hl_name IS NOT NULL) LOOP 1108 | l_cur_col_highlight := g_col_settings(p_column_name).highlight_conds(l_cur_hl_name); 1109 | dbms_sql.COLUMN_VALUE( g_cursor_info.cursor_id, l_cur_col_highlight.col_num, l_col_hl_value); 1110 | FOR i IN 0 .. p_fetched_row_cnt - 1 LOOP 1111 | -- highlight condition TRUE 1112 | IF l_col_hl_value(i + l_col_hl_value.FIRST()) IS NOT NULL THEN 1113 | -- no previous highlight condition matched 1114 | IF NOT retval.EXISTS(i) THEN 1115 | retval(i) := l_cur_col_highlight; 1116 | END IF; 1117 | END IF; 1118 | END LOOP; 1119 | l_col_hl_value.DELETE; 1120 | l_cur_hl_name := g_col_settings(p_column_name).highlight_conds.next(l_cur_hl_name); 1121 | END LOOP; 1122 | RETURN retval; 1123 | END process_col_highlights; 1124 | 1125 | /** 1126 | * Prints the defined aggregates for a column 1127 | * @param p_column_name The current column to run the aggregates 1128 | * @param p_fetched_row_cnt Amount of rows fetched 1129 | */ 1130 | PROCEDURE print_aggregates ( p_column_name IN VARCHAR2 1131 | , p_fetched_row_cnt IN PLS_INTEGER 1132 | ) 1133 | AS 1134 | l_aggregate_values dbms_sql.number_table; 1135 | l_cur_aggregate_name VARCHAR2(30); 1136 | l_aggregate_offset PLS_INTEGER := 1; 1137 | BEGIN 1138 | IF NOT ( g_col_settings(p_column_name).is_break_col 1139 | OR g_col_settings(p_column_name).display_column = g_apex_ir_info.aggregate_type_disp_column 1140 | ) 1141 | THEN -- exclude break cols 1142 | -- fixed order for aggregates, same as occurence in t_apexir_col type 1143 | l_cur_aggregate_name := g_apex_ir_info.active_aggregates.FIRST(); 1144 | WHILE (l_cur_aggregate_name IS NOT NULL) LOOP 1145 | IF g_col_settings(p_column_name).aggregates.EXISTS(l_cur_aggregate_name) THEN 1146 | dbms_sql.COLUMN_VALUE( g_cursor_info.cursor_id 1147 | , g_col_settings(p_column_name).aggregates(l_cur_aggregate_name).col_num 1148 | , l_aggregate_values 1149 | ); 1150 | END IF; 1151 | FOR i IN 0 .. p_fetched_row_cnt - 1 loop 1152 | IF ( g_apex_ir_info.aggregate_type_disp_column > 1 1153 | AND g_cursor_info.break_rows(g_current_sql_row + i + 1) != g_cursor_info.break_rows(g_current_sql_row + i) 1154 | ) 1155 | OR ( g_apex_ir_info.aggregate_type_disp_column = 1 1156 | AND p_fetched_row_cnt <= c_bulk_size 1157 | AND i = p_fetched_row_cnt - 1 1158 | ) --last row 1159 | THEN 1160 | xlsx_builder_pkg.cell( p_col => g_col_settings(p_column_name).display_column 1161 | , p_row => g_current_disp_row + i + g_cursor_info.break_rows(g_current_sql_row + i) + l_aggregate_offset 1162 | , p_value => CASE 1163 | WHEN NOT g_col_settings(p_column_name).aggregates.EXISTS(l_cur_aggregate_name) 1164 | THEN TO_NUMBER(NULL) 1165 | WHEN i = 0 AND g_current_sql_row > 1 1166 | THEN g_col_settings(p_column_name).aggregates(l_cur_aggregate_name).last_value 1167 | ELSE l_aggregate_values( i + l_aggregate_values.FIRST() ) 1168 | END 1169 | , p_numFmtId => xlsx_builder_pkg.get_numFmt(xlsx_builder_pkg.OraNumFmt2Excel(g_col_settings(p_column_name).format_mask)) 1170 | , p_sheet => g_xlsx_options.sheet 1171 | ); 1172 | END IF; 1173 | IF g_col_settings(p_column_name).aggregates.EXISTS(l_cur_aggregate_name) THEN 1174 | g_col_settings(p_column_name).aggregates(l_cur_aggregate_name).last_value := l_aggregate_values( i + l_aggregate_values.FIRST() ); 1175 | END IF; 1176 | END LOOP row_loop; 1177 | l_aggregate_offset := l_aggregate_offset + 1; 1178 | l_cur_aggregate_name := g_apex_ir_info.active_aggregates.NEXT(l_cur_aggregate_name); 1179 | l_aggregate_values.DELETE; 1180 | END LOOP aggregate_loop; 1181 | END IF; 1182 | END print_aggregates; 1183 | 1184 | /** 1185 | * Print column of type NUMBER. 1186 | * @param p_column_name Current column 1187 | * @param p_fetched_row_cnt Amount of rows fetched 1188 | * @param p_active_highlights Array of column highlights where condition was met. 1189 | */ 1190 | PROCEDURE print_num_column ( p_column_name IN VARCHAR2 1191 | , p_fetched_row_cnt IN PLS_INTEGER 1192 | , p_active_highlights IN apexir_xlsx_types_pkg.t_apex_ir_active_hl 1193 | ) 1194 | AS 1195 | l_col_values dbms_sql.number_table; 1196 | BEGIN 1197 | dbms_sql.COLUMN_VALUE( g_cursor_info.cursor_id, g_col_settings(p_column_name).sql_col_num, l_col_values ); 1198 | FOR i IN 0 .. p_fetched_row_cnt - 1 loop 1199 | xlsx_builder_pkg.cell( p_col => g_col_settings(p_column_name).display_column 1200 | , p_row => g_current_disp_row + i + g_cursor_info.break_rows(g_current_sql_row + i) 1201 | , p_value => l_col_values( i + l_col_values.FIRST() ) 1202 | , p_numFmtId => xlsx_builder_pkg.get_numFmt(xlsx_builder_pkg.OraNumFmt2Excel(g_col_settings(p_column_name).format_mask)) 1203 | , p_fontId => CASE 1204 | WHEN p_active_highlights.EXISTS(i) AND p_active_highlights(i).font_color IS NOT NULL THEN 1205 | xlsx_builder_pkg.get_font( p_name => g_xlsx_options.default_font 1206 | , p_rgb => p_active_highlights(i).font_color 1207 | ) 1208 | ELSE NULL 1209 | END 1210 | , p_fillId => CASE 1211 | WHEN p_active_highlights.EXISTS(i) AND p_active_highlights(i).bg_color IS NOT NULL THEN 1212 | xlsx_builder_pkg.get_fill( p_patternType => 'solid' 1213 | , p_fgRGB => p_active_highlights(i).bg_color 1214 | ) 1215 | ELSE NULL 1216 | END 1217 | , p_sheet => g_xlsx_options.sheet 1218 | ); 1219 | IF g_xlsx_options.show_aggregates AND g_apex_ir_info.aggregate_type_disp_column > g_col_settings(p_column_name).display_column THEN 1220 | IF (i = p_fetched_row_cnt AND p_fetched_row_cnt < c_bulk_size) 1221 | OR g_cursor_info.break_rows(g_current_sql_row + i + 1) != g_cursor_info.break_rows(g_current_sql_row + i) 1222 | THEN 1223 | FOR j IN 1..g_apex_ir_info.active_aggregates.count LOOP 1224 | xlsx_builder_pkg.cell( p_col => g_col_settings(p_column_name).display_column 1225 | , p_row => g_current_disp_row + i + g_cursor_info.break_rows(g_current_sql_row + i) + j 1226 | , p_value => CASE 1227 | WHEN g_col_settings(p_column_name).is_break_col 1228 | THEN l_col_values( i + l_col_values.FIRST() ) 1229 | ELSE NULL 1230 | END 1231 | , p_sheet => g_xlsx_options.sheet 1232 | ); 1233 | END LOOP; 1234 | END IF; 1235 | END IF; 1236 | END loop; 1237 | IF g_xlsx_options.show_aggregates THEN 1238 | print_aggregates(p_column_name, p_fetched_row_cnt); 1239 | END IF; 1240 | l_col_values.DELETE; 1241 | END print_num_column; 1242 | 1243 | /** 1244 | * Prints a column of data type DATE. 1245 | * @param p_column_name Current column 1246 | * @param p_fetched_row_cnt Amount of rows fetched 1247 | * @param p_active_highlights Array of column highlights where condition was met 1248 | */ 1249 | PROCEDURE print_date_column ( p_column_name IN VARCHAR2 1250 | , p_fetched_row_cnt IN PLS_INTEGER 1251 | , p_active_highlights IN apexir_xlsx_types_pkg.t_apex_ir_active_hl 1252 | ) 1253 | AS 1254 | l_col_values dbms_sql.date_table; 1255 | BEGIN 1256 | dbms_sql.COLUMN_VALUE( g_cursor_info.cursor_id, g_col_settings(p_column_name).sql_col_num, l_col_values ); 1257 | FOR i IN 0 .. p_fetched_row_cnt - 1 loop 1258 | xlsx_builder_pkg.cell( p_col => g_col_settings(p_column_name).display_column 1259 | , p_row => g_current_disp_row + i + g_cursor_info.break_rows(g_current_sql_row + i) 1260 | , p_value => l_col_values( i + l_col_values.FIRST() ) 1261 | , p_numFmtId => xlsx_builder_pkg.get_numFmt(xlsx_builder_pkg.OraFmt2Excel(COALESCE(g_col_settings(p_column_name).format_mask, g_xlsx_options.default_date_format))) 1262 | , p_fontId => CASE 1263 | WHEN p_active_highlights.EXISTS(i) AND p_active_highlights(i).font_color IS NOT NULL THEN 1264 | xlsx_builder_pkg.get_font( p_name => g_xlsx_options.default_font 1265 | , p_rgb => p_active_highlights(i).font_color 1266 | ) 1267 | ELSE NULL 1268 | END 1269 | , p_fillId => CASE 1270 | WHEN p_active_highlights.EXISTS(i) AND p_active_highlights(i).bg_color IS NOT NULL THEN 1271 | xlsx_builder_pkg.get_fill( p_patternType => 'solid' 1272 | , p_fgRGB => p_active_highlights(i).bg_color 1273 | ) 1274 | ELSE NULL 1275 | END 1276 | , p_sheet => g_xlsx_options.sheet 1277 | ); 1278 | IF g_xlsx_options.show_aggregates AND g_apex_ir_info.aggregate_type_disp_column > g_col_settings(p_column_name).display_column THEN 1279 | IF (i = p_fetched_row_cnt AND p_fetched_row_cnt < c_bulk_size) 1280 | OR g_cursor_info.break_rows(g_current_sql_row + i + 1) != g_cursor_info.break_rows(g_current_sql_row + i) 1281 | THEN 1282 | FOR j IN 1..g_apex_ir_info.active_aggregates.count LOOP 1283 | xlsx_builder_pkg.cell( p_col => g_col_settings(p_column_name).display_column 1284 | , p_row => g_current_disp_row + i + g_cursor_info.break_rows(g_current_sql_row + i) + j 1285 | , p_value => CASE 1286 | WHEN g_col_settings(p_column_name).is_break_col 1287 | THEN l_col_values( i + l_col_values.FIRST() ) 1288 | ELSE NULL 1289 | END 1290 | , p_sheet => g_xlsx_options.sheet 1291 | ); 1292 | END LOOP; 1293 | END IF; 1294 | END IF; 1295 | END LOOP; 1296 | IF g_xlsx_options.show_aggregates THEN 1297 | print_aggregates(p_column_name, p_fetched_row_cnt); 1298 | END IF; 1299 | l_col_values.DELETE; 1300 | END print_date_column; 1301 | 1302 | /** 1303 | * Prints a column of data type VARCHAR. 1304 | * @param p_column_name Current column 1305 | * @param p_fetched_row_cnt Amount of rows fetched 1306 | * @param p_active_highlights Array of column highlights where condition was met 1307 | */ 1308 | PROCEDURE print_vc_column ( p_column_name IN VARCHAR2 1309 | , p_fetched_row_cnt IN PLS_INTEGER 1310 | , p_active_highlights IN apexir_xlsx_types_pkg.t_apex_ir_active_hl 1311 | ) 1312 | AS 1313 | l_col_values dbms_sql.varchar2_table; 1314 | BEGIN 1315 | dbms_sql.COLUMN_VALUE( g_cursor_info.cursor_id, g_col_settings(p_column_name).sql_col_num, l_col_values ); 1316 | FOR i IN 0 .. p_fetched_row_cnt - 1 loop 1317 | xlsx_builder_pkg.cell( p_col => g_col_settings(p_column_name).display_column 1318 | , p_row => g_current_disp_row + i + g_cursor_info.break_rows(g_current_sql_row + i) 1319 | , p_value => REPLACE(l_col_values(i + l_col_values.FIRST()), g_xlsx_options.original_line_break, g_xlsx_options.replace_line_break) 1320 | , p_alignment => CASE WHEN g_xlsx_options.allow_wrap_text THEN NULL ELSE xlsx_builder_pkg.get_alignment(p_wrapText => FALSE) END 1321 | , p_fontId => CASE 1322 | WHEN p_active_highlights.EXISTS(i) AND p_active_highlights(i).font_color IS NOT NULL THEN 1323 | xlsx_builder_pkg.get_font( p_name => g_xlsx_options.default_font 1324 | , p_rgb => p_active_highlights(i).font_color 1325 | ) 1326 | ELSE NULL 1327 | END 1328 | , p_fillId => CASE 1329 | WHEN p_active_highlights.EXISTS(i) AND p_active_highlights(i).bg_color IS NOT NULL THEN 1330 | xlsx_builder_pkg.get_fill( p_patternType => 'solid' 1331 | , p_fgRGB => p_active_highlights(i).bg_color 1332 | ) 1333 | ELSE NULL 1334 | END 1335 | , p_sheet => g_xlsx_options.sheet 1336 | ); 1337 | IF g_xlsx_options.show_aggregates AND g_apex_ir_info.aggregate_type_disp_column > g_col_settings(p_column_name).display_column THEN 1338 | IF (i = p_fetched_row_cnt AND p_fetched_row_cnt < c_bulk_size) 1339 | OR g_cursor_info.break_rows(g_current_sql_row + i + 1) != g_cursor_info.break_rows(g_current_sql_row + i) 1340 | THEN 1341 | FOR j IN 1..g_apex_ir_info.active_aggregates.count LOOP 1342 | xlsx_builder_pkg.cell( p_col => g_col_settings(p_column_name).display_column 1343 | , p_row => g_current_disp_row + i + g_cursor_info.break_rows(g_current_sql_row + i) + j 1344 | , p_value => CASE 1345 | WHEN g_col_settings(p_column_name).is_break_col 1346 | THEN REPLACE(l_col_values(i + l_col_values.FIRST()), g_xlsx_options.original_line_break, g_xlsx_options.replace_line_break) 1347 | ELSE NULL 1348 | END 1349 | , p_alignment => CASE WHEN g_xlsx_options.allow_wrap_text THEN NULL ELSE xlsx_builder_pkg.get_alignment(p_wrapText => FALSE) END 1350 | , p_sheet => g_xlsx_options.sheet 1351 | ); 1352 | END LOOP; 1353 | END IF; 1354 | END IF; 1355 | END LOOP; 1356 | IF g_xlsx_options.show_aggregates THEN 1357 | print_aggregates(p_column_name, p_fetched_row_cnt); 1358 | END IF; 1359 | l_col_values.DELETE; 1360 | END print_vc_column; 1361 | 1362 | /** 1363 | * Prints a column of data type CLOB. 1364 | * Value is converted to VARCHAR2, therefore standard limitation of VARCAHR2 applies. 1365 | * If CLOB is too long value is simply truncated. 1366 | * @param p_column_name Current column 1367 | * @param p_fetched_row_cnt Amount of rows fetched 1368 | * @param p_active_highlights Array of column highlights where condition was met 1369 | */ 1370 | PROCEDURE print_clob_column ( p_column_name IN VARCHAR2 1371 | , p_fetched_row_cnt IN PLS_INTEGER 1372 | , p_active_highlights IN apexir_xlsx_types_pkg.t_apex_ir_active_hl 1373 | ) 1374 | AS 1375 | l_col_values dbms_sql.clob_table; 1376 | BEGIN 1377 | dbms_sql.COLUMN_VALUE( g_cursor_info.cursor_id, g_col_settings(p_column_name).sql_col_num, l_col_values ); 1378 | FOR i IN 0 .. p_fetched_row_cnt - 1 loop 1379 | xlsx_builder_pkg.cell( p_col => g_col_settings(p_column_name).display_column 1380 | , p_row => g_current_disp_row + i + g_cursor_info.break_rows(g_current_sql_row + i) 1381 | , p_value => REPLACE(dbms_lob.substr(l_col_values(i + l_col_values.FIRST())), g_xlsx_options.original_line_break, g_xlsx_options.replace_line_break) 1382 | , p_alignment => CASE WHEN g_xlsx_options.allow_wrap_text THEN NULL ELSE xlsx_builder_pkg.get_alignment(p_wrapText => FALSE) END 1383 | , p_fontId => CASE 1384 | WHEN p_active_highlights.EXISTS(i) AND p_active_highlights(i).font_color IS NOT NULL THEN 1385 | xlsx_builder_pkg.get_font( p_name => g_xlsx_options.default_font 1386 | , p_rgb => p_active_highlights(i).font_color 1387 | ) 1388 | ELSE NULL 1389 | END 1390 | , p_fillId => CASE 1391 | WHEN p_active_highlights.EXISTS(i) AND p_active_highlights(i).bg_color IS NOT NULL THEN 1392 | xlsx_builder_pkg.get_fill( p_patternType => 'solid' 1393 | , p_fgRGB => p_active_highlights(i).bg_color 1394 | ) 1395 | ELSE NULL 1396 | END 1397 | , p_sheet => g_xlsx_options.sheet 1398 | ); 1399 | IF g_xlsx_options.show_aggregates AND g_apex_ir_info.aggregate_type_disp_column != g_col_settings(p_column_name).display_column THEN 1400 | IF (i = p_fetched_row_cnt AND p_fetched_row_cnt < c_bulk_size) 1401 | OR g_cursor_info.break_rows(g_current_sql_row + i + 1) != g_cursor_info.break_rows(g_current_sql_row + i) 1402 | THEN 1403 | FOR j IN 1..g_apex_ir_info.active_aggregates.count LOOP 1404 | xlsx_builder_pkg.cell( p_col => g_col_settings(p_column_name).display_column 1405 | , p_row => g_current_disp_row + i + g_cursor_info.break_rows(g_current_sql_row + i) + j 1406 | , p_value => CASE 1407 | WHEN g_col_settings(p_column_name).is_break_col 1408 | THEN REPLACE(dbms_lob.substr(l_col_values(i + l_col_values.FIRST())), g_xlsx_options.original_line_break, g_xlsx_options.replace_line_break) 1409 | ELSE NULL 1410 | END 1411 | , p_alignment => CASE WHEN g_xlsx_options.allow_wrap_text THEN NULL ELSE xlsx_builder_pkg.get_alignment(p_wrapText => FALSE) END 1412 | , p_sheet => g_xlsx_options.sheet 1413 | ); 1414 | END LOOP; 1415 | END IF; 1416 | END IF; 1417 | END LOOP; 1418 | IF g_xlsx_options.show_aggregates THEN 1419 | print_aggregates(p_column_name, p_fetched_row_cnt); 1420 | END IF; 1421 | l_col_values.DELETE; 1422 | END print_clob_column; 1423 | 1424 | /** 1425 | * Prints the used aggregate types given a control break. 1426 | * @param p_row_offset Additional row offset to place aggregate types 1427 | */ 1428 | PROCEDURE print_aggregate_types (p_row_offset IN PLS_INTEGER) 1429 | AS 1430 | l_cur_aggregate_type VARCHAR2(30); 1431 | l_cnt PLS_INTEGER := 0; 1432 | BEGIN 1433 | l_cur_aggregate_type := g_apex_ir_info.active_aggregates.FIRST(); 1434 | WHILE (l_cur_aggregate_type IS NOT NULL) LOOP 1435 | xlsx_builder_pkg.set_row( p_row => g_current_disp_row + p_row_offset + l_cnt 1436 | , p_fontId => xlsx_builder_pkg.get_font( p_name => g_xlsx_options.default_font 1437 | , p_bold => TRUE 1438 | ) 1439 | , p_fillId => xlsx_builder_pkg.get_fill( p_patternType => 'solid' 1440 | , p_fgRGB => 'FFF8DC' 1441 | ) 1442 | , p_alignment => xlsx_builder_pkg.get_alignment( p_wrapText => NULLIF(g_xlsx_options.allow_wrap_text, TRUE) ) 1443 | , p_sheet => g_xlsx_options.sheet 1444 | ); 1445 | 1446 | xlsx_builder_pkg.cell( p_col => g_apex_ir_info.aggregate_type_disp_column 1447 | , p_row => g_current_disp_row + p_row_offset + l_cnt 1448 | , p_value => l_cur_aggregate_type 1449 | , p_sheet => g_xlsx_options.sheet 1450 | ); 1451 | l_cnt := l_cnt + 1; 1452 | l_cur_aggregate_type := g_apex_ir_info.active_aggregates.next(l_cur_aggregate_type); 1453 | END LOOP; 1454 | END print_aggregate_types; 1455 | 1456 | /** 1457 | * Checks for any control breaks in current fetch and populates global variable. 1458 | * @param p_fetched_row_cnt Amount of rows fetched 1459 | */ 1460 | PROCEDURE process_break_rows (p_fetched_row_cnt IN PLS_INTEGER) 1461 | AS 1462 | l_cnt NUMBER := 0; 1463 | l_break_values dbms_sql.varchar2_table; 1464 | l_cur_break_val VARCHAR2(32767); 1465 | BEGIN 1466 | IF NOT g_cursor_info.break_rows.EXISTS(g_current_sql_row) THEN 1467 | g_cursor_info.break_rows(g_current_sql_row) := 0; 1468 | END IF; 1469 | IF g_xlsx_options.show_aggregates AND g_apex_ir_info.break_def_column IS NOT NULL THEN 1470 | DBMS_SQL.COLUMN_VALUE( g_cursor_info.cursor_id, g_apex_ir_info.break_def_column, l_break_values); 1471 | FOR i IN 0..p_fetched_row_cnt - 1 LOOP 1472 | l_cur_break_val := l_break_values(i + l_break_values.FIRST()); 1473 | IF l_cur_break_val != g_cursor_info.prev_break_val THEN 1474 | print_aggregate_types(i + l_cnt); 1475 | l_cnt := l_cnt + g_apex_ir_info.active_aggregates.count; 1476 | END IF; 1477 | g_cursor_info.prev_break_val := l_break_values(i + l_break_values.FIRST()); 1478 | g_cursor_info.break_rows(g_current_sql_row + i) := l_cnt; 1479 | END LOOP; 1480 | IF p_fetched_row_cnt < c_bulk_size THEN 1481 | g_cursor_info.break_rows(g_current_sql_row + p_fetched_row_cnt) := l_cnt + g_apex_ir_info.active_aggregates.count; 1482 | print_aggregate_types(p_fetched_row_cnt + l_cnt); 1483 | ELSE 1484 | g_cursor_info.break_rows(g_current_sql_row + p_fetched_row_cnt) := l_cnt + 1; 1485 | END IF; 1486 | l_break_values.DELETE; 1487 | ELSE 1488 | FOR i IN 1..p_fetched_row_cnt + 1 LOOP 1489 | g_cursor_info.break_rows(g_current_sql_row + i) := l_cnt; 1490 | END LOOP; 1491 | IF p_fetched_row_cnt < c_bulk_size AND g_xlsx_options.show_aggregates THEN 1492 | print_aggregate_types(p_fetched_row_cnt + l_cnt); 1493 | END IF; 1494 | END IF; 1495 | END process_break_rows; 1496 | 1497 | /** 1498 | * Wrapper for all procedures printing data. 1499 | * Calls the building blocks in the right order and provides the overall control structure. 1500 | */ 1501 | PROCEDURE print_data 1502 | AS 1503 | l_cur_col_name VARCHAR2(4000); 1504 | l_fetched_row_cnt PLS_INTEGER; 1505 | l_active_col_highlights apexir_xlsx_types_pkg.t_apex_ir_active_hl; 1506 | BEGIN 1507 | l_fetched_row_cnt := dbms_sql.execute( g_cursor_info.cursor_id ); 1508 | LOOP 1509 | l_fetched_row_cnt := dbms_sql.fetch_rows( g_cursor_info.cursor_id ); 1510 | IF l_fetched_row_cnt > 0 THEN 1511 | -- new calculation for every bulk set 1512 | process_break_rows( p_fetched_row_cnt => l_fetched_row_cnt ); 1513 | process_row_highlights( p_fetched_row_cnt => l_fetched_row_cnt ); 1514 | FOR c IN 1..g_cursor_info.column_count LOOP 1515 | IF g_sql_columns(c).is_displayed THEN 1516 | -- next display column, empty active highlights 1517 | l_active_col_highlights.DELETE; 1518 | -- check if highlight processing is enabled and column has highlights attached 1519 | IF g_xlsx_options.process_highlights AND 1520 | g_col_settings(g_sql_columns(c).col_name).highlight_conds.count() > 0 1521 | THEN 1522 | l_active_col_highlights := process_col_highlights( p_column_name => g_sql_columns(c).col_name 1523 | , p_fetched_row_cnt => l_fetched_row_cnt 1524 | ); 1525 | END IF; 1526 | 1527 | -- now create the cells 1528 | CASE 1529 | WHEN g_sql_columns(c).col_data_type = c_col_data_type_num THEN 1530 | print_num_column( p_column_name => g_sql_columns(c).col_name 1531 | , p_fetched_row_cnt => l_fetched_row_cnt 1532 | , p_active_highlights => l_active_col_highlights 1533 | ); 1534 | WHEN g_sql_columns(c).col_data_type = c_col_data_type_date THEN 1535 | print_date_column( p_column_name => g_sql_columns(c).col_name 1536 | , p_fetched_row_cnt => l_fetched_row_cnt 1537 | , p_active_highlights => l_active_col_highlights 1538 | ); 1539 | WHEN g_sql_columns(c).col_data_type = c_col_data_type_vc THEN 1540 | print_vc_column( p_column_name => g_sql_columns(c).col_name 1541 | , p_fetched_row_cnt => l_fetched_row_cnt 1542 | , p_active_highlights => l_active_col_highlights 1543 | ); 1544 | WHEN g_sql_columns(c).col_data_type = c_col_data_type_clob THEN 1545 | print_clob_column( p_column_name => g_sql_columns(c).col_name 1546 | , p_fetched_row_cnt => l_fetched_row_cnt 1547 | , p_active_highlights => l_active_col_highlights 1548 | ); 1549 | ELSE NULL; -- unsupported data type 1550 | END CASE; 1551 | END IF; 1552 | END LOOP; 1553 | END IF; 1554 | EXIT WHEN l_fetched_row_cnt != c_bulk_size; 1555 | g_current_sql_row := g_current_sql_row + l_fetched_row_cnt; 1556 | g_current_disp_row := g_current_disp_row + l_fetched_row_cnt + g_cursor_info.break_rows(g_current_sql_row - 1); 1557 | END LOOP; 1558 | dbms_sql.close_cursor( g_cursor_info.cursor_id ); 1559 | END print_data; 1560 | 1561 | FUNCTION get_report_id 1562 | RETURN NUMBER 1563 | AS 1564 | l_region_id NUMBER; 1565 | BEGIN 1566 | SELECT region_id 1567 | INTO l_region_id 1568 | FROM apex_application_page_ir 1569 | WHERE application_id = g_apex_ir_info.application_id 1570 | AND page_id = g_apex_ir_info.page_id; 1571 | RETURN l_region_id; 1572 | EXCEPTION 1573 | WHEN TOO_MANY_ROWS THEN 1574 | apex_debug.ERROR( p_message => 'WARNING: More than 1 IR Region on page %s, choose p_ir_region_id!' 1575 | , p0 => TO_CHAR (g_apex_ir_info.page_id) 1576 | ); 1577 | raise_application_error( num => -20002 1578 | , msg => 'Error retrieving Region ID, check APEX Debug Messages!' 1579 | ); 1580 | WHEN NO_DATA_FOUND THEN 1581 | apex_debug.ERROR( p_message => 'WARNING: There is NO IR Region on page %s!' 1582 | , p0 => TO_CHAR (g_apex_ir_info.page_id) 1583 | ); 1584 | raise_application_error( num => -20002 1585 | , msg => 'Error retrieving Region ID, check APEX Debug Messages!' 1586 | ); 1587 | END get_report_id; 1588 | 1589 | FUNCTION apexir2sheet 1590 | ( p_ir_region_id NUMBER := NULL 1591 | , p_app_id NUMBER := NV('APP_ID') 1592 | , p_ir_page_id NUMBER := NV('APP_PAGE_ID') 1593 | , p_ir_session_id NUMBER := NV('SESSION') 1594 | , p_ir_request VARCHAR2 := V('REQUEST') 1595 | , p_ir_view_mode VARCHAR2 := NULL 1596 | , p_column_headers BOOLEAN := TRUE 1597 | , p_col_hdr_help BOOLEAN := TRUE 1598 | , p_freeze_col_hdr BOOLEAN := FALSE 1599 | , p_aggregates IN BOOLEAN := TRUE 1600 | , p_process_highlights IN BOOLEAN := TRUE 1601 | , p_show_report_title IN BOOLEAN := TRUE 1602 | , p_show_filters IN BOOLEAN := TRUE 1603 | , p_include_page_items IN BOOLEAN := FALSE 1604 | , p_show_highlights IN BOOLEAN := TRUE 1605 | , p_original_line_break IN VARCHAR2 := '
' 1606 | , p_replace_line_break IN VARCHAR2 := chr(13) || chr(10) 1607 | , p_filter_replacement IN VARCHAR2 := ' ' 1608 | , p_append_date IN BOOLEAN := TRUE 1609 | , p_append_date_fmt IN VARCHAR2 := 'YYYYMMDD' 1610 | ) 1611 | RETURN apexir_xlsx_types_pkg.t_returnvalue 1612 | AS 1613 | l_retval apexir_xlsx_types_pkg.t_returnvalue; 1614 | BEGIN 1615 | -- IR infos 1616 | g_apex_ir_info.application_id := p_app_id; 1617 | g_apex_ir_info.page_id := p_ir_page_id; 1618 | g_apex_ir_info.session_id := p_ir_session_id; 1619 | g_apex_ir_info.region_id := COALESCE( p_ir_region_id, get_report_id ); 1620 | g_apex_ir_info.request := p_ir_request; 1621 | g_apex_ir_info.base_report_id := apex_ir.get_last_viewed_report_id(p_page_id => g_apex_ir_info.page_id, p_region_id => g_apex_ir_info.region_id); -- set manual for test outside APEX Environment 1622 | g_apex_ir_info.report_definition := APEX_IR.GET_REPORT ( p_page_id => g_apex_ir_info.page_id, p_region_id => g_apex_ir_info.region_id); 1623 | apex_debug.message( p_message => 'Size of SQL statement is %s' 1624 | , p0 => LENGTH( g_apex_ir_info.report_definition.sql_query ) 1625 | ); 1626 | g_apex_ir_info.aggregates_offset := regexp_count(substr(g_apex_ir_info.report_definition.sql_query, 1, INSTR(UPPER(g_apex_ir_info.report_definition.sql_query), ') OVER (')), ','); 1627 | -- Fix the IR view mode if requested 1628 | IF p_ir_view_mode IN (c_ir_standard_view, c_ir_group_by_view) THEN 1629 | g_apex_ir_info.view_mode := p_ir_view_mode; 1630 | END IF; 1631 | 1632 | -- Generation Options 1633 | g_xlsx_options.show_aggregates := p_aggregates; 1634 | g_xlsx_options.process_highlights := p_process_highlights; 1635 | g_xlsx_options.show_title := p_show_report_title; 1636 | g_xlsx_options.show_filters := p_show_filters; 1637 | g_xlsx_options.include_page_items := p_include_page_items; 1638 | g_xlsx_options.show_highlights := p_show_highlights; 1639 | g_xlsx_options.show_column_headers := p_column_headers; 1640 | g_xlsx_options.col_hdr_help := p_col_hdr_help; 1641 | g_xlsx_options.freeze_column_headers := p_freeze_col_hdr; 1642 | g_xlsx_options.display_column_count := 0; -- shift result set to right if > 0 1643 | g_xlsx_options.default_font := 'Arial'; 1644 | g_xlsx_options.default_border_color := 'b0a070'; -- not yet implemented... 1645 | g_xlsx_options.allow_wrap_text := TRUE; 1646 | g_xlsx_options.original_line_break := p_original_line_break; 1647 | g_xlsx_options.replace_line_break := p_replace_line_break; 1648 | g_xlsx_options.filter_replacement := p_filter_replacement; 1649 | g_xlsx_options.append_date_file_name := p_append_date; 1650 | g_xlsx_options.requested_view_mode := p_ir_view_mode; 1651 | 1652 | -- retrieve IR infos 1653 | get_settings; 1654 | -- construct full SQL and prepare cursor 1655 | prepare_cursor; 1656 | 1657 | -- needed before running any xlsx_builder_pkg commands 1658 | g_xlsx_options.sheet := xlsx_builder_pkg.new_sheet( p_sheetname => g_apex_ir_info.view_mode ); 1659 | -- print header if any header option is enabled 1660 | IF g_xlsx_options.show_title OR g_xlsx_options.show_filters OR g_xlsx_options.show_highlights THEN 1661 | print_header; 1662 | END IF; 1663 | 1664 | -- print column headings if enabled 1665 | IF g_xlsx_options.show_column_headers THEN 1666 | print_column_headers; 1667 | IF g_xlsx_options.freeze_column_headers THEN 1668 | xlsx_builder_pkg.freeze_rows(g_current_disp_row-1); 1669 | END IF; 1670 | END IF; 1671 | 1672 | -- Generate the "real" data 1673 | print_data; 1674 | 1675 | -- show generated SQL statement in debug mode 1676 | apex_debug.log_long_message( p_message => 'Generated SQL: ' || g_apex_ir_info.final_sql 1677 | , p_level => apex_debug.c_log_level_info 1678 | ); 1679 | -- return the generated spreadsheet and file info 1680 | l_retval.file_content := xlsx_builder_pkg.FINISH; 1681 | l_retval.file_name := g_apex_ir_info.report_title 1682 | || CASE WHEN g_xlsx_options.append_date_file_name 1683 | THEN '_' || to_char(SYSDATE, p_append_date_fmt) 1684 | ELSE NULL 1685 | END 1686 | || '.xlsx'; 1687 | l_retval.mime_type := 'application/octet'; 1688 | l_retval.file_size := dbms_lob.getlength(l_retval.file_content); 1689 | RETURN l_retval; 1690 | $IF NOT $$PLSQL_DEBUG $THEN 1691 | EXCEPTION 1692 | WHEN column_not_found THEN 1693 | apex_debug.error( p_message => g_exception_info ); 1694 | raise_application_error(-20003, g_exception_info); 1695 | WHEN ir_def_not_found THEN 1696 | raise_application_error(-20004, g_exception_info); 1697 | WHEN OTHERS THEN 1698 | IF dbms_sql.is_open( g_cursor_info.cursor_id ) THEN 1699 | dbms_sql.close_cursor( g_cursor_info.cursor_id ); 1700 | END IF; 1701 | apex_debug.error( p_message => 'Unexpected error while generating file.' ); 1702 | apex_debug.error( p_message => 'Error Backtrace: %s' 1703 | , p0 => dbms_utility.format_error_backtrace 1704 | , p_max_length => 32000 1705 | ); 1706 | apex_debug.error( p_message => 'Error Stack: %s' 1707 | , p0 => dbms_utility.format_error_stack 1708 | , p_max_length => 32000 1709 | ); 1710 | apex_debug.error( p_message => 'Generated SQL: %s' 1711 | , p0 => g_apex_ir_info.final_sql 1712 | , p_max_length => 32000 1713 | ); 1714 | RAISE; 1715 | l_retval.error_encountered := TRUE; 1716 | RETURN l_retval; 1717 | $END 1718 | END apexir2sheet; 1719 | 1720 | PROCEDURE download 1721 | ( p_ir_region_id NUMBER := NULL 1722 | , p_app_id NUMBER := NV('APP_ID') 1723 | , p_ir_page_id NUMBER := NV('APP_PAGE_ID') 1724 | , p_ir_session_id NUMBER := NV('SESSION') 1725 | , p_ir_request VARCHAR2 := V('REQUEST') 1726 | , p_ir_view_mode VARCHAR2 := NULL 1727 | , p_column_headers BOOLEAN := TRUE 1728 | , p_col_hdr_help BOOLEAN := TRUE 1729 | , p_freeze_col_hdr BOOLEAN := FALSE 1730 | , p_aggregates IN BOOLEAN := TRUE 1731 | , p_process_highlights IN BOOLEAN := TRUE 1732 | , p_show_report_title IN BOOLEAN := TRUE 1733 | , p_show_filters IN BOOLEAN := TRUE 1734 | , p_include_page_items IN BOOLEAN := FALSE 1735 | , p_show_highlights IN BOOLEAN := TRUE 1736 | , p_original_line_break IN VARCHAR2 := '
' 1737 | , p_replace_line_break IN VARCHAR2 := chr(13) || chr(10) 1738 | , p_filter_replacement IN VARCHAR2 := ' ' 1739 | , p_append_date IN BOOLEAN := TRUE 1740 | , p_append_date_fmt IN VARCHAR2 := 'YYYYMMDD' 1741 | ) 1742 | AS 1743 | l_xlsx apexir_xlsx_types_pkg.t_returnvalue; 1744 | BEGIN 1745 | l_xlsx := apexir2sheet( p_ir_region_id => p_ir_region_id 1746 | , p_app_id => p_app_id 1747 | , p_ir_page_id => p_ir_page_id 1748 | , p_ir_session_id => p_ir_session_id 1749 | , p_ir_request => p_ir_request 1750 | , p_ir_view_mode => p_ir_view_mode 1751 | , p_column_headers => p_column_headers 1752 | , p_col_hdr_help => p_col_hdr_help 1753 | , p_freeze_col_hdr => p_freeze_col_hdr 1754 | , p_aggregates => p_aggregates 1755 | , p_process_highlights => p_process_highlights 1756 | , p_show_report_title => p_show_report_title 1757 | , p_show_filters => p_show_filters 1758 | , p_include_page_items => p_include_page_items 1759 | , p_show_highlights => p_show_highlights 1760 | , p_original_line_break => p_original_line_break 1761 | , p_replace_line_break => p_replace_line_break 1762 | , p_filter_replacement => p_filter_replacement 1763 | , p_append_date => p_append_date 1764 | , p_append_date_fmt => p_append_date_fmt 1765 | ); 1766 | IF NOT l_xlsx.error_encountered THEN 1767 | OWA_UTIL.mime_header( l_xlsx.mime_type, FALSE ); 1768 | HTP.P( 'Content-length: ' || l_xlsx.file_size ); 1769 | HTP.P( 'Content-Disposition: attachment; filename="' || l_xlsx.file_name || '"' ); 1770 | OWA_UTIL.http_header_close; 1771 | WPG_DOCLOAD.download_file( l_xlsx.file_content ); 1772 | ELSE 1773 | raise_application_error( -20001, 'Something went wrong while generating the file. :-(', true ); 1774 | END IF; 1775 | END download; 1776 | 1777 | FUNCTION get_version 1778 | RETURN VARCHAR2 1779 | AS 1780 | BEGIN 1781 | RETURN c_version; 1782 | END get_version; 1783 | 1784 | END APEXIR_XLSX_PKG; 1785 | 1786 | / 1787 | --------------------------------------------------------------------------------