├── LICENSE ├── README.md ├── apex_dml_collections ├── README.md ├── examples.sql └── install.sql ├── apex_lang_utils ├── README.md ├── apex_lang_utils.pkb └── apex_lang_utils.pks ├── apex_zip_utils ├── README.md ├── apex_zip_utils.pkb └── apex_zip_utils.pks ├── application └── f130.sql ├── dba_dictionary ├── README.md ├── dba_dictionary.sql ├── dba_docs.html └── generate_docs.sql └── lob_2_script ├── README.md ├── lob_2_script.pkb ├── lob_2_script.pks └── screens ├── screen.png ├── script01.png └── script02.png /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2024 Zoran Tica 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Various Oracle Database and Oracle APEX utilities 2 | In this repository You may find various Oracle Database and Oracle APEX utilities 3 | 4 | - [Oracle APEX - DML on Collections ](#oracle-apex---dml-on-collections) 5 | - [Oracle APEX - apex_lang_utils package ](#oracle-apex---apex_lang_utils-package) 6 | - [Oracle APEX - Lob 2 Script ](#oracle-apex---lob-2-script) 7 | - [Oracle APEX - apex_zip_utils package ](#oracle-apex---apex_zip_utils-package) 8 | 9 | ### History of changes: 10 | - 1.0 - created "Oracle APEX - DML On Collections" utility 11 | - 1.1 - created "apex_lang_utils" package 12 | - 1.2 - created "Lob 2 Script" utility 13 | - 1.3 - created "apex_zip_utils" utility 14 | 15 | ## Oracle APEX - DML on Collections 16 | This utility provides You the functionality to execute DML statements directly on APEX collections from pure SQL. No need for using PL/SQL APEX_COLLECTION API. This may come handy in various scenarios like using Interactive Grid for data editing or manipulating temporary data. 17 | 18 | Installation and examples scripts with instructions can be found in the folder [apex_dml_collections](https://github.com/zorantica/db_apex_utils/tree/main/apex_dml_collections). But simply... just create the package, view and trigger in the target schema and You're ready to go. 19 | 20 | Quick peek - if You want for example to populate the APEX collection with data from DEMO_CUSTOMERS table, You may execute the following INSERT statement: 21 | 22 | ```sql 23 | INSERT INTO apex_collections_dml ( 24 | collection_name, 25 | n001, --customer_id 26 | c001, --cust_first_name 27 | c002, --cust_last_name 28 | c003, --cust_street_address1 29 | c004, --cust_street_address2 30 | c005, --cust_city 31 | c006, --cust_state 32 | c007, --cust_postal_code 33 | c008, --cust_email 34 | c009, --phone_number1 35 | c010, --phone_number2 36 | c011, --url 37 | c012, --tag 38 | n002 --credit_limit 39 | ) 40 | SELECT 41 | 'DEMO_CUSTOMERS', 42 | customer_id, 43 | cust_first_name, 44 | cust_last_name, 45 | cust_street_address1, 46 | cust_street_address2, 47 | cust_city, 48 | cust_state, 49 | cust_postal_code, 50 | cust_email, 51 | phone_number1, 52 | phone_number2, 53 | url, 54 | tags, 55 | credit_limit 56 | FROM 57 | demo_customers 58 | ; 59 | ``` 60 | 61 | Or You may update the collection and change the credit limit for repeat customers by 10% like this: 62 | 63 | ```sql 64 | UPDATE apex_collections_dml 65 | SET 66 | n002 = n002 + (10 * n002 / 100) 67 | WHERE 68 | c012 = 'REPEAT CUSTOMER' 69 | AND collection_name = 'DEMO_CUSTOMERS' 70 | ; 71 | ``` 72 | 73 | Or delete all customers from "VA" state: 74 | 75 | ```sql 76 | DELETE apex_collections_dml 77 | WHERE 78 | collection_name = 'DEMO_CUSTOMERS' 79 | AND c006 = 'VA' 80 | ; 81 | ``` 82 | 83 | Do not forget to commit the changes :blush: 84 | 85 | ## Oracle APEX - apex_lang_utils package 86 | 87 | Compatible with the Oracle APEX vesrion 23.1 88 | 89 | Package installation scripts can be found in the folder [apex_lang_utils](https://github.com/zorantica/db_apex_utils/tree/main/apex_lang_utils). 90 | 91 | The package contains following program units: 92 | - a function get_xliff_per_page to export multiple XLIFF files for selected pages 93 | - a procedure apply_xliff_files to apply multiple XLIFF translation files stored in a single ZIP file 94 | 95 | ## Oracle APEX - LOB 2 Script 96 | Compatible with the Oracle APEX vesrion 19.2 97 | 98 | Package installation scripts can be found in the folder [lob_2_script](https://github.com/zorantica/db_apex_utils/tree/main/lob_2_script). 99 | 100 | Utility application can be found in the folder [application](https://github.com/zorantica/db_apex_utils/tree/main/application). 101 | 102 | The utility provides You functionality to create PL/SQL script from a binary file content (LOB).
103 | Produced script can be included in Your patches and executed on the target environment, storing the LOB content in the database table cell.
104 | It can be useful to move images, Word or Execl documents and other binary or large text files between various databases / environments.
105 | We use it often to include [APEX Office Print](#https://www.apexofficeprint.com/index.html) Word templates in patches. 106 | 107 | ## Oracle APEX - apex_zip_utils package 108 | 109 | Package installation scripts can be found in the folder [apex_zip_utils](https://github.com/zorantica/db_apex_utils/tree/main/apex_zip_utils). 110 | 111 | The package contains following program units: 112 | - a function unzip_pl to extract files and return them as a SQL dataset 113 | - a function unzip to extract files and return them as a nested table collection 114 | - a function unzip_ar to extract files and return them as a associative array collection 115 | -------------------------------------------------------------------------------- /apex_dml_collections/README.md: -------------------------------------------------------------------------------- 1 | # Oracle APEX - DML on Collections 2 | 3 | History of changes: 4 | - 1.0 - initial version 5 | 6 | ## Install instructions 7 | 8 | In the target schema create following objects. 9 | 10 | - create package spec and package body (apex_collections_dml_pkg) 11 | - create view (apex_collections_dml) 12 | - create instead of trigger (apex_collections_dml_trg) 13 | 14 | The objects definition can be found in the following script [install.sql](https://github.com/zorantica/db_apex_utils/blob/main/apex_dml_collections/install.sql) 15 | 16 | The script works for the Oracle database version 12c or newer. 17 | 18 | ## Examples 19 | 20 | Examples can be found in the script [examples.sql](https://github.com/zorantica/db_apex_utils/blob/main/apex_dml_collections/examples.sql) 21 | 22 | ## How it works 23 | 24 | The database package APEX_COLLECTIONS_DML_PKG contains pipelined function, which returns data from the APEX_COLLECTIONS view for the current session. 25 | 26 | The view APEX_COLLECTIONS_DML is just a wrapper around the pipelined function. 27 | 28 | The "instead of" trigger APEX_COLLECTIONS_DML_TRG, created on the view APEX_COLLECTIONS_DML, is executing DML operations on APEX collections via APEX_COLLECTION API. 29 | 30 | So, all DML operations executed on the APEX_COLLECTIONS_DML view are reflected on the APEX collections and data can be accessed either from APEX_COLLECTIONS or APEX_COLLECTIONS_DML view. 31 | 32 | ## Why this approach with pipelined function? 33 | 34 | Well... first option was to create a trigger directly on the APEX_COLLECTIONS view. But I have no privileges to do so. Plus, this also means messing up with APEX objects, which is never a good option. 35 | 36 | Second option was to create a local view APEX_COLLECTIONS_DML, which read data directly from APEX_COLLECTIONS view. And to create a trigger on the view. But the problem was that the database is checking privileges on underlying objects BEFORE executing the trigger and therefore I ended up with "ORA-01031: insufficient privileges" error. 37 | 38 | In order to avoid this ORA error I needed to somehow separate APEX_COLLECTIONS view from my local DML view... and pipelined function was just right. -------------------------------------------------------------------------------- /apex_dml_collections/examples.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------------------------------------------------------------------------------- 2 | ------------------------------------------------------------------------------------------------------------------------------- 3 | --EXAMPLE 01 4 | 5 | --if needed, create an APEX session 6 | BEGIN 7 | apex_session.create_session ( 8 | p_app_id => 150, 9 | p_page_id => 1, 10 | p_username => 'ZORAN' 11 | ); 12 | END; 13 | 14 | 15 | 16 | --insert new records into the collection 17 | --if collection does not exist no problem - it is going to be created automatically - no need to create it previously 18 | INSERT INTO apex_collections_dml ( 19 | collection_name, 20 | n001, 21 | c001 22 | ) 23 | SELECT 24 | 'MY_COLL' as collection_name, 25 | level as counter, 26 | 'my record ' || level as my_text 27 | FROM dual 28 | CONNECT BY level <= 100 29 | ; 30 | 31 | COMMIT; 32 | 33 | SELECT * 34 | FROM apex_collections 35 | WHERE collection_name = 'MY_COLL' 36 | ; 37 | 38 | SELECT * 39 | FROM apex_collections_dml 40 | WHERE collection_name = 'MY_COLL' 41 | ; 42 | 43 | 44 | --update records in the collection 45 | UPDATE apex_collections_dml 46 | SET 47 | c002 = c001, 48 | n002 = n001 * 2, 49 | d001 = trunc(sysdate) + n001 50 | WHERE 51 | collection_name = 'MY_COLL' 52 | ; 53 | 54 | COMMIT; 55 | 56 | SELECT * 57 | FROM apex_collections 58 | WHERE collection_name = 'MY_COLL' 59 | ; 60 | 61 | SELECT * 62 | FROM apex_collections_dml 63 | WHERE collection_name = 'MY_COLL' 64 | ; 65 | 66 | 67 | --delete records from the collection 68 | DELETE apex_collections_dml 69 | WHERE 70 | collection_name = 'MY_COLL' 71 | AND n002 <= 50; 72 | 73 | COMMIT; 74 | 75 | SELECT * 76 | FROM apex_collections 77 | WHERE collection_name = 'MY_COLL' 78 | ; 79 | 80 | SELECT * 81 | FROM apex_collections_dml 82 | WHERE collection_name = 'MY_COLL' 83 | ; 84 | 85 | 86 | 87 | ------------------------------------------------------------------------------------------------------------------------------- 88 | ------------------------------------------------------------------------------------------------------------------------------- 89 | --EXAMPLE 02 - use data from DEMO_CUSTOMERS table (table needs to be installed first with the APEX demo app) 90 | 91 | 92 | --clear the collection 93 | DELETE apex_collections_dml 94 | WHERE collection_name = 'DEMO_CUSTOMERS' 95 | ; 96 | 97 | commit; 98 | 99 | --populate the collection from DEMO_CUSTOMERS table 100 | INSERT INTO apex_collections_dml ( 101 | collection_name, 102 | n001, --customer_id 103 | c001, --cust_first_name 104 | c002, --cust_last_name 105 | c003, --cust_street_address1 106 | c004, --cust_street_address2 107 | c005, --cust_city 108 | c006, --cust_state 109 | c007, --cust_postal_code 110 | c008, --cust_email 111 | c009, --phone_number1 112 | c010, --phone_number2 113 | c011, --url 114 | c012, --tag 115 | n002 --credit_limit 116 | ) 117 | SELECT 118 | 'DEMO_CUSTOMERS', 119 | customer_id, 120 | cust_first_name, 121 | cust_last_name, 122 | cust_street_address1, 123 | cust_street_address2, 124 | cust_city, 125 | cust_state, 126 | cust_postal_code, 127 | cust_email, 128 | phone_number1, 129 | phone_number2, 130 | url, 131 | tags, 132 | credit_limit 133 | FROM 134 | demo_customers 135 | ; 136 | 137 | commit; 138 | 139 | 140 | --check data 141 | SELECT * 142 | FROM apex_collections 143 | WHERE collection_name = 'DEMO_CUSTOMERS' 144 | ; 145 | 146 | SELECT * 147 | FROM apex_collections_dml 148 | WHERE collection_name = 'DEMO_CUSTOMERS' 149 | ; 150 | 151 | 152 | 153 | --update credit limit for repeat customers by 10% 154 | UPDATE apex_collections_dml 155 | SET 156 | n002 = n002 + (10 * n002 / 100) 157 | WHERE 158 | c012 = 'REPEAT CUSTOMER' 159 | AND collection_name = 'DEMO_CUSTOMERS' 160 | ; 161 | 162 | commit; 163 | 164 | 165 | 166 | --check data 167 | SELECT * 168 | FROM apex_collections 169 | WHERE collection_name = 'DEMO_CUSTOMERS' 170 | ; 171 | 172 | SELECT * 173 | FROM apex_collections_dml 174 | WHERE collection_name = 'DEMO_CUSTOMERS' 175 | ; 176 | 177 | 178 | 179 | --remove customers from the state "VA" 180 | DELETE apex_collections_dml 181 | WHERE 182 | collection_name = 'DEMO_CUSTOMERS' 183 | AND c006 = 'VA' 184 | ; 185 | 186 | commit; 187 | -------------------------------------------------------------------------------- /apex_dml_collections/install.sql: -------------------------------------------------------------------------------- 1 | /* 2 | INSTALL INSTRUCTIONS 3 | 4 | In the target schema: 5 | - create package spec and package body (apex_collections_dml_pkg) 6 | - create view (APEX_COLLECTIONS_DML) 7 | - create instead of trigger (APEX_COLLECTIONS_DML_TRG) 8 | 9 | Actually, You can simply execute the following script 10 | */ 11 | 12 | CREATE OR REPLACE PACKAGE apex_collections_dml_pkg AS 13 | 14 | TYPE t_coll IS TABLE OF apex_collections%ROWTYPE; 15 | 16 | FUNCTION get_coll_data RETURN t_coll PIPELINED; 17 | 18 | END apex_collections_dml_pkg; 19 | / 20 | 21 | 22 | CREATE OR REPLACE PACKAGE BODY apex_collections_dml_pkg AS 23 | 24 | FUNCTION get_coll_data RETURN t_coll PIPELINED IS 25 | 26 | CURSOR c_data IS 27 | SELECT * 28 | FROM apex_collections; 29 | 30 | lrData t_coll; 31 | 32 | BEGIN 33 | OPEN c_data; 34 | 35 | LOOP 36 | FETCH c_data BULK COLLECT INTO lrData LIMIT 50; 37 | EXIT WHEN lrData.count = 0; 38 | 39 | FOR t IN 1 .. lrData.count LOOP 40 | PIPE ROW (lrData(t)); 41 | END LOOP; 42 | 43 | END LOOP; 44 | 45 | CLOSE c_data; 46 | 47 | END; 48 | 49 | END apex_collections_dml_pkg; 50 | / 51 | 52 | 53 | CREATE OR REPLACE VIEW apex_collections_dml AS 54 | SELECT * 55 | FROM table( apex_collections_dml_pkg.get_coll_data ) 56 | / 57 | 58 | 59 | 60 | CREATE OR REPLACE TRIGGER apex_collections_dml_trg 61 | INSTEAD OF INSERT OR UPDATE OR DELETE 62 | ON apex_collections_dml 63 | FOR EACH ROW 64 | BEGIN 65 | if not apex_collection.collection_exists( nvl(:new.collection_name, :old.collection_name) ) then 66 | apex_collection.create_collection(nvl(:new.collection_name, :old.collection_name)); 67 | end if; 68 | 69 | if inserting then 70 | apex_collection.add_member ( 71 | p_collection_name => :new.collection_name, 72 | p_c001 => :new.c001, 73 | p_c002 => :new.c002, 74 | p_c003 => :new.c003, 75 | p_c004 => :new.c004, 76 | p_c005 => :new.c005, 77 | p_c006 => :new.c006, 78 | p_c007 => :new.c007, 79 | p_c008 => :new.c008, 80 | p_c009 => :new.c009, 81 | p_c010 => :new.c010, 82 | p_c011 => :new.c011, 83 | p_c012 => :new.c012, 84 | p_c013 => :new.c013, 85 | p_c014 => :new.c014, 86 | p_c015 => :new.c015, 87 | p_c016 => :new.c016, 88 | p_c017 => :new.c017, 89 | p_c018 => :new.c018, 90 | p_c019 => :new.c019, 91 | p_c020 => :new.c020, 92 | p_c021 => :new.c021, 93 | p_c022 => :new.c022, 94 | p_c023 => :new.c023, 95 | p_c024 => :new.c024, 96 | p_c025 => :new.c025, 97 | p_c026 => :new.c026, 98 | p_c027 => :new.c027, 99 | p_c028 => :new.c028, 100 | p_c029 => :new.c029, 101 | p_c030 => :new.c030, 102 | p_c031 => :new.c031, 103 | p_c032 => :new.c032, 104 | p_c033 => :new.c033, 105 | p_c034 => :new.c034, 106 | p_c035 => :new.c035, 107 | p_c036 => :new.c036, 108 | p_c037 => :new.c037, 109 | p_c038 => :new.c038, 110 | p_c039 => :new.c039, 111 | p_c040 => :new.c040, 112 | p_c041 => :new.c041, 113 | p_c042 => :new.c042, 114 | p_c043 => :new.c043, 115 | p_c044 => :new.c044, 116 | p_c045 => :new.c045, 117 | p_c046 => :new.c046, 118 | p_c047 => :new.c047, 119 | p_c048 => :new.c048, 120 | p_c049 => :new.c049, 121 | p_c050 => :new.c050, 122 | p_n001 => :new.n001, 123 | p_n002 => :new.n002, 124 | p_n003 => :new.n003, 125 | p_n004 => :new.n004, 126 | p_n005 => :new.n005, 127 | p_d001 => :new.d001, 128 | p_d002 => :new.d002, 129 | p_d003 => :new.d003, 130 | p_d004 => :new.d004, 131 | p_d005 => :new.d005, 132 | p_clob001 => :new.clob001, 133 | p_blob001 => :new.blob001, 134 | p_xmltype001 => :new.xmltype001 135 | ); 136 | 137 | elsif updating then 138 | apex_collection.update_member ( 139 | p_seq => :new.seq_id, 140 | p_collection_name => :new.collection_name, 141 | p_c001 => :new.c001, 142 | p_c002 => :new.c002, 143 | p_c003 => :new.c003, 144 | p_c004 => :new.c004, 145 | p_c005 => :new.c005, 146 | p_c006 => :new.c006, 147 | p_c007 => :new.c007, 148 | p_c008 => :new.c008, 149 | p_c009 => :new.c009, 150 | p_c010 => :new.c010, 151 | p_c011 => :new.c011, 152 | p_c012 => :new.c012, 153 | p_c013 => :new.c013, 154 | p_c014 => :new.c014, 155 | p_c015 => :new.c015, 156 | p_c016 => :new.c016, 157 | p_c017 => :new.c017, 158 | p_c018 => :new.c018, 159 | p_c019 => :new.c019, 160 | p_c020 => :new.c020, 161 | p_c021 => :new.c021, 162 | p_c022 => :new.c022, 163 | p_c023 => :new.c023, 164 | p_c024 => :new.c024, 165 | p_c025 => :new.c025, 166 | p_c026 => :new.c026, 167 | p_c027 => :new.c027, 168 | p_c028 => :new.c028, 169 | p_c029 => :new.c029, 170 | p_c030 => :new.c030, 171 | p_c031 => :new.c031, 172 | p_c032 => :new.c032, 173 | p_c033 => :new.c033, 174 | p_c034 => :new.c034, 175 | p_c035 => :new.c035, 176 | p_c036 => :new.c036, 177 | p_c037 => :new.c037, 178 | p_c038 => :new.c038, 179 | p_c039 => :new.c039, 180 | p_c040 => :new.c040, 181 | p_c041 => :new.c041, 182 | p_c042 => :new.c042, 183 | p_c043 => :new.c043, 184 | p_c044 => :new.c044, 185 | p_c045 => :new.c045, 186 | p_c046 => :new.c046, 187 | p_c047 => :new.c047, 188 | p_c048 => :new.c048, 189 | p_c049 => :new.c049, 190 | p_c050 => :new.c050, 191 | p_n001 => :new.n001, 192 | p_n002 => :new.n002, 193 | p_n003 => :new.n003, 194 | p_n004 => :new.n004, 195 | p_n005 => :new.n005, 196 | p_d001 => :new.d001, 197 | p_d002 => :new.d002, 198 | p_d003 => :new.d003, 199 | p_d004 => :new.d004, 200 | p_d005 => :new.d005, 201 | p_clob001 => :new.clob001, 202 | p_blob001 => :new.blob001, 203 | p_xmltype001 => :new.xmltype001 204 | ); 205 | 206 | elsif deleting then 207 | apex_collection.delete_member ( 208 | p_collection_name => :old.collection_name, 209 | p_seq => :old.seq_id 210 | ); 211 | 212 | end if; 213 | 214 | END apex_collections_dml_trg; 215 | / -------------------------------------------------------------------------------- /apex_lang_utils/README.md: -------------------------------------------------------------------------------- 1 | # Oracle APEX - "apex_lang_utils" package 2 | 3 | History of changes: 4 | - 1.0 - initial version 5 | 6 | ## Install instructions 7 | 8 | In the target schema create the package specification and the package body. 9 | 10 | ## Program unit specs 11 | 12 | ### Function get_xliff_per_page 13 | 14 | Function returns a ZIP file with exported XLIFF files for selected pages and selected languages. 15 | Compatible with APEX 23.1 or newer. 16 | 17 | Parameters: 18 | - p_app_id - main application ID in primary language 19 | - p_pages - a comma separated list of desired pages OR "all" value for all pages 20 | - p_languages - a comma separated list of desired languages OR "all" value for all languages 21 | - p_folder_per_group_yn - if files are going to be stored in separate folders named by page groups; values Y/N 22 | - p_only_modified_elements_yn - if only modified elements are going to be exported; values Y/N 23 | 24 | ### Procedure apply_xliff_files 25 | 26 | Procedure receives a ZIP file with XLIFF translations and applies them to a selected application. 27 | Compatible with APEX 23.1 or newer. 28 | 29 | Parameters: 30 | - p_zip - a ZIP file containing XLIFF files 31 | - p_app_id - main application ID in primary language 32 | - p_seed_yn - if the seed action should be executed BEFORE applying XLIFF files 33 | - p_publish_yn - if the publish action should be executed AFTER applying XLIFF files 34 | 35 | ## Usage 36 | 37 | ### Export multiple XLIFF files in a single ZIP file 38 | 39 | ```sql 40 | DECLARE 41 | l_zip blob; 42 | 43 | BEGIN 44 | --create a ZIP file 45 | l_zip := apex_lang_utils.get_xliff_per_page ( 46 | p_app_id => 140, 47 | p_pages => '1,2,3', 48 | p_languages => 'nl-be,fr-be', 49 | p_folder_per_group_yn => 'Y', 50 | p_only_modified_elements_yn => 'N' 51 | ); 52 | 53 | --store the ZIP file into the TEST table 54 | DELETE test; 55 | INSERT INTO test (id, blob_doc) 56 | VALUES (1, l_zip); 57 | 58 | COMMIT; 59 | 60 | END; 61 | ``` 62 | 63 | ### Apply multiple XLIFF files from a single ZIP file 64 | 65 | ```sql 66 | DECLARE 67 | l_zip blob; 68 | 69 | BEGIN 70 | --fetch a ZIP file with XLIFF translations from the TEST table 71 | SELECT blob_doc 72 | INTO l_zip 73 | FROM test 74 | WHERE id = 2; 75 | 76 | --apply translations 77 | apex_lang_utils.apply_xliff_files ( 78 | p_zip => l_zip, 79 | p_app_id => 140, 80 | p_seed_yn => 'Y', 81 | p_publish_yn => 'N' 82 | ); 83 | 84 | END; 85 | ``` -------------------------------------------------------------------------------- /apex_lang_utils/apex_lang_utils.pkb: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE PACKAGE BODY apex_lang_utils AS 2 | 3 | 4 | 5 | PROCEDURE create_session_if_needed ( 6 | p_app_id number 7 | ) IS 8 | BEGIN 9 | if nvl(v('APP_ID'), 0) <> p_app_id then 10 | 11 | dbms_output.put_line('Creating a session for APP id ' || p_app_id); 12 | 13 | --please provide an appropriate username and page in order to create a session 14 | apex_session.create_session ( 15 | p_app_id => p_app_id, 16 | p_page_id => 1, 17 | p_username => 'zoran' 18 | ); 19 | 20 | else 21 | dbms_output.put_line('Session ' || v('APP_SESSION') || ' already created'); 22 | 23 | end if; 24 | 25 | END create_session_if_needed; 26 | 27 | FUNCTION get_xliff_per_page ( 28 | p_app_id number, 29 | p_pages varchar2 default 'all', 30 | p_languages varchar2 default 'all', 31 | p_folder_per_group_yn varchar2 default 'Y', 32 | p_only_modified_elements_yn varchar2 default 'N' 33 | 34 | ) RETURN blob IS 35 | 36 | CURSOR c_data IS 37 | SELECT 38 | tm.translated_app_language, 39 | p.page_id, 40 | p_app_id || '/' || 41 | tm.translated_app_language || '/' || 42 | CASE p_folder_per_group_yn WHEN 'Y' THEN nvl(p.page_group, '(unassigned)') || '/' ELSE null END || 43 | to_char(p.page_id, 'fm00000') || ' - ' || 44 | replace( replace(p.page_name, '/', '_'), '\', '_') || ' (' || 45 | tm.translated_app_language || ').xlf' as filename 46 | FROM 47 | apex_application_trans_map tm 48 | JOIN apex_application_pages p ON tm.primary_application_id = p.application_id 49 | WHERE 50 | tm.primary_application_id = p_app_id 51 | AND ( 52 | p_languages = 'all' 53 | OR tm.translated_app_language in 54 | ( 55 | SELECT column_value as translated_app_language 56 | FROM table( apex_string.split(p_languages, ',')) 57 | ) 58 | ) 59 | AND ( 60 | p_pages = 'all' 61 | OR p.page_id in 62 | ( 63 | SELECT column_value as page_id 64 | FROM table( apex_string.split(p_pages, ',')) 65 | ) 66 | ) 67 | --AND rownum <= 10 --for testing purposes 68 | ; 69 | 70 | TYPE t_data IS TABLE OF c_data%ROWTYPE; 71 | l_data t_data; 72 | 73 | l_xliff clob; 74 | l_zip blob; 75 | 76 | BEGIN 77 | --fetch data 78 | OPEN c_data; 79 | FETCH c_data BULK COLLECT INTO l_data; 80 | CLOSE c_data; 81 | 82 | --create APEX session (if needed) 83 | create_session_if_needed ( 84 | p_app_id => p_app_id 85 | ); 86 | 87 | --loop through all pages and languages, prepare XLIFF files and zip them 88 | FOR t IN 1 .. l_data.count LOOP 89 | 90 | dbms_output.put_line('Exporting file for page ' || l_data(t).page_id || ' and language ' || l_data(t).translated_app_language || '...'); 91 | 92 | l_xliff := apex_lang.get_xliff_document ( 93 | p_application_id => p_app_id, 94 | p_page_id => l_data(t).page_id, 95 | p_language => l_data(t).translated_app_language, 96 | p_only_modified_elements => CASE p_only_modified_elements_yn WHEN 'Y' THEN true ELSE false END 97 | ); 98 | 99 | apex_zip.add_file ( 100 | p_zipped_blob => l_zip, 101 | p_file_name => l_data(t).filename, 102 | p_content => ape_utils.f_clob_to_blob(l_xliff) 103 | ); 104 | 105 | END LOOP; 106 | 107 | apex_zip.finish(l_zip); 108 | 109 | RETURN l_zip; 110 | 111 | END get_xliff_per_page; 112 | 113 | 114 | 115 | PROCEDURE apply_xliff_files ( 116 | p_zip blob, 117 | p_app_id number, 118 | p_seed_yn varchar2 default 'Y', 119 | p_publish_yn varchar2 default 'Y' 120 | ) IS 121 | 122 | l_files apex_zip.t_files; 123 | l_file blob; 124 | l_xliff clob; 125 | l_lang varchar2(10); 126 | 127 | CURSOR c_languages IS 128 | SELECT amp.translated_app_language as lang 129 | FROM apex_application_trans_map amp 130 | WHERE amp.primary_application_id = p_app_id 131 | ; 132 | 133 | 134 | PROCEDURE p_seed IS 135 | BEGIN 136 | FOR t IN c_languages LOOP 137 | dbms_output.put_line('Seeding ' || t.lang); 138 | apex_lang.seed_translations( 139 | p_application_id => p_app_id, 140 | p_language => t.lang 141 | ); 142 | dbms_output.put_line('Seed finished ' || t.lang); 143 | END LOOP; 144 | 145 | COMMIT; 146 | 147 | END p_seed; 148 | 149 | PROCEDURE p_publish IS 150 | BEGIN 151 | FOR t IN c_languages LOOP 152 | dbms_output.put_line('Publishing ' || t.lang); 153 | apex_lang.publish_application( 154 | p_application_id => p_app_id, 155 | p_language => t.lang 156 | ); 157 | dbms_output.put_line('Publish finished ' || t.lang); 158 | 159 | END LOOP; 160 | 161 | COMMIT; 162 | 163 | END p_publish; 164 | 165 | BEGIN 166 | --create APEX session (if needed) 167 | create_session_if_needed ( 168 | p_app_id => p_app_id 169 | ); 170 | 171 | --seed (if needed) 172 | if p_seed_yn = 'Y' then 173 | p_seed; 174 | end if; 175 | 176 | 177 | --get a list of files from the ZIP file 178 | l_files := apex_zip.get_files ( p_zipped_blob => p_zip ); 179 | 180 | --loop through files and apply them if possible 181 | FOR t IN 1 .. l_files.count LOOP 182 | 183 | --check file extension (ignore MAC subfolder) 184 | if lower( substr( l_files(t), -4 ) ) = '.xlf' and not instr(l_files(t), '__MACOSX') > 0 then 185 | 186 | dbms_output.put_line( 'Processing ' || l_files(t) ); 187 | 188 | --get a single file content and convert it from blob to clob 189 | l_file := apex_zip.get_file_content ( 190 | p_zipped_blob => p_zip, 191 | p_file_name => l_files(t) 192 | ); 193 | 194 | l_xliff := apex_util.blob_to_clob(l_file); 195 | 196 | --determine the target language from the file 197 | SELECT 198 | XMLCast ( 199 | xmlquery( 200 | '(: :) /xliff/file/@target-language' 201 | passing xmlType(l_xliff) 202 | RETURNING CONTENT 203 | ) 204 | as varchar2(10) 205 | ) as lang 206 | INTO l_lang 207 | FROM dual; 208 | 209 | dbms_output.put_line('Detected language ' || l_lang); 210 | dbms_output.put_line('File size: ' || length(l_xliff) ); 211 | 212 | if l_lang is null then 213 | RAISE_APPLICATION_ERROR(-20001, 'Language can not be determined for a file ' || l_files(t)); 214 | end if; 215 | 216 | 217 | --apply translation to the repository 218 | apex_lang.apply_xliff_document ( 219 | p_application_id => p_app_id, 220 | p_language => l_lang, 221 | p_document => l_xliff 222 | ); 223 | 224 | dbms_output.put_line( 'File applied ' || l_files(t) ); 225 | 226 | else 227 | dbms_output.put_line( 'Skipping ' || l_files(t) ); 228 | 229 | end if; 230 | 231 | END LOOP; 232 | 233 | --publish (if needed) 234 | if p_publish_yn = 'Y' then 235 | p_publish; 236 | end if; 237 | 238 | 239 | END apply_xliff_files; 240 | 241 | 242 | END apex_lang_utils; -------------------------------------------------------------------------------- /apex_lang_utils/apex_lang_utils.pks: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE PACKAGE apex_lang_utils AS 2 | 3 | /* 4 | Function returns a ZIP file with exported XLIFF files for selected pages and selected languages. 5 | Compatible with APEX 23.1 or newer. 6 | 7 | Parameters: 8 | @p_app_id - main application ID in primary language 9 | @p_pages - a comma separated list of desired pages OR "all" value for all pages 10 | @p_languages - a comma separated list of desired languages OR "all" value for all languages 11 | @p_folder_per_group_yn - if files are going to be stored in separate folders named by page groups; values Y/N 12 | @p_only_modified_elements_yn - if only modified elements are going to be exported; values Y/N 13 | 14 | usage: 15 | DECLARE 16 | l_zip blob; 17 | BEGIN 18 | l_zip := apex_lang_utils.get_xliff_per_page ( 19 | p_app_id => 140, 20 | p_pages => '1,2,3', 21 | p_languages => 'nl-be,fr-be', 22 | p_folder_per_group_yn => 'Y', 23 | p_only_modified_elements_yn => 'N' 24 | ); 25 | 26 | DELETE test; 27 | INSERT INTO test (id, blob_doc) 28 | VALUES (1, l_zip); 29 | 30 | COMMIT; 31 | 32 | END; 33 | */ 34 | FUNCTION get_xliff_per_page ( 35 | p_app_id number, 36 | p_pages varchar2 default 'all', 37 | p_languages varchar2 default 'all', 38 | p_folder_per_group_yn varchar2 default 'Y', 39 | p_only_modified_elements_yn varchar2 default 'N' 40 | ) RETURN blob; 41 | 42 | 43 | 44 | /* 45 | Procedure receives a ZIP file with XLIFF translations and applies them to a selected application. 46 | Compatible with APEX 23.1 or newer. 47 | 48 | Parameters: 49 | @p_zip - a ZIP file containing XLIFF files 50 | @p_app_id - main application ID in primary language 51 | @p_seed_yn - if the seed action should be executed BEFORE applying XLIFF files 52 | @p_publish_yn - if the publish action should be executed AFTER applying XLIFF files 53 | */ 54 | 55 | PROCEDURE apply_xliff_files ( 56 | p_zip blob, 57 | p_app_id number, 58 | p_seed_yn varchar2 default 'Y', 59 | p_publish_yn varchar2 default 'Y' 60 | ); 61 | 62 | 63 | END apex_lang_utils; -------------------------------------------------------------------------------- /apex_zip_utils/README.md: -------------------------------------------------------------------------------- 1 | # Oracle APEX - "apex_zip_utils" package 2 | 3 | History of changes: 4 | - 1.0 - initial version 5 | 6 | ## Install instructions 7 | 8 | Create the package specification and the package body in the target database schema. 9 | 10 | ## Program unit specs 11 | 12 | ### Function unzip (pipelined) 13 | 14 | The pipelined function unzips all files from the passed ZIP file and returns a dataset with list of unziped files containing: 15 | - file name 16 | - file directory and name 17 | - file size 18 | - file content 19 | 20 | Parameters: 21 | - p_zipped_blob - a blob value containing a ZIP file 22 | - p_include - a separated string containing file and directory name criterias to include in a result set, like "\*.jpg" or "tiles\*.gif"; separator is defined in a parameter p_separator (default value ":") 23 | - p_exclude - a separated string containing file and directory name criterias to exclude from a result set, like "tiles/\*"; separator is defined in a parameter p_separator (default value ":") 24 | - p_separator - include and exclude string separator 25 | 26 | #### Code example (without any include/exclude filters): 27 | 28 | ```sql 29 | SELECT * 30 | FROM 31 | table( 32 | apex_zip_utils.unzip ( 33 | p_zipped_blob => (SELECT blob_content FROM import_zip WHERE id = 1) 34 | ) 35 | ) 36 | ; 37 | ``` 38 | 39 | ```text 40 | Result: 41 | FILE_NAME FILE_NAME_AND_DIRECTORY FILE_SIZE FILE_CONTENT 42 | 00000000000000130429.jpeg 00000000000000130429.jpeg 11900 (blob) 43 | 00000000000000130430.jpeg 00000000000000130430.jpeg 9340 (blob) 44 | 00000000000000130431.jpeg 00000000000000130431.jpeg 17634 (blob) 45 | ajax-loading.gif ajax-loading.gif 72232 (blob) 46 | apexrnd-555x311.png apexrnd-555x311.png 31480 (blob) 47 | test.txt test.txt 4 (blob) 48 | 00000000000000130407.jpeg tiles/00000000000000130407.jpeg 9270 (blob) 49 | 00000000000000130408.jpeg tiles/00000000000000130408.jpeg 11206 (blob) 50 | ``` 51 | 52 | 53 | #### Code example (with include filters): 54 | 55 | ```sql 56 | SELECT * 57 | FROM 58 | table( 59 | apex_zip_utils.unzip ( 60 | p_zipped_blob => (SELECT blob_content FROM import_zip WHERE id = 1), 61 | p_include => '*.gif:*.jpeg' 62 | ) 63 | ) 64 | ; 65 | ``` 66 | 67 | ```text 68 | Result: 69 | FILE_NAME FILE_NAME_AND_DIRECTORY FILE_SIZE FILE_CONTENT 70 | 00000000000000130429.jpeg 00000000000000130429.jpeg 11900 (blob) 71 | 00000000000000130430.jpeg 00000000000000130430.jpeg 9340 (blob) 72 | 00000000000000130431.jpeg 00000000000000130431.jpeg 17634 (blob) 73 | ajax-loading.gif ajax-loading.gif 72232 (blob) 74 | 00000000000000130407.jpeg tiles/00000000000000130407.jpeg 9270 (blob) 75 | 00000000000000130408.jpeg tiles/00000000000000130408.jpeg 11206 (blob) 76 | ``` 77 | 78 | #### Code example (with include filters and excluding a folder "tiles"): 79 | 80 | ```sql 81 | SELECT * 82 | FROM 83 | table( 84 | apex_zip_utils.unzip ( 85 | p_zipped_blob => (SELECT blob_content FROM import_zip WHERE id = 1), 86 | p_include => '*.gif:*.jpeg', 87 | p_exclude => 'tiles/*' 88 | ) 89 | ) 90 | ; 91 | ``` 92 | 93 | ```text 94 | Result: 95 | FILE_NAME FILE_NAME_AND_DIRECTORY FILE_SIZE FILE_CONTENT 96 | 00000000000000130429.jpeg 00000000000000130429.jpeg 11900 (blob) 97 | 00000000000000130430.jpeg 00000000000000130430.jpeg 9340 (blob) 98 | 00000000000000130431.jpeg 00000000000000130431.jpeg 17634 (blob) 99 | ajax-loading.gif ajax-loading.gif 72232 (blob) 100 | ``` 101 | 102 | 103 | ### Function unzip_nt 104 | The function returns the same result as unzip function in a form of a nested table collection. 105 | 106 | Code example: 107 | 108 | ```sql 109 | DECLARE 110 | 111 | l_zipped_blob blob; 112 | l_files apex_zip_utils.t_files; 113 | 114 | BEGIN 115 | --get zip file from the table 116 | SELECT blob_content 117 | INTO l_zipped_blob 118 | FROM import_zip 119 | WHERE id = 1; 120 | 121 | l_files := apex_zip_utils.unzip_nt ( 122 | p_zipped_blob => l_zipped_blob 123 | ); 124 | 125 | FOR t IN 1 .. l_files.count LOOP 126 | dbms_output.put_line(l_files(t).file_name_and_directory); 127 | dbms_output.put_line(l_files(t).file_name || ' (' || l_files(t).file_size || ' bytes)'); 128 | END LOOP; 129 | END; 130 | ``` 131 | 132 | ### Function unzip_ar 133 | The function returns the same result as unzip function in a form of a associative array collection. 134 | 135 | The collection index is the file directory and name, for example 'my/folder/file.xml' 136 | 137 | Code example: 138 | 139 | ```sql 140 | DECLARE 141 | 142 | l_zipped_blob blob; 143 | l_files apex_zip_utils.t_files_ar; 144 | l_index varchar2(32000); 145 | 146 | BEGIN 147 | --get zip file from the table 148 | SELECT blob_content 149 | INTO l_zipped_blob 150 | FROM import_zip 151 | WHERE id = 1; 152 | 153 | l_files := apex_zip_utils.unzip_ar ( 154 | p_zipped_blob => l_zipped_blob 155 | ); 156 | 157 | l_index := 'tiles/00000000000000130407.jpeg'; 158 | dbms_output.put_line( 159 | l_files(l_index).file_name || ' (' || 160 | l_files(l_index).file_size || ' bytes)' 161 | ); 162 | END; 163 | ``` 164 | 165 | 166 | 167 | -------------------------------------------------------------------------------- /apex_zip_utils/apex_zip_utils.pkb: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE PACKAGE BODY apex_zip_utils AS 2 | 3 | 4 | FUNCTION unzip ( 5 | p_zipped_blob IN blob, 6 | p_include varchar2 default null, 7 | p_exclude varchar2 default null, 8 | p_separator varchar2 default ':' 9 | ) RETURN t_files PIPELINED IS 10 | 11 | $IF wwv_flow_api.c_current >= apex_zip_utils.c_apex_21_2 $THEN 12 | l_files apex_zip.t_dir_entries; 13 | $ELSE 14 | l_files apex_zip.t_files; 15 | $END 16 | 17 | l_file blob; 18 | l_counter pls_integer := 1; 19 | l_index varchar2(32767); 20 | l_filter apex_t_varchar2; 21 | 22 | l_filename varchar2(4000); 23 | l_filename_and_directory varchar2(4000); 24 | 25 | l_row r_file; 26 | 27 | l_match_found boolean; 28 | 29 | BEGIN 30 | --get a file list from the zip file 31 | $IF wwv_flow_api.c_current >= apex_zip_utils.c_apex_21_2 $THEN 32 | l_files := apex_zip.get_dir_entries ( 33 | p_zipped_blob => p_zipped_blob, 34 | p_only_files => true 35 | ); 36 | $ELSE 37 | l_files := apex_zip.get_files ( 38 | p_zipped_blob => p_zipped_blob 39 | ); 40 | $END 41 | 42 | 43 | --unzipping files and populating the output collection 44 | l_index := l_files.first; 45 | 46 | LOOP 47 | EXIT WHEN l_index is null; 48 | 49 | --get filename 50 | 51 | $IF wwv_flow_api.c_current >= apex_zip_utils.c_apex_21_2 $THEN 52 | l_filename := l_files( l_index ).file_name; 53 | l_row.file_name_and_directory := l_index; 54 | $ELSE 55 | l_filename := l_files( l_index ); 56 | l_row.file_name_and_directory := l_files( l_index ); 57 | $END 58 | 59 | l_row.file_name := 60 | CASE 61 | WHEN instr(l_filename, '/') = 0 THEN l_filename 62 | ELSE substr(l_filename, instr(l_filename, '/', -1) + 1 ) 63 | END 64 | ; 65 | 66 | --include files 67 | if p_include is null then --no filters -> extract all files 68 | l_match_found := true; 69 | 70 | else --check filters 71 | 72 | l_match_found := false; 73 | 74 | l_filter := apex_string.split ( 75 | p_str => p_include, 76 | p_sep => p_separator 77 | ); 78 | 79 | FOR t IN 1 .. l_filter.count LOOP 80 | if l_row.file_name_and_directory like replace(l_filter(t), '*', '%') then 81 | l_match_found := true; 82 | EXIT; 83 | end if; 84 | END LOOP; 85 | 86 | end if; 87 | 88 | --exclude files 89 | if p_include is not null and l_match_found then --exclude 90 | l_filter := apex_string.split ( 91 | p_str => p_exclude, 92 | p_sep => p_separator 93 | ); 94 | 95 | FOR t IN 1 .. l_filter.count LOOP 96 | if l_row.file_name_and_directory like replace(l_filter(t), '*', '%') then 97 | l_match_found := false; 98 | EXIT; 99 | end if; 100 | END LOOP; 101 | 102 | end if; 103 | 104 | 105 | if l_match_found then 106 | 107 | --get file content 108 | $IF wwv_flow_api.c_current >= apex_zip_utils.c_apex_21_2 $THEN 109 | l_row.file_content := apex_zip.get_file_content ( 110 | p_zipped_blob => p_zipped_blob, 111 | p_dir_entry => l_files( l_index ) 112 | ); 113 | $ELSE 114 | l_row.file_content := apex_zip.get_file_content ( 115 | p_zipped_blob => p_zipped_blob, 116 | p_file_name => l_files( l_index ) 117 | ); 118 | $END 119 | 120 | --get file size 121 | $IF wwv_flow_api.c_current >= apex_zip_utils.c_apex_21_2 $THEN 122 | l_row.file_size := l_files( l_index ).uncompressed_length; 123 | $ELSE 124 | l_row.file_size := dbms_lob.getLength(l_row.file_content); 125 | $END 126 | 127 | pipe row (l_row); 128 | 129 | end if; 130 | 131 | --next file index 132 | l_index := l_files.next(l_index); 133 | l_counter := l_counter + 1; 134 | END LOOP; 135 | 136 | RETURN; 137 | END unzip; 138 | 139 | 140 | FUNCTION unzip_nt ( 141 | p_zipped_blob blob, 142 | p_include varchar2 default null, 143 | p_exclude varchar2 default null, 144 | p_separator varchar2 default ':' 145 | ) RETURN t_files IS 146 | 147 | l_output t_files; 148 | 149 | BEGIN 150 | SELECT * 151 | BULK COLLECT INTO l_output 152 | FROM 153 | table( 154 | apex_zip_utils.unzip ( 155 | p_zipped_blob => p_zipped_blob, 156 | p_include => p_include, 157 | p_exclude => p_exclude, 158 | p_separator => p_separator 159 | ) 160 | ) 161 | ; 162 | 163 | RETURN l_output; 164 | 165 | END unzip_nt; 166 | 167 | 168 | 169 | FUNCTION unzip_ar ( 170 | p_zipped_blob blob, 171 | p_include varchar2 default null, 172 | p_exclude varchar2 default null, 173 | p_separator varchar2 default ':' 174 | ) RETURN t_files_ar IS 175 | 176 | l_output_nt t_files; 177 | l_output t_files_ar; 178 | 179 | BEGIN 180 | SELECT * 181 | BULK COLLECT INTO l_output_nt 182 | FROM 183 | table( 184 | apex_zip_utils.unzip ( 185 | p_zipped_blob => p_zipped_blob, 186 | p_include => p_include, 187 | p_exclude => p_exclude, 188 | p_separator => p_separator 189 | ) 190 | ) 191 | ; 192 | 193 | FOR t IN 1 .. l_output_nt.count LOOP 194 | l_output( l_output_nt(t).file_name_and_directory ) := l_output_nt(t); 195 | END LOOP; 196 | 197 | RETURN l_output; 198 | 199 | END unzip_ar; 200 | 201 | 202 | 203 | END apex_zip_utils; -------------------------------------------------------------------------------- /apex_zip_utils/apex_zip_utils.pks: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE PACKAGE apex_zip_utils AS 2 | 3 | TYPE r_file IS RECORD ( 4 | file_name varchar2(32000), 5 | file_name_and_directory varchar2(32000), 6 | file_size number, 7 | file_content blob 8 | ); 9 | 10 | TYPE t_files IS TABLE OF r_file; 11 | TYPE t_files_ar IS TABLE OF r_file INDEX BY varchar2(32000); 12 | 13 | --copied from wwv_flow_api package 14 | c_apex_21_2 constant number := 20211015; 15 | 16 | 17 | /* 18 | The pipelined function unzips all files from the passed ZIP file and returns a dataset with list of unziped files containing: 19 | - file name 20 | - file directory and name 21 | - file size 22 | - file content 23 | 24 | Parameters: 25 | - p_zipped_blob - a blob value containing a ZIP file 26 | - p_include - a separated string containing file and directory name criterias to include in a result set, like "*.jpg" or "tile*.gif"; separator is defined in a parameter p_separator (default value ":") 27 | - p_exclude - a separated string containing file and directory name criterias to exclude from a result set, like "tiles/*"; separator is defined in a parameter p_separator (default value ":") 28 | - p_separator - include and exclude string separator 29 | 30 | 31 | Code example (without any include/exclude filters): 32 | 33 | SELECT * 34 | FROM 35 | table( 36 | apex_zip_utils.unzip ( 37 | p_zipped_blob => (SELECT blob_content FROM import_zip WHERE id = 1) 38 | ) 39 | ) 40 | ; 41 | 42 | Result; 43 | FILE_NAME FILE_NAME_AND_DIRECTORY FILE_SIZE FILE_CONTENT 44 | 00000000000000130429.jpeg 00000000000000130429.jpeg 11900 (blob) 45 | 00000000000000130430.jpeg 00000000000000130430.jpeg 9340 (blob) 46 | 00000000000000130431.jpeg 00000000000000130431.jpeg 17634 (blob) 47 | ajax-loading.gif ajax-loading.gif 72232 (blob) 48 | apexrnd-555x311.png apexrnd-555x311.png 31480 (blob) 49 | test.txt test.txt 4 (blob) 50 | 00000000000000130407.jpeg tiles/00000000000000130407.jpeg 9270 (blob) 51 | 00000000000000130408.jpeg tiles/00000000000000130408.jpeg 11206 (blob) 52 | 53 | 54 | Code example (with include filters): 55 | 56 | SELECT * 57 | FROM 58 | table( 59 | apex_zip_utils.unzip ( 60 | p_zipped_blob => (SELECT blob_content FROM import_zip WHERE id = 1), 61 | p_include => '*.gif:*.jpeg' 62 | ) 63 | ) 64 | ; 65 | 66 | Result; 67 | Result; 68 | FILE_NAME FILE_NAME_AND_DIRECTORY FILE_SIZE FILE_CONTENT 69 | 00000000000000130429.jpeg 00000000000000130429.jpeg 11900 (blob) 70 | 00000000000000130430.jpeg 00000000000000130430.jpeg 9340 (blob) 71 | 00000000000000130431.jpeg 00000000000000130431.jpeg 17634 (blob) 72 | ajax-loading.gif ajax-loading.gif 72232 (blob) 73 | 00000000000000130407.jpeg tiles/00000000000000130407.jpeg 9270 (blob) 74 | 00000000000000130408.jpeg tiles/00000000000000130408.jpeg 11206 (blob) 75 | 76 | 77 | Code example (with include filters and excluding a folder "tiles"): 78 | 79 | SELECT * 80 | FROM 81 | table( 82 | apex_zip_utils.unzip ( 83 | p_zipped_blob => (SELECT blob_content FROM import_zip WHERE id = 1), 84 | p_include => '*.gif:*.jpeg', 85 | p_exclude => 'tiles/*' 86 | ) 87 | ) 88 | ; 89 | 90 | Result; 91 | Result; 92 | FILE_NAME FILE_NAME_AND_DIRECTORY FILE_SIZE FILE_CONTENT 93 | 00000000000000130429.jpeg 00000000000000130429.jpeg 11900 (blob) 94 | 00000000000000130430.jpeg 00000000000000130430.jpeg 9340 (blob) 95 | 00000000000000130431.jpeg 00000000000000130431.jpeg 17634 (blob) 96 | ajax-loading.gif ajax-loading.gif 72232 (blob) 97 | */ 98 | 99 | 100 | FUNCTION unzip ( 101 | p_zipped_blob blob, 102 | p_include varchar2 default null, 103 | p_exclude varchar2 default null, 104 | p_separator varchar2 default ':' 105 | ) RETURN t_files PIPELINED; 106 | 107 | 108 | /* 109 | The function unzips all files from the passed ZIP file and retuns a nested table collection of files containing: 110 | - file name 111 | - file directory and name 112 | - file size 113 | - file content 114 | 115 | Code example: 116 | 117 | DECLARE 118 | 119 | l_zipped_blob blob; 120 | l_files apex_zip_utils.t_files; 121 | 122 | BEGIN 123 | --get zip file from the table 124 | SELECT blob_content 125 | INTO l_zipped_blob 126 | FROM import_zip 127 | WHERE id = 1; 128 | 129 | l_files := apex_zip_utils.unzip_nt ( 130 | p_zipped_blob => l_zipped_blob 131 | ); 132 | 133 | FOR t IN 1 .. l_files.count LOOP 134 | dbms_output.put_line(l_files(t).file_name_and_directory); 135 | dbms_output.put_line(l_files(t).file_name || ' (' || l_files(t).file_size || ' bytes)'); 136 | END LOOP; 137 | END; 138 | */ 139 | 140 | FUNCTION unzip_nt ( 141 | p_zipped_blob blob, 142 | p_include varchar2 default null, 143 | p_exclude varchar2 default null, 144 | p_separator varchar2 default ':' 145 | ) RETURN t_files; 146 | 147 | 148 | /* 149 | The function unzips all files from the passed ZIP file and returns an associative array collection of files containing: 150 | - file name 151 | - file directory and name 152 | - file size 153 | - file content data 154 | 155 | The collection index is the file directory and name, for example 'my/folder/file.xml' 156 | 157 | Example of usage: 158 | 159 | DECLARE 160 | 161 | l_zipped_blob blob; 162 | l_files apex_zip_utils.t_files_ar; 163 | l_index varchar2(32000); 164 | 165 | BEGIN 166 | --get zip file from the table 167 | SELECT blob_content 168 | INTO l_zipped_blob 169 | FROM import_zip 170 | WHERE id = 1; 171 | 172 | l_files := apex_zip_utils.unzip_ar ( 173 | p_zipped_blob => l_zipped_blob 174 | ); 175 | 176 | l_index := 'tiles/00000000000000130407.jpeg'; 177 | dbms_output.put_line( 178 | l_files(l_index).file_name || ' (' || 179 | l_files(l_index).file_size || ' bytes)' 180 | ); 181 | END; 182 | 183 | */ 184 | 185 | FUNCTION unzip_ar ( 186 | p_zipped_blob blob, 187 | p_include varchar2 default null, 188 | p_exclude varchar2 default null, 189 | p_separator varchar2 default ':' 190 | ) RETURN t_files_ar; 191 | 192 | END apex_zip_utils; 193 | -------------------------------------------------------------------------------- /dba_dictionary/README.md: -------------------------------------------------------------------------------- 1 | # Oracle Database - dba_dictionary view and documentation generator 2 | 3 | History of changes: 4 | - 1.0 - initial version 5 | 6 | ## Install instructions 7 | 8 | Create the view in the target database schema. 9 | 10 | ## Usage 11 | 12 | ### The View 13 | 14 | This view provides a list of all dictionary views within Oracle database accompanied with column names and column comments. 15 | 16 | It is similar to APEX_DICTIONARY view. 17 | 18 | Read more on my blog post: 19 | 20 | [https://zorantica.blogspot.com/2022/04/oracle-apexdictionary-and-dbadictionary.html](https://zorantica.blogspot.com/2022/04/oracle-apexdictionary-and-dbadictionary.html) 21 | 22 | ### Documentation Generatior 23 | 24 | Big thanks goes to [Connor McDonald](https://connor-mcdonald.com/) and his blog post 25 | 26 | [https://connor-mcdonald.com/2025/02/26/the-apex-data-dictionary/?unapproved=29590&moderation-hash=b30c9e18937ecb67f6a458b7b0413d4a#respond](https://connor-mcdonald.com/2025/02/26/the-apex-data-dictionary/?unapproved=29590&moderation-hash=b30c9e18937ecb67f6a458b7b0413d4a#respond) 27 | 28 | I adapted his script for database dictionary views. 29 | 30 | To generate the documentation download the script and run it from SQLPlus. 31 | 32 | The result is a HTML file containing descriptions and details for all database dictionary views. An example of the generated document can be found [here](dba_docs.html). -------------------------------------------------------------------------------- /dba_dictionary/dba_dictionary.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE VIEW DBA_DICTIONARY AS 2 | SELECT 3 | d.table_name as view_name, 4 | atc.column_id, 5 | atc.column_name, 6 | com.comments as comments, 7 | 'Column' as comment_type, 8 | null as parent_view 9 | FROM 10 | all_tab_columns atc 11 | JOIN dictionary d ON atc.table_name = d.table_name AND atc.owner = 'SYS' 12 | LEFT JOIN all_col_comments com ON atc.table_name = com.table_name AND atc.column_name = com.column_name AND atc.owner = 'SYS' 13 | UNION ALL 14 | SELECT 15 | d.table_name, 16 | 0 as column_id, 17 | null as column_name, 18 | com.comments as comments, 19 | 'View' as comment_type, 20 | null as parent_view 21 | FROM 22 | dictionary d 23 | LEFT JOIN all_tab_comments com ON d.table_name = com.table_name AND com.owner = 'SYS' 24 | ORDER BY 25 | view_name, 26 | column_id 27 | ; -------------------------------------------------------------------------------- /dba_dictionary/generate_docs.sql: -------------------------------------------------------------------------------- 1 | set termout off 2 | store set sqlplus_settings replace 3 | clear breaks 4 | clear columns 5 | clear computes 6 | set feedback off 7 | set verify off 8 | set pages 0 9 | set lines 2000 10 | set define off 11 | set trimspool on 12 | set verify off 13 | set feedback off 14 | col seq nopri 15 | set sqlterminator off 16 | SELECT 17 | line || CASE WHEN substr(seq, 1, 2) = '01' and substr(lead(seq) over (order by seq), 1, 2) = '02' THEN '' ELSE null END as line 18 | FROM 19 | ( 20 | with comment_data as ( 21 | SELECT 22 | view_name, 23 | CASE WHEN column_id > 0 THEN column_name ELSE null END as column_name, 24 | comments, 25 | column_id, 26 | CASE WHEN column_id > 0 THEN count(*) over ( partition by view_name) - 1 ELSE -1 END as num_cols, 27 | CASE WHEN column_id = 0 THEN count(distinct view_name) over () ELSE -1 END as num_views 28 | FROM dba_dictionary 29 | ) 30 | select 31 | ''||view_name||''||comments||'' as line, 32 | '01-'||rpad(view_name,200)||'00000' seq 33 | from comment_data 34 | where column_id = 0 35 | union all 36 | select 37 | case when column_id = 0 then '

'||view_name||'

'||comments||' Back to top

' end|| 38 | case when column_id > 0 then '' end|| 39 | case when column_id = num_cols then '
'||column_name||''||comments||'
' end, 40 | '02-'||rpad(view_name,200)||lpad(column_id,5,'0') seq 41 | from comment_data 42 | order by seq 43 | ) 44 | 45 | spool dba_docs.html 46 | pro 47 | pro 48 | pro 107 | pro 108 | pro 109 | pro 110 | pro

DBA dictionary views

111 | pro 112 | / 113 | pro 114 | spool off 115 | set termout off 116 | @sqlplus_settings 117 | clear breaks 118 | clear columns 119 | clear computes 120 | clear seq clear 121 | set termout on -------------------------------------------------------------------------------- /lob_2_script/README.md: -------------------------------------------------------------------------------- 1 | # "Lob 2 Script" utility 2 | 3 | The utility provides You functionality to create PL/SQL script from a binary file content (LOB).
4 | Produced script can be included in Your patches and executed on the target environment, storing the LOB content in the database table cell.
5 | I find this utility very useful when I need to include binary files in my patches such as APEX Office Print templates, PDF files or images, which content is going to be stored in the database tables. 6 | 7 | ## History of changes: 8 | - 1.0 - initial version 9 | 10 | ## Install instructions 11 | - Create the package specification and the package body in the target schema. 12 | - Optionally import the [APEX application](https://github.com/zorantica/db_apex_utils/tree/main/application) in Your workspace for easier usage of this utility (APEX 19.2 or newer). 13 | 14 | ## Usage 15 | 16 | ### From APEX UI: 17 | First select a file source (upload a file or read a file content from the table).
18 | If You selected an "Upload file" option then You should to upload a file manually in the item named "File". You may use a drag and drop approach or click on the item and browse.
19 | If You selected a "Read a file content from the table" then the file content is going to be read automatically from the selected table, selected column and where condition entered in items below. Those 3 values should determine exactly one cell in the table containing LOB value.
20 | Then enter a target table, column and where condition to percisely determine the file destination... a single cell in the table where the LOB content is going to be stored on the target environment.
21 | Then click on a Create Script button... and that's it. The document is going to be downloaded in Your browser. 22 | 23 | screen 24 | 25 | The generated PL/SQL script looks like this: 26 | 27 | script header 28 | 29 | ... 30 | 31 | script header 32 | 33 | 34 | ### From PL/SQL script 35 | ```sql 36 | DECLARE 37 | l_script clob; 38 | 39 | BEGIN 40 | l_script := 41 | lob_2_script.f_generate_script ( 42 | p_table => 'ZORANDBA.TEST', 43 | p_column => 'BLOB_DOC', 44 | p_column_type => 'B', 45 | p_where => 'ID = 1', 46 | p_lob_source => 'TABLE' 47 | ); 48 | 49 | END; 50 | ``` 51 | 52 | ## Program unit specs 53 | 54 | ### Function f_generate_script 55 | 56 | Function returns a CLOB value containg a PL/SQL script, which can be included in the patch or executed in the target environment. 57 | 58 | Parameters: 59 | - p_table - target table, in which the LOB contect is going to be stored 60 | - p_column - target table column (CLOB or BLOB), in which the LOB contect is going to be stored 61 | - p_column_type - C for CLOB or B for BLOB 62 | - p_where - where condition for the target table, which determines one record, in which the LOB content is going to be stored; the combination of column and where condition is determining one table cell to store LOB content 63 | - p_lob_source - LOB content source; values are: "PARAM" (content is read from function input parameter p_file), "APEX_VIEW" (a single file from APEX_APPLICATION_TEMP_FILES view - used for APEX UI), "READ_FROM_TABLE" (read from the database table - the cell containing the content is deteremined by function parameters p_table, p_column and p_where) 64 | - p_file - a blob content, if the p_lob_source is "PARAM" 65 | 66 | -------------------------------------------------------------------------------- /lob_2_script/lob_2_script.pkb: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE PACKAGE BODY lob_2_script IS 2 | 3 | 4 | 5 | FUNCTION f_lob_type ( 6 | p_table varchar2, 7 | p_column varchar2 8 | ) RETURN varchar2 IS 9 | 10 | lcLobType varchar2(1); 11 | 12 | BEGIN 13 | SELECT 14 | CASE 15 | WHEN data_type = 'CLOB' THEN 'C' 16 | ELSE 'B' 17 | END 18 | INTO 19 | lcLobType 20 | FROM 21 | all_tab_columns 22 | WHERE 23 | owner || '.' || table_name = p_table 24 | AND column_name = p_column 25 | ; 26 | 27 | RETURN lcLobType; 28 | 29 | EXCEPTION WHEN others THEN 30 | RETURN 'B'; 31 | 32 | END f_lob_type; 33 | 34 | 35 | 36 | FUNCTION f_generate_script( 37 | p_table varchar2, 38 | p_column varchar2, 39 | p_column_type varchar2, --"C" for CLOB; "B" for BLOB 40 | p_where varchar2, 41 | p_lob_source varchar2, --"PARAM" as p_file_blob parameter, "APEX_VIEW" as single file from apex_application_temp_file_blobs view, "READ_FROM_TABLE" read from source table 42 | p_file_blob blob default null 43 | ) RETURN clob IS 44 | 45 | lbBlob blob; 46 | lcClob clob; 47 | lrPieces apex_t_varchar2; 48 | 49 | PROCEDURE p_add(p_text varchar2 default null) IS 50 | BEGIN 51 | lcClob := lcClob || p_text || chr(10); 52 | END p_add; 53 | 54 | BEGIN 55 | --get document 56 | if p_lob_source = 'TABLE' then 57 | EXECUTE IMMEDIATE 58 | 'SELECT ' || 59 | CASE WHEN p_column_type = 'C' THEN 'lob_2_script.f_clob_to_blob(' || p_column || ')' ELSE p_column END || 60 | ' FROM ' || p_table || 61 | ' WHERE ' || p_where 62 | INTO lbBlob; 63 | 64 | elsif p_lob_source = 'APEX_VIEW' then 65 | SELECT blob_content 66 | INTO lbBlob 67 | FROM apex_application_temp_files 68 | WHERE rownum = 1; 69 | 70 | elsif p_lob_source = 'PARAM' then 71 | lbBlob := p_file_blob; 72 | 73 | else 74 | RAISE_APPLICATION_ERROR(-20001, 'Selected source option is not valid. It must be TABLE, APEX_VIEW or PARAM.'); 75 | 76 | end if; 77 | 78 | 79 | --encode to base64 and split into rows 80 | lcClob := replace( apex_web_service.blob2clobbase64(p_blob => lbBlob), chr(13) || chr(10), chr(10) ); 81 | lrPieces := apex_string.split(lcClob); 82 | 83 | 84 | --P R E P A R E S C R I P T 85 | --header 86 | lcClob := null; 87 | p_add('DECLARE'); 88 | p_add; 89 | p_add(' lcClob clob;'); 90 | p_add(' lbBlob blob;'); 91 | p_add; 92 | 93 | p_add(q'[ function decode_base64(p_clob_in in clob) return blob is 94 | v_blob blob; 95 | v_result blob; 96 | v_offset integer; 97 | v_buffer_size binary_integer := 48; 98 | v_buffer_varchar varchar2(48); 99 | v_buffer_raw raw(48); 100 | begin 101 | if p_clob_in is null then 102 | return null; 103 | end if; 104 | dbms_lob.createtemporary(v_blob, true); 105 | v_offset := 1; 106 | for i in 1 .. ceil(dbms_lob.getlength(p_clob_in) / v_buffer_size) loop 107 | dbms_lob.read(p_clob_in, v_buffer_size, v_offset, v_buffer_varchar); 108 | v_buffer_raw := utl_raw.cast_to_raw(v_buffer_varchar); 109 | v_buffer_raw := utl_encode.base64_decode(v_buffer_raw); 110 | dbms_lob.writeappend(v_blob, utl_raw.length(v_buffer_raw), v_buffer_raw); 111 | v_offset := v_offset + v_buffer_size; 112 | end loop; 113 | v_result := v_blob; 114 | dbms_lob.freetemporary(v_blob); 115 | return v_result; 116 | end decode_base64;]'); 117 | p_add; 118 | 119 | if p_column_type = 'C' then 120 | p_add(q'[ FUNCTION f_blob_to_clob( 121 | blob_in IN blob, 122 | plEncoding IN NUMBER default 0) RETURN clob IS 123 | 124 | v_clob Clob; 125 | v_in Pls_Integer := 1; 126 | v_out Pls_Integer := 1; 127 | v_lang Pls_Integer := 0; 128 | v_warning Pls_Integer := 0; 129 | v_id number(10); 130 | 131 | BEGIN 132 | if blob_in is null then 133 | return null; 134 | end if; 135 | 136 | v_in:=1; 137 | v_out:=1; 138 | dbms_lob.createtemporary(v_clob,TRUE); 139 | DBMS_LOB.convertToClob(v_clob, 140 | blob_in, 141 | DBMS_lob.getlength(blob_in), 142 | v_in, 143 | v_out, 144 | plEncoding, 145 | v_lang, 146 | v_warning); 147 | 148 | RETURN v_clob; 149 | 150 | END f_blob_to_clob;]'); 151 | p_add; 152 | end if; 153 | 154 | 155 | p_add('BEGIN'); 156 | 157 | --lines 158 | FOR t in 1 .. lrPieces.count LOOP 159 | p_add(' lcClob := lcClob || ''' || lrPieces(t) || ''';'); 160 | END LOOP; 161 | p_add; 162 | 163 | --convert back to blob 164 | p_add(' lbBlob := decode_base64(lcClob);'); 165 | p_add; 166 | 167 | --update desired record 168 | p_add( 169 | ' UPDATE ' || p_table || 170 | ' SET ' || p_column || ' = ' || 171 | CASE p_column_type WHEN 'B' THEN 'lbBlob' ELSE 'f_blob_to_clob(lbBlob)' END || 172 | ' WHERE ' || p_where || 173 | ';' 174 | ); 175 | p_add; 176 | 177 | --finish 178 | p_add(' COMMIT;'); 179 | p_add; 180 | p_add('END;'); 181 | p_add('/'); 182 | 183 | DELETE FROM apex_application_temp_files; 184 | COMMIT; 185 | 186 | 187 | RETURN lcClob; 188 | 189 | END f_generate_script; 190 | 191 | 192 | FUNCTION f_clob_to_blob( 193 | c clob, 194 | plEncoding IN NUMBER default 0) RETURN blob IS 195 | 196 | v_blob Blob; 197 | v_in Pls_Integer := 1; 198 | v_out Pls_Integer := 1; 199 | v_lang Pls_Integer := 0; 200 | v_warning Pls_Integer := 0; 201 | v_id number(10); 202 | 203 | BEGIN 204 | if c is null then 205 | return null; 206 | end if; 207 | 208 | v_in:=1; 209 | v_out:=1; 210 | dbms_lob.createtemporary(v_blob,TRUE); 211 | 212 | DBMS_LOB.convertToBlob( 213 | v_blob, 214 | c, 215 | DBMS_lob.getlength(c), 216 | v_in, 217 | v_out, 218 | plEncoding, 219 | v_lang, 220 | v_warning 221 | ); 222 | 223 | RETURN v_blob; 224 | 225 | END f_clob_to_blob; 226 | 227 | 228 | PROCEDURE p_download_document ( 229 | p_doc IN OUT blob, 230 | p_file_blob_name varchar2, 231 | p_disposition varchar2 default 'attachment' --values "attachment" and "inline" 232 | ) IS 233 | BEGIN 234 | htp.init; 235 | OWA_UTIL.MIME_HEADER('application/pdf', FALSE); 236 | htp.p('Content-length: ' || dbms_lob.getlength(p_doc) ); 237 | htp.p('Content-Disposition: ' || p_disposition || '; filename="' || p_file_blob_name || '"' ); 238 | OWA_UTIL.HTTP_HEADER_CLOSE; 239 | 240 | WPG_DOCLOAD.DOWNLOAD_FILE(p_doc); 241 | DBMS_LOB.FREETEMPORARY(p_doc); 242 | 243 | apex_application.stop_apex_engine; 244 | END p_download_document; 245 | 246 | 247 | PROCEDURE p_download_document( 248 | p_text IN OUT clob, 249 | p_file_blob_name varchar2, 250 | p_disposition varchar2 default 'attachment' --values "attachment" and "inline" 251 | ) IS 252 | 253 | lbBlob blob; 254 | 255 | BEGIN 256 | lbBlob := f_clob_to_blob(p_text); 257 | 258 | p_download_document( 259 | p_doc => lbBlob, 260 | p_file_blob_name => p_file_blob_name, 261 | p_disposition => p_disposition 262 | ); 263 | 264 | END p_download_document; 265 | 266 | 267 | 268 | PROCEDURE p_generate_script_and_download ( 269 | p_table varchar2, 270 | p_column varchar2, 271 | p_column_type varchar2, --"C" for CLOB; "B" for BLOB 272 | p_where varchar2, 273 | p_lob_source varchar2, --"PARAM" as p_file_blob parameter, "APEX_VIEW" as single file from apex_application_temp_file_blobs view, "READ_FROM_TABLE" read from source table 274 | p_file_blob blob default null 275 | ) IS 276 | 277 | lcClob clob; 278 | 279 | BEGIN 280 | lcClob := f_generate_script ( 281 | p_table => p_table, 282 | p_column => p_column, 283 | p_column_type => p_column_type, 284 | p_where => p_where, 285 | p_lob_source => p_lob_source, 286 | p_file_blob => p_file_blob 287 | ); 288 | 289 | --convert script to blob and download 290 | p_download_document( 291 | p_text => lcClob, 292 | p_file_blob_name => 'lob_doc.sql' 293 | ); 294 | 295 | END p_generate_script_and_download; 296 | 297 | END lob_2_script; 298 | / 299 | 300 | -------------------------------------------------------------------------------- /lob_2_script/lob_2_script.pks: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE PACKAGE lob_2_script IS 2 | 3 | --UTILITY PROGRAM UNITS 4 | FUNCTION f_clob_to_blob( 5 | c clob, 6 | plEncoding IN NUMBER default 0 7 | ) RETURN blob; 8 | 9 | 10 | 11 | FUNCTION f_lob_type ( 12 | p_table varchar2, 13 | p_column varchar2 14 | ) RETURN varchar2; 15 | 16 | 17 | --MAIN PROGRAM UNITS 18 | 19 | /* 20 | Function returns a CLOB value containg a SQL script, 21 | which can be included in the patch or executed in the target environment. 22 | 23 | Parameters: 24 | @ p_table - target table, in which the LOB contect is going to be stored 25 | @ p_column - target table column (CLOB or BLOB), in which the LOB contect is going to be stored 26 | @ p_column_type - C for CLOB or B for BLOB 27 | @ p_where - where condition for the target table, which determines one record, in which the LOB content is going to be stored; the combination of column and where condition is determining one table cell to store LOB content 28 | @ p_lob_source - LOB content source; values are: "PARAM" (content is read from function input parameter p_file), "APEX_VIEW" (a single file from APEX_APPLICATION_TEMP_FILES view - used for APEX UI), "TABLE" (read from the database table - the cell containing the content is deteremined by function parameters p_table, p_column and p_where) 29 | @ p_file - a blob content, if the p_lob_source is "PARAM" 30 | 31 | @return - CLOB value containg a SQL script 32 | 33 | 34 | Usage: 35 | DECLARE 36 | l_script clob; 37 | 38 | BEGIN 39 | l_script := 40 | lob_2_script.f_generate_script ( 41 | p_table => 'ZORANDBA.TEST', 42 | p_column => 'BLOB_DOC', 43 | p_column_type => 'B', 44 | p_where => 'ID = 1', 45 | p_lob_source => 'TABLE' 46 | ); 47 | 48 | END; 49 | */ 50 | FUNCTION f_generate_script( 51 | p_table varchar2, 52 | p_column varchar2, 53 | p_column_type varchar2, 54 | p_where varchar2, 55 | p_lob_source varchar2, 56 | p_file_blob blob default null 57 | ) RETURN clob; 58 | 59 | 60 | -- 61 | PROCEDURE p_generate_script_and_download ( 62 | p_table varchar2, 63 | p_column varchar2, 64 | p_column_type varchar2, 65 | p_where varchar2, 66 | p_lob_source varchar2, 67 | p_file_blob blob default null 68 | ); 69 | 70 | END lob_2_script; 71 | / 72 | 73 | -------------------------------------------------------------------------------- /lob_2_script/screens/screen.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/zorantica/db_apex_utils/c1b18d7baa16be5f141d68abb8a8c535e4adb0f0/lob_2_script/screens/screen.png -------------------------------------------------------------------------------- /lob_2_script/screens/script01.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/zorantica/db_apex_utils/c1b18d7baa16be5f141d68abb8a8c535e4adb0f0/lob_2_script/screens/script01.png -------------------------------------------------------------------------------- /lob_2_script/screens/script02.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/zorantica/db_apex_utils/c1b18d7baa16be5f141d68abb8a8c535e4adb0f0/lob_2_script/screens/script02.png --------------------------------------------------------------------------------