diff --git a/.mvn/maven.config b/.mvn/maven.config index 0de85b77..377d3991 100644 --- a/.mvn/maven.config +++ b/.mvn/maven.config @@ -1 +1 @@ --Drevision=1.4.0 +-Drevision=1.5.0 diff --git a/CHANGELOG.md b/CHANGELOG.md index 08d83e86..c6366489 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -16,6 +16,21 @@ Types of changes: [Unreleased] - [It should be possible to exclude (temporary) database jobs while generating DDL.](https://github.com/paulissoft/oracle-tools/issues/22) +- [Add SQL Datamodeler custom library and transformations scripts.](https://github.com/paulissoft/oracle-tools/issues/46) + +## [1.5.0] - 2022-08-22 + +### Added + +- [Set up Continuous Integration / Delivery / Deployment.](https://github.com/paulissoft/oracle-tools/issues/27) + +### Changed + +- [Upgrade Flyway version.](https://github.com/paulissoft/oracle-tools/issues/45) + +### Fixed + +- [When DDL is generated with the 'sort objects by dependencies' flag, an error is raised for unknown dependencies.](https://github.com/paulissoft/oracle-tools/issues/47) ## [1.4.0] - 2022-07-17 diff --git a/datamodeler/CustomLibrary.js b/datamodeler/CustomLibrary.js new file mode 100644 index 00000000..fbed81ed --- /dev/null +++ b/datamodeler/CustomLibrary.js @@ -0,0 +1,308 @@ +// Custom Transformation Script: Show selected tables - custom +var appView = Java.type('oracle.dbtools.crest.swingui.ApplicationView'); + +function _msg(msg) { + appView.log(msg); +} + +function _getSelectedObjects(model, objectType) { + var appv = model.getAppView(); + var dpv = appv.getCurrentDPV(); + var objects = []; + + _msg('Window: ' + dpv); + // check there is a diagram selected and it belongs to the same model + if (dpv != null && dpv.getDesignPart() == model) { + var tvs = dpv.getSelectedTopViews(); + + for (var i = 0; i < tvs.length; i++) { + var obj = tvs[i].getModel(); + + _msg('Object type: ' + obj.getObjectTypeName()); + + //if table then put its name in the log window + if (objectType.equals(obj.getObjectTypeName())) { + objects[objects.length] = obj + } + } + } + _msg('# Objects of type ' + objectType + ': ' + objects.length); + + return objects; +} + +function _showObject(obj) { + _msg(obj.getName()); +} + +function showSelectedTables(model) { + _getSelectedObjects(model, "Table").forEach(_showObject); +} + +// Custom Transformation Script: Show selected tables - custom +function showSelectedEntities(model) { + _getSelectedObjects(model, "Entity").forEach(_showObject); +} + +// Custom Transformation Script: Copy Comments in RDBMS to Comments (logical) - custom | logical +var maxLength = 4000; + +function _copyCommentInRDBMS(object) { + _showObject(object); + if (object.getComment().equals("")) { + if (!object.getCommentInRDBMS().equals("")) { + if (object.getCommentInRDBMS().length() > maxLength) { + object.setComment(object.getCommentInRDBMS().substring(0, maxLength)); + } else { + object.setComment(object.getCommentInRDBMS()); + } + object.setDirty(true); + } + } +} + +function copyCommentsInRDBMS_logical(model) { + var entities = model.getEntitySet().toArray(); + + for (var e = 0; e < entities.length; e++) { + var entity = entities[e]; + + _copyCommentInRDBMS(entity); + + var attributes = entity.getElements(); + + for (var i = 0; i < attributes.length; i++) { + _copyCommentInRDBMS(attributes[i]); + } + + var keys = entity.getKeys(); + + for (var i = 0; i < keys.length; i++) { + var key = keys[i]; + + if (!key.isFK()) { + _copyCommentInRDBMS(key); + } else { + _copyCommentInRDBMS(key.getFKAssociation()); + } + } + } +} + +// Custom Transformation Script: Copy Preferred Abbreviation to Short Name - custom | logical +function _copyPreferredAbbreviation(object) { + _showObject(object); + if (object.getShortName().equals("")) { + var preferredAbbreviation = object.getPreferredAbbreviation(); + + if (!preferredAbbreviation.equals("")) { + object.setShortName(preferredAbbreviation); + object.setDirty(true); + } + } +} + +function copyPreferredAbbreviation(model) { + var entities = model.getEntitySet().toArray(); + + for (var e = 0; e < entities.length; e++) { + _copyPreferredAbbreviation(entities[e]); + } +} + +// Custom Transformation Script: Set Relation Name - custom | logical +function _setRelationName(object, sourceShortName, sourceAbbreviation, targetShortName, targetAbbreviation) { + _showObject(object); + + var sourceName = (sourceAbbreviation.equals('') ? sourceShortName : sourceAbbreviation); + var targetName = (targetAbbreviation.equals('') ? targetShortName : targetAbbreviation); + var name = (sourceName.equals('') || targetName.equals('') ? '' : sourceName + '_' + targetName); + + if (!name.equals('') && !object.getName().equals(name)) { + object.setName(name); + object.setDirty(true); + } +} + +function setRelationName(model) { + var relations = model.getRelationSet().toArray(); + + for (var r = 0; r < relations.length; r++) { + _setRelationName(relations[r], + relations[r].getSourceEntity().getShortName(), + relations[r].getSourceEntity().getPreferredAbbreviation(), + relations[r].getTargetEntity().getShortName(), + relations[r].getTargetEntity().getPreferredAbbreviation()); + } +} + +// Custom Transformation Script: Copy Comments in RDBMS to Comments (relational) - custom | relational +function copyCommentsInRDBMS_relational(model) { + var tables = model.getTableSet().toArray(); + + for (var t = 0; t < tables.length; t++) { + var table = tables[t]; + + _copyCommentInRDBMS(table); + + var columns = table.getElements(); + var size = table.getElementsCollection().size(); + + for (var i = 0; i < columns.length; i++) { + _copyCommentInRDBMS(columns[i]); + } + + var keys = table.getKeys(); + + for (var i = 0; i < keys.length; i++) { + var key = keys[i]; + + if (!key.isFK()) { + _copyCommentInRDBMS(key); + } else { + _copyCommentInRDBMS(key.getFKAssociation()); + } + } + } +} + +// Custom Transformation Script: Set security options - custom | relational +function _setSecurityOptions(table) { + _showObject(table); + + var cols = table.getElements(); + + for (var c = 0; c < cols.length; c++) { + if (cols[c].isContainsPII() != true) { + cols[c].setContainsPII(false); + } + if (cols[c].isContainsSensitiveInformation() != true) { + cols[c].setContainsSensitiveInformation(false); } + } + table.setDirty(true); +} + +function setSecurityOptions(model) { + var tables = model.getTableSet().toArray(); + + for (var t = 0; t < tables.length; t++) { + _setSecurityOptions(tables[t]); + } +} + +// Custom Transformation Script: Set selected security options - custom | relational +function setSelectedSecurityOptions(model) { + var tables = _getSelectedObjects(model, "Table"); + + for (var t = 0; t < tables.length; t++) { + _setSecurityOptions(tables[t]); + } +} + +// Custom Transformation Script: Table names plural - custom | relational +function _setTableNamePlural(table) { + _showObject(table); + + var tableName = table.getName(); + + if (tableName.endsWith("Y")) { + // Y -> IES + table.setName(tableName.slice(0, -1) + "IES"); + table.setDirty(true); + } else if (tableName.endsWith("X")) { + // X -> CES + table.setName(tableName.slice(0, -1) + "CES"); + table.setDirty(true); + } else if (!tableName.endsWith("S")) { + // . -> .S + table.setName(tableName + "S"); + table.setDirty(true); + } +} + +function setTableNamesPlural(model) { + var tables = model.getTableSet().toArray(); + + for (var t = 0; t < tables.length; t++) { + _setTableNamePlural(tables[t]); + } +} + +// Custom Transformation Script: Set Use Domain Constraints - custom | relational +function _setUseDomainConstraints(table) { + _showObject(table); + + var cols = table.getElements(); + + for(var c = 0; c < cols.length; c++) { + if (cols[c].getDomain() != null && cols[c].getDomain().getName() != "Unknown" && cols[c].getUseDomainConstraints() != true) { + cols[c].setUseDomainConstraints(true); + table.setDirty(true); + } + } +} + +function setUseDomainConstraints(model) { + var tables = model.getTableSet().toArray(); + + for (var t = 0; t < tables.length; t++) { + _setUseDomainConstraints(tables[t]); + } +} + +// Custom Transformation Script: Define IDENTITY clause for ID columns - custom | relational +function _setIdentityColumn_relational(table) { + _showObject(table); + + var cols = table.getElements(); + + for (var c = 0; c < cols.length; c++) { + if (cols[c].getName().equals("ID")) { + cols[c].setAutoIncrementColumn(true); + cols[c].setIdentityColumn(true); + cols[c].setAutoIncrementGenerateTrigger(false); + cols[c].setDirty(true); + } + } +} + +function _setIdentityColumn_physical(table) { + _showObject(table); + + var cols = table.getColumns().toArray(); + var clause = "IDENTITY_CLAUSE"; // not conform the SQL Data Modeler 18 documentation (!) + + for (var c = 0; c < cols.length; c++) { + if (cols[c].getName().equals("ID")) { + cols[c].setAutoIncrementDDL(clause); + cols[c].setDirty(true); + } + } +} + +function _setIdentityColumns(relationalTables, physicalTables) { + var tableNames = [] + + for (var rt = 0; rt < relationalTables.length; rt++) { + _setIdentityColumn_relational(relationalTables[rt]); + tableNames[tableNames.length] = relationalTables[rt].getName(); + + for (var pt = 0; pt < physicalTables.length; pt++) { + if (relationalTables[rt].getName().equals(physicalTables[pt].getName())) { + _setIdentityColumn_physical(physicalTables[pt]); + break; + } + } + } +} + +function setIdentityColumns(model) { + _setIdentityColumns(model.getTableSet().toArray(), + model.getStorageDesign().getTableProxySet().toArray()); +} + +// Custom Transformation Script: Define IDENTITY clause for selected ID columns - custom | relational +function setSelectedIdentityColumns(model) { + _setIdentityColumns(_getSelectedObjects(model, "Table"), + model.getStorageDesign().getTableProxySet().toArray()); +} diff --git a/datamodeler/CustomLibrary.xml b/datamodeler/CustomLibrary.xml new file mode 100644 index 00000000..c16effc1 --- /dev/null +++ b/datamodeler/CustomLibrary.xml @@ -0,0 +1,362 @@ + + + + + + + + + + \ No newline at end of file diff --git a/datamodeler/CustomTransformationScripts.xml b/datamodeler/CustomTransformationScripts.xml index 4b3819f9..b1aa09bb 100644 --- a/datamodeler/CustomTransformationScripts.xml +++ b/datamodeler/CustomTransformationScripts.xml @@ -360,15 +360,3193 @@ if(template!=null){ }]]> - + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + - - - - - - - + - - - - - - - - - - - - \ No newline at end of file diff --git a/db/app/ddl/src/full/R__09.ORACLE_TOOLS.PACKAGE_SPEC.PKG_DDL_UTIL.sql b/db/app/ddl/src/full/R__09.ORACLE_TOOLS.PACKAGE_SPEC.PKG_DDL_UTIL.sql index 6c19bc2d..01083adc 100644 --- a/db/app/ddl/src/full/R__09.ORACLE_TOOLS.PACKAGE_SPEC.PKG_DDL_UTIL.sql +++ b/db/app/ddl/src/full/R__09.ORACLE_TOOLS.PACKAGE_SPEC.PKG_DDL_UTIL.sql @@ -25,6 +25,7 @@ CREATE OR REPLACE PACKAGE "ORACLE_TOOLS"."PKG_DDL_UTIL" AUTHID CURRENT_USER IS c_use_sqlterminator constant boolean := false; -- pkg_dd_util v4/v5 c_debugging constant naturaln := 1; -- 0: none, 1: standard, 2: verbose, 3: even more verbose + c_debugging_parse_ddl constant boolean := true; -- pivotal issues @@ -381,6 +382,29 @@ CREATE OR REPLACE PACKAGE "ORACLE_TOOLS"."PKG_DDL_UTIL" AUTHID CURRENT_USER IS return integer deterministic; + function fetch_ddl + ( p_schema in t_schema_nn default user + , p_object_type in t_metadata_object_type default null + , p_object_names in t_object_names default null + , p_object_names_include in t_numeric_boolean default null + , p_grantor_is_schema in t_numeric_boolean_nn default 0 + , p_transform_param_list in varchar2 default c_transform_param_list + ) + return sys.ku$_ddls + pipelined; + + function fetch_ddl + ( p_schema in t_schema_nn + , p_object_type in t_metadata_object_type + , p_object_names in t_object_names + , p_object_names_include in t_numeric_boolean + , p_use_schema_export in t_numeric_boolean_nn + , p_schema_object_tab in oracle_tools.t_schema_object_tab + , p_transform_param_list in varchar2 + ) + return sys.ku$_ddls + pipelined; + /* -- Help function to get the DDL belonging to a list of allowed objects returned by get_schema_object() */ diff --git a/db/app/ddl/src/full/R__10.ORACLE_TOOLS.VIEW.V_MY_FETCH_DDL.sql b/db/app/ddl/src/full/R__10.ORACLE_TOOLS.VIEW.V_MY_FETCH_DDL.sql new file mode 100644 index 00000000..5c962534 --- /dev/null +++ b/db/app/ddl/src/full/R__10.ORACLE_TOOLS.VIEW.V_MY_FETCH_DDL.sql @@ -0,0 +1,17 @@ +CREATE OR REPLACE VIEW "ORACLE_TOOLS"."V_MY_FETCH_DDL" ("DDL#", "DDLTEXT", "ITEM", "VALUE", "OBJECT_ROW") AS +with src as ( + select rownum as ddl# + , t.* + from table + ( oracle_tools.pkg_ddl_util.fetch_ddl + ( p_schema => user + ) + ) t +) +select t.ddl# +, t.ddltext +, o.item +, o.value +, o.object_row +from src t +, table(t.parseditems) o; diff --git a/db/app/ddl/src/full/R__14.ORACLE_TOOLS.PACKAGE_BODY.PKG_DDL_UTIL.sql b/db/app/ddl/src/full/R__14.ORACLE_TOOLS.PACKAGE_BODY.PKG_DDL_UTIL.sql index 1a54c499..66a1af3e 100644 --- a/db/app/ddl/src/full/R__14.ORACLE_TOOLS.PACKAGE_BODY.PKG_DDL_UTIL.sql +++ b/db/app/ddl/src/full/R__14.ORACLE_TOOLS.PACKAGE_BODY.PKG_DDL_UTIL.sql @@ -774,6 +774,23 @@ $end , p_grantable out nocopy varchar2 ) is + procedure nullify_output_parameters + is + begin + -- nullify all output parameters + p_verb := null; + p_object_name := null; + p_object_type := null; + p_object_schema := null; + p_base_object_name := null; + p_base_object_type := null; + p_base_object_schema := null; + p_column_name := null; + p_grantee := null; + p_privilege := null; + p_grantable := null; + end nullify_output_parameters; + procedure parse_alter is l_constraint varchar2(32767 char) := oracle_tools.pkg_str_util.dbms_lob_substr(p_clob => p_ddl.ddlText, p_amount => 32767); @@ -843,7 +860,7 @@ $end end loop; l_constraint := substr(l_constraint, l_pos1); -$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 2 $then +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging_parse_ddl $then dbug.print(dbug."info", 'l_constraint: "%s"', l_constraint); $end if l_constraint like l_constraint_expr_tab(1) @@ -1143,8 +1160,13 @@ $end -- :REF_CONSTRAINT:UN_DG_LIST_UN_DG_CLASSIFI_FK1:::: p_object_type := case when instr(l_constraint, ' FOREIGN KEY ') > 0 then 'REF_CONSTRAINT' else 'CONSTRAINT' end; - elsif l_constraint not like l_constraint_expr_tab(7) + elsif l_constraint like l_constraint_expr_tab(7) then + null; + elsif trim(replace(replace(l_constraint, chr(13)), chr(10))) is null + then + nullify_output_parameters; + else raise_application_error(oracle_tools.pkg_ddl_error.c_could_not_parse, 'Could not parse "' || l_constraint || '"'); end if; end parse_alter; @@ -1159,6 +1181,10 @@ $end l_pos2 pls_integer; l_comment constant all_tab_comments.comments%type := oracle_tools.pkg_str_util.dbms_lob_substr(p_clob => p_ddl.ddlText, p_amount => case when l_pos1 > 0 then l_pos1 else 2000 end); begin +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging_parse_ddl $then + dbug.print(dbug."info", 'l_comment: "%s"', l_comment); +$end + if p_base_object_schema is null then l_pos1 := instr(l_comment, '"', 1, 1); @@ -1198,7 +1224,8 @@ $end then p_base_object_type := 'MATERIALIZED_VIEW'; - else -- column + when l_comment like '% ON COLUMN %' + then select min(obj.object_type) into p_base_object_type from all_objects obj @@ -1208,6 +1235,12 @@ $end and obj.generated = 'N' -- GPA 2016-12-19 #136334705 ; + when trim(replace(replace(l_comment, chr(13)), chr(10))) is null + then + nullify_output_parameters; + + else + raise_application_error(oracle_tools.pkg_ddl_error.c_could_not_parse, 'Could not parse "' || l_comment || '"'); end case; end if; exception @@ -1228,11 +1261,19 @@ $end l_pos1 pls_integer := null; l_pos2 pls_integer := null; begin +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging_parse_ddl $then + dbug.print(dbug."info", 'l_plsql_block: "%s"', l_plsql_block); +$end if upper(l_plsql_block) like q'[%DBMS_SCHEDULER.CREATE_%('"%"'%]' then l_pos1 := instr(l_plsql_block, '"', 1, 1); l_pos2 := instr(l_plsql_block, '"', 1, 2); p_object_name := substr(l_plsql_block, l_pos1+1, l_pos2 - (l_pos1+1)); + elsif trim(replace(replace(l_plsql_block, chr(13)), chr(10))) is null + then + nullify_output_parameters; + else + raise_application_error(oracle_tools.pkg_ddl_error.c_could_not_parse, 'Could not parse "' || l_plsql_block || '"'); end if; end parse_procobj; @@ -1242,18 +1283,35 @@ $end l_pos1 pls_integer := null; l_pos2 pls_integer := null; begin - -- CREATE INDEX ""."schema_version_s_idx" ON ""."schema_version" - if p_base_object_schema is null +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging_parse_ddl $then + dbug.print(dbug."info", 'l_index: "%s"', l_index); +$end + if l_index like 'CREATE INDEX %' or + l_index like 'CREATE UNIQUE INDEX %' or + l_index like 'CREATE BITMAP INDEX %' then - l_pos1 := instr(l_index, '"', 1, 5); - l_pos2 := instr(l_index, '"', 1, 6); - p_base_object_schema := substr(l_index, l_pos1+1, l_pos2 - (l_pos1+1)); - end if; - if p_base_object_name is null + -- CREATE INDEX ""."schema_version_s_idx" ON ""."schema_version" + if p_base_object_schema is null + then + -- CREATE INDEX ""."schema_version_s_idx" ON ""."schema_version" + if p_base_object_schema is null + then + l_pos1 := instr(l_index, '"', 1, 5); + l_pos2 := instr(l_index, '"', 1, 6); + p_base_object_schema := substr(l_index, l_pos1+1, l_pos2 - (l_pos1+1)); + end if; + if p_base_object_name is null + then + l_pos1 := instr(l_index, '"', 1, 7); + l_pos2 := instr(l_index, '"', 1, 8); + p_base_object_name := substr(l_index, l_pos1+1, l_pos2 - (l_pos1+1)); + end if; + end if; + elsif trim(replace(replace(l_index, chr(13)), chr(10))) is null then - l_pos1 := instr(l_index, '"', 1, 7); - l_pos2 := instr(l_index, '"', 1, 8); - p_base_object_name := substr(l_index, l_pos1+1, l_pos2 - (l_pos1+1)); + nullify_output_parameters; + else + raise_application_error(oracle_tools.pkg_ddl_error.c_could_not_parse, 'Could not parse "' || l_index || '"'); end if; end parse_index; @@ -1263,24 +1321,30 @@ $end l_pos1 pls_integer := null; l_pos2 pls_integer := null; begin - -- GRANT SELECT ON ""."" TO ""; - -- or - -- GRANT SELECT ON ""."
" TO "" WITH GRANT OPTION; - p_grantable := case when l_object_grant like '% WITH GRANT OPTION%' then 'YES' else 'NO' end; - l_pos1 := instr(l_object_grant, 'GRANT ') + length('GRANT '); - l_pos2 := instr(l_object_grant, ' ON "'); - p_privilege := substr(l_object_grant, l_pos1, l_pos2 - l_pos1); +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging_parse_ddl $then + dbug.print(dbug."info", 'l_object_grant: "%s"', l_object_grant); +$end + if l_object_grant like 'GRANT %' + then + -- GRANT SELECT ON ""."
" TO ""; + -- or + -- GRANT SELECT ON ""."
" TO "" WITH GRANT OPTION; + p_grantable := case when l_object_grant like '% WITH GRANT OPTION%' then 'YES' else 'NO' end; + l_pos1 := instr(l_object_grant, 'GRANT ') + length('GRANT '); + l_pos2 := instr(l_object_grant, ' ON "'); + p_privilege := substr(l_object_grant, l_pos1, l_pos2 - l_pos1); + elsif trim(replace(replace(l_object_grant, chr(13)), chr(10))) is null + then + nullify_output_parameters; + else + raise_application_error(oracle_tools.pkg_ddl_error.c_could_not_parse, 'Could not parse "' || l_object_grant || '"'); + end if; end parse_object_grant; begin -$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 2 $then +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging_parse_ddl $then dbug.enter(g_package_prefix || 'PARSE_DDL'); - dbug.print - ( dbug."input" - , 'p_schema: %s; p_ddl.ddlText: %s' - , p_schema - , oracle_tools.pkg_str_util.dbms_lob_substr(p_clob => p_ddl.ddlText, p_amount => 200) - ); + dbug.print(dbug."input", 'p_schema: %s', p_schema); $end if p_ddl.parseditems is not null and @@ -1334,10 +1398,13 @@ $end elsif p_object_type = 'OBJECT_GRANT' -- GPA 2016-11-28 #135018217 then parse_object_grant; + elsif p_object_type = 'PROCACT_SYSTEM' + then + nullify_output_parameters; end if; end if; -$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 2 $then +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging_parse_ddl $then dbug.print ( dbug."output" , 'p_verb: %s; p_object_name; %s; p_object_type: %s; p_object_schema: %s' @@ -1972,6 +2039,7 @@ $end procedure md_fetch_ddl ( p_handle in number + , p_split_grant_statement in boolean , p_ddl_tab out nocopy sys.ku$_ddls ) is @@ -2000,9 +2068,15 @@ $end loop l_statement := oracle_tools.pkg_str_util.dbms_lob_substr(p_clob => p_ddl_tab(i_ku$ddls_idx).ddlText, p_offset => 1, p_amount => 4000); $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 2 $then - dbug.print(dbug."info", 'i_ku$ddls_idx: %s; ltrim(l_statement): %s', i_ku$ddls_idx, ltrim(l_statement)); + dbug.print + ( dbug."info" + , 'i_ku$ddls_idx: %s; length(ltrim(l_statement)): %s; ltrim(l_statement): %s' + , i_ku$ddls_idx + , length(ltrim(l_statement)) + , ltrim(l_statement) + ); $end - if ltrim(l_statement) like 'GRANT %, % ON "%' + if p_split_grant_statement and ltrim(l_statement) like 'GRANT %, % ON "%' then l_pos1 := instr(l_statement, 'GRANT ') + length('GRANT '); l_pos2 := instr(l_statement, ' ON "'); @@ -2026,7 +2100,12 @@ $end for i_idx in l_line_tab.first .. l_line_tab.last loop $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 2 $then - dbug.print(dbug."info", 'replace(l_statement, l_privileges, l_line_tab(%s)): %s', i_idx, replace(l_statement, l_privileges, l_line_tab(i_idx))); + dbug.print + ( dbug."info" + , 'replace(l_statement, l_privileges, l_line_tab(%s)): %s' + , i_idx + , replace(l_statement, l_privileges, l_line_tab(i_idx)) + ); $end if i_idx = l_line_tab.first then @@ -2140,109 +2219,116 @@ $end , l_grantable ); - l_object_type := oracle_tools.t_schema_object.dict2metadata_object_type(l_object_type); - l_base_object_type := oracle_tools.t_schema_object.dict2metadata_object_type(l_base_object_type); - - l_schema_object := - oracle_tools.t_schema_object.create_schema_object - ( p_object_schema => l_object_schema - , p_object_type => l_object_type - , p_object_name => l_object_name - , p_base_object_schema => l_base_object_schema - , p_base_object_type => l_base_object_type - , p_base_object_name => l_base_object_name - , p_column_name => l_column_name - , p_grantee => l_grantee - , p_privilege => l_privilege - , p_grantable => l_grantable - ); + if l_verb is null and + ( l_object_name is null and l_object_type is null and l_object_schema is null ) and + ( l_base_object_name is null and l_base_object_type is null and l_base_object_schema is null ) + then + cleanup; + else + l_object_type := oracle_tools.t_schema_object.dict2metadata_object_type(l_object_type); + l_base_object_type := oracle_tools.t_schema_object.dict2metadata_object_type(l_base_object_type); + + l_schema_object := + oracle_tools.t_schema_object.create_schema_object + ( p_object_schema => l_object_schema + , p_object_type => l_object_type + , p_object_name => l_object_name + , p_base_object_schema => l_base_object_schema + , p_base_object_type => l_base_object_type + , p_base_object_name => l_base_object_name + , p_column_name => l_column_name + , p_grantee => l_grantee + , p_privilege => l_privilege + , p_grantable => l_grantable + ); - -- check the object type (base object set if necessary and so on) - l_schema_object.chk(p_schema); + -- check the object type (base object set if necessary and so on) + l_schema_object.chk(p_schema); - p_object_key := l_schema_object.id(); + p_object_key := l_schema_object.id(); - begin - if not(p_object_lookup_tab(p_object_key).ready) - then - p_object_lookup_tab(p_object_key).schema_ddl.add_ddl - ( p_verb => l_verb - , p_text => p_ku$_ddl.ddlText - ); + begin + if not(p_object_lookup_tab(p_object_key).ready) + then + p_object_lookup_tab(p_object_key).schema_ddl.add_ddl + ( p_verb => l_verb + , p_text => p_ku$_ddl.ddlText + ); - begin - p_object_lookup_tab(p_object_key).schema_ddl.chk(p_schema); - exception - when others - then + begin + p_object_lookup_tab(p_object_key).schema_ddl.chk(p_schema); + exception + when others + then $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then - p_object_lookup_tab(p_object_key).schema_ddl.print(); + p_object_lookup_tab(p_object_key).schema_ddl.print(); $end - raise_application_error(oracle_tools.pkg_ddl_error.c_object_not_correct, 'Object ' || p_object_lookup_tab(p_object_key).schema_ddl.obj.id() || ' is not correct.', true); - end; + raise_application_error(oracle_tools.pkg_ddl_error.c_object_not_correct, 'Object ' || p_object_lookup_tab(p_object_key).schema_ddl.obj.id() || ' is not correct.', true); + end; - -- the normal stuff - p_object_lookup_tab(p_object_key).count := p_object_lookup_tab(p_object_key).count + 1; - end if; -- if not(p_object_lookup_tab(p_object_key).ready) - exception - when no_data_found - then - case - when schema_object_matches_filter - ( -- filter values - p_object_type => p_object_type - , p_object_names => p_object_names - , p_object_names_include => p_object_names_include - , p_object_types_to_check => null - -- database values - , p_metadata_object_type => l_object_type - , p_object_name => l_object_name - , p_metadata_base_object_type => l_base_object_type - , p_base_object_name => l_base_object_name - ) = 0 -- object not but on purpose - then + -- the normal stuff + p_object_lookup_tab(p_object_key).count := p_object_lookup_tab(p_object_key).count + 1; + end if; -- if not(p_object_lookup_tab(p_object_key).ready) + exception + when no_data_found + then + case + when schema_object_matches_filter + ( -- filter values + p_object_type => p_object_type + , p_object_names => p_object_names + , p_object_names_include => p_object_names_include + , p_object_types_to_check => null + -- database values + , p_metadata_object_type => l_object_type + , p_object_name => l_object_name + , p_metadata_base_object_type => l_base_object_type + , p_base_object_name => l_base_object_name + ) = 0 -- object not but on purpose + then $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 2 $then - dbug.print - ( dbug."info" - , 'l_object_type: %s; l_object_name: %s; l_base_object_type: %s; l_base_object_name' - , l_object_type - , l_object_name - , l_base_object_type - , l_base_object_name - ); + dbug.print + ( dbug."info" + , 'l_object_type: %s; l_object_name: %s; l_base_object_type: %s; l_base_object_name' + , l_object_type + , l_object_name + , l_base_object_type + , l_base_object_name + ); $end - p_object_key := null; + p_object_key := null; - when l_object_type = 'PROCACT_SCHEMA' or - l_object_type = 'PROCACT_SYSTEM' or - l_verb in ('DBMS_JAVA.START_IMPORT', 'DBMS_JAVA.IMPORT_TEXT_CHUNK', 'DBMS_JAVA.IMPORT_RAW_CHUNK', 'DBMS_JAVA.END_IMPORT') - then - p_object_key := null; - - -- GPA 2017-02-05 Ignore the old job package DBMS_JOB - when l_object_type = 'PROCOBJ' and l_verb = 'DBMS_JOB.SUBMIT' - then - p_object_key := null; + when l_object_type = 'PROCACT_SCHEMA' or + l_object_type = 'PROCACT_SYSTEM' or + l_verb in ('DBMS_JAVA.START_IMPORT', 'DBMS_JAVA.IMPORT_TEXT_CHUNK', 'DBMS_JAVA.IMPORT_RAW_CHUNK', 'DBMS_JAVA.END_IMPORT') + then + p_object_key := null; - else - -- GJP 2021-08-27 Ignore this only when the DDL is whitespace only. - if p_ku$_ddl.ddlText is not null + -- GPA 2017-02-05 Ignore the old job package DBMS_JOB + when l_object_type = 'PROCOBJ' and l_verb = 'DBMS_JOB.SUBMIT' then - l_ddl_text := trim(replace(replace(oracle_tools.pkg_str_util.dbms_lob_substr(p_ku$_ddl.ddlText, 32767), chr(10), ' '), chr(13), ' ')); - if l_ddl_text is not null + p_object_key := null; + + else + -- GJP 2021-08-27 Ignore this only when the DDL is whitespace only. + if p_ku$_ddl.ddlText is not null then - raise_application_error - ( oracle_tools.pkg_ddl_error.c_object_not_found - , utl_lms.format_message - ( 'object "%s" not found in allowed objects; ddl: "%s"' - , p_object_key - , substr(l_ddl_text, 1, 2000) - ) - ); + l_ddl_text := trim(replace(replace(oracle_tools.pkg_str_util.dbms_lob_substr(p_ku$_ddl.ddlText, 32767), chr(10), ' '), chr(13), ' ')); + if l_ddl_text is not null + then + raise_application_error + ( oracle_tools.pkg_ddl_error.c_object_not_found + , utl_lms.format_message + ( 'object "%s" not found in allowed objects; ddl: "%s"' + , p_object_key + , substr(l_ddl_text, 1, 2000) + ) + ); + end if; end if; - end if; - end case; - end; + end case; + end; + end if; -- if l_verb is not null cleanup; @@ -2252,7 +2338,7 @@ $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging > $end exception -- GJP 2021-08-30 Ignore this always. - when oracle_tools.pkg_ddl_error.e_object_not_found + when oracle_tools.pkg_ddl_error.e_object_not_found or oracle_tools.pkg_ddl_error.e_could_not_parse then p_object_key := null; cleanup; @@ -4317,6 +4403,10 @@ $end where i.owner = p_schema -- GPA 2017-06-28 #147916863 - As a release operator I do not want comments without table or column. and not(/*substr(i.index_name, 1, 5) = 'APEX$' or */substr(i.index_name, 1, 7) = 'I_MLOG$') + -- GJP 2022-08-22 + -- When constraint_index = 'YES' the index is created as part of the constraint DDL, + -- so it will not be listed as a separated DDL statement. + and not(i.constraint_index = 'YES') and oracle_tools.pkg_ddl_util.schema_object_matches_filter ( -- filter values p_object_type => p_object_type @@ -5411,10 +5501,60 @@ $end return l_result; end is_exclude_name_expr; + function fetch_ddl + ( p_schema in t_schema_nn default user + , p_object_type in t_metadata_object_type default null + , p_object_names in t_object_names default null + , p_object_names_include in t_numeric_boolean default null + , p_grantor_is_schema in t_numeric_boolean_nn default 0 + , p_transform_param_list in varchar2 default c_transform_param_list + ) + return sys.ku$_ddls + pipelined + is + l_use_schema_export constant pls_integer := + case + when p_object_type is not null and substr(p_object_type, 1, 1) != '!' + then 0 + when p_object_names_include = 1 + then 0 + else 1 + end; + l_schema_object_tab oracle_tools.t_schema_object_tab; + begin + get_schema_object + ( p_schema => p_schema + , p_object_type => p_object_type + , p_object_names => p_object_names + , p_object_names_include => p_object_names_include + , p_grantor_is_schema => p_grantor_is_schema + , p_schema_object_tab => l_schema_object_tab + ); + for r in + ( select value(t) as obj + from table + ( oracle_tools.pkg_ddl_util.fetch_ddl + ( p_schema => p_schema + , p_object_type => p_object_type + , p_object_names => p_object_names + , p_object_names_include => p_object_names_include + , p_use_schema_export => l_use_schema_export + , p_schema_object_tab => l_schema_object_tab + , p_transform_param_list => p_transform_param_list + ) + ) t + ) + loop + pipe row (r.obj); + end loop; + + return; -- essential for a pipelined function + end fetch_ddl; + /* -- Help function to get the DDL belonging to a list of allowed objects returned by get_schema_object() */ - function get_schema_ddl + function fetch_ddl ( p_schema in t_schema_nn , p_object_type in t_metadata_object_type , p_object_names in t_object_names @@ -5423,7 +5563,7 @@ $end , p_schema_object_tab in oracle_tools.t_schema_object_tab , p_transform_param_list in varchar2 ) - return oracle_tools.t_schema_ddl_tab + return sys.ku$_ddls pipelined is -- ORA-31642: the following SQL statement fails: @@ -5433,9 +5573,6 @@ $end -- ORA-04092: cannot COMMIT in a trigger pragma autonomous_transaction; - l_object_lookup_tab t_object_lookup_tab; -- list of all objects - l_constraint_lookup_tab t_constraint_lookup_tab; - l_object_key t_object; l_handle number := null; l_ddl_tab sys.ku$_ddls; -- moet package globaal zijn i.v.m. performance @@ -5552,7 +5689,7 @@ $end l_transform_param_tab t_transform_param_tab; - l_program constant t_module := 'GET_SCHEMA_DDL'; -- geen schema omdat l_program in dbms_application_info wordt gebruikt + l_program constant t_module := 'FETCH_DDL'; -- geen schema omdat l_program in dbms_application_info wordt gebruikt -- dbms_application_info stuff l_longops_rec t_longops_rec; @@ -5562,8 +5699,6 @@ $end procedure init is - l_schema_object oracle_tools.t_schema_object; - l_ref_constraint_object oracle_tools.t_ref_constraint_object; begin $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then dbug.enter(g_package_prefix || l_program || '.INIT'); @@ -5571,51 +5706,6 @@ $end get_transform_param_tab(p_transform_param_list, l_transform_param_tab); - if p_schema_object_tab is not null and p_schema_object_tab.count > 0 - then - for i_idx in p_schema_object_tab.first .. p_schema_object_tab.last - loop - begin - l_schema_object := p_schema_object_tab(i_idx); - - l_schema_object.chk(p_schema); - - l_object_key := l_schema_object.id(); - - if not l_object_lookup_tab.exists(l_object_key) - then - oracle_tools.t_schema_ddl.create_schema_ddl - ( p_obj => l_schema_object - , p_ddl_tab => oracle_tools.t_ddl_tab() - , p_schema_ddl => l_object_lookup_tab(l_object_key).schema_ddl - ); - else - raise dup_val_on_index; - end if; - -$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 2 $then - l_schema_object.print(); -$end - - -- now we are going to store constraints for faster lookup in parse_ddl() - if l_schema_object.object_type() in ('CONSTRAINT', 'REF_CONSTRAINT') - then - -- not by constraint name (dbms_metadata does not supply that) but by signature - l_object_key := l_schema_object.signature(); - - if not l_constraint_lookup_tab.exists(l_object_key) - then - l_constraint_lookup_tab(l_object_key) := l_schema_object.id(); - else - raise dup_val_on_index; - end if; - end if; - exception - when others - then raise_application_error(oracle_tools.pkg_ddl_error.c_reraise_with_backtrace, 'Object id: ' || l_schema_object.id() || chr(10) || 'Object signature: ' || l_object_key, true); - end; - end loop; - end if; $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then dbug.leave; exception @@ -5632,6 +5722,7 @@ $end $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then dbug.enter(g_package_prefix || l_program || '.FIND_NEXT_PARAMS'); $end + -- now we are going to find an object type which has at least one object not ready <> loop @@ -5639,30 +5730,6 @@ $end exit find_next_params_loop when l_params_idx is null or l_params_tab(l_params_idx).object_type = 'SCHEMA_EXPORT'; - -- determine whether there is no object which is not ready - l_object_key := l_object_lookup_tab.first; - <> - while l_object_key is not null - loop - if not(l_object_lookup_tab(l_object_key).ready) and - l_object_key like oracle_tools.t_schema_object.id('%', l_params_tab(l_params_idx).object_type, '%', '%', '%', '%', '%', '%', '%', '%') - then - -- we must process this handle -$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then - dbug.print - ( dbug."warning" - , 'Object %s not ready for schema %s and type %s' - , l_object_key - , l_params_tab(l_params_idx).object_schema - , l_params_tab(l_params_idx).object_type - ); -$end - exit find_next_params_loop; - end if; - - l_object_key := l_object_lookup_tab.next(l_object_key); - end loop object_loop; - $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then dbug.print ( dbug."info" @@ -5672,50 +5739,16 @@ $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging > ); $end end loop find_next_params_loop; -$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then - dbug.leave; - exception - when others - then - dbug.leave_on_error; - raise; -$end - end find_next_params; $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then - procedure chk - is - begin - dbug.enter(g_package_prefix || l_program || '.CHK'); - l_object_key := l_object_lookup_tab.first; - while l_object_key is not null - loop - dbug.print - ( case sign(l_object_lookup_tab(l_object_key).count) - when 1 -- found by get_schema_object and fetch_ddl - then dbug."info" - else dbug."warning" - end - , 'l_object_lookup_tab(%s): %s' - , l_object_key - , l_object_lookup_tab(l_object_key).count - ); - if l_object_lookup_tab(l_object_key).count >= 1 - then - null; - else - raise_application_error(oracle_tools.pkg_ddl_error.c_no_ddl_retrieved, 'No DDL retrieved for object ' || l_object_key); - end if; - l_object_key := l_object_lookup_tab.next(l_object_key); - end loop; dbug.leave; exception when others then dbug.leave_on_error; raise; - end chk; $end + end find_next_params; procedure cleanup is @@ -5736,7 +5769,7 @@ $end init; - l_longops_rec := longops_init(p_op_name => 'fetch', p_units => 'objects', p_target_desc => l_program, p_totalwork => l_object_lookup_tab.count); + l_longops_rec := longops_init(p_op_name => 'fetch', p_units => 'objects', p_target_desc => l_program, p_totalwork => case when p_schema_object_tab is not null then p_schema_object_tab.count end); open c_params; fetch c_params bulk collect into l_params_tab; @@ -5774,7 +5807,7 @@ $end ( p_totalwork => case when r_params.object_type = 'SCHEMA_EXPORT' - then l_object_lookup_tab.count - l_longops_rec.sofar + then case when p_schema_object_tab is not null then p_schema_object_tab.count end - l_longops_rec.sofar else r_params.nr_objects end , p_op_name => @@ -5802,7 +5835,7 @@ $end -- objects fetched for this param <> loop - md_fetch_ddl(l_handle, l_ddl_tab); + md_fetch_ddl(l_handle, true, l_ddl_tab); exit fetch_loop when l_ddl_tab is null; @@ -5810,37 +5843,7 @@ $end then for i_ku$ddls_idx in l_ddl_tab.first .. l_ddl_tab.last loop - parse_object - ( p_schema => p_schema - , p_object_type => p_object_type - , p_object_names => p_object_names - , p_object_names_include => p_object_names_include - , p_constraint_lookup_tab => l_constraint_lookup_tab - , p_object_lookup_tab => l_object_lookup_tab - , p_ku$_ddl => l_ddl_tab(i_ku$ddls_idx) - , p_object_key => l_object_key - ); - - if l_object_key is not null - then - -- some checks - if not(l_object_lookup_tab.exists(l_object_key)) - then - raise_application_error - ( oracle_tools.pkg_ddl_error.c_object_not_found - , 'Can not find object with key "' || l_object_key || '"' - ); - end if; - - if not(l_object_lookup_tab(l_object_key).ready) - then - pipe row (l_object_lookup_tab(l_object_key).schema_ddl); - - l_longops_type_rec.sofar := l_longops_type_rec.sofar + 1; - - l_object_lookup_tab(l_object_key).ready := true; - end if; - end if; + pipe row (l_ddl_tab(i_ku$ddls_idx)); end loop; end if; @@ -5854,16 +5857,246 @@ $end md_close(l_handle); exception - when dup_val_on_index + when others then $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then dbug.on_error; $end - raise_application_error - ( oracle_tools.pkg_ddl_error.c_duplicate_item - , 'Duplicate objects to be retrieved: type: ' || r_params.object_type || '; schema: ' || r_params.object_schema || '; base schema: ' || r_params.base_object_schema - ); + md_close(l_handle); + if r_params.object_type = 'SCHEMA_EXPORT' + then + null; + else + raise; + end if; + end; + + find_next_params; + end loop open_handle_loop; + + -- show 100% + longops_done(l_longops_open_rec); + longops_done(l_longops_rec); + + cleanup; + +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then + dbug.leave; +$end + + commit; -- see pragma + + return; -- essential for a pipelined function + exception + when no_data_needed + then + cleanup; +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then + dbug.leave; +$end + when no_data_found + then + cleanup; +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then + dbug.leave_on_error; +$end + raise_application_error(oracle_tools.pkg_ddl_error.c_reraise_with_backtrace, l_program, true); + + when others + then + cleanup; +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then + dbug.leave_on_error; +$end + raise; + end fetch_ddl; + + /* + -- Help function to get the DDL belonging to a list of allowed objects returned by get_schema_object() + */ + function get_schema_ddl + ( p_schema in t_schema_nn + , p_object_type in t_metadata_object_type + , p_object_names in t_object_names + , p_object_names_include in t_numeric_boolean + , p_use_schema_export in t_numeric_boolean_nn + , p_schema_object_tab in oracle_tools.t_schema_object_tab + , p_transform_param_list in varchar2 + ) + return oracle_tools.t_schema_ddl_tab + pipelined + is + l_object_lookup_tab t_object_lookup_tab; -- list of all objects + l_constraint_lookup_tab t_constraint_lookup_tab; + l_object_key t_object; + + l_program constant t_module := 'GET_SCHEMA_DDL'; -- geen schema omdat l_program in dbms_application_info wordt gebruikt + + -- dbms_application_info stuff + l_longops_rec t_longops_rec; + + procedure init + is + l_schema_object oracle_tools.t_schema_object; + l_ref_constraint_object oracle_tools.t_ref_constraint_object; + begin +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then + dbug.enter(g_package_prefix || l_program || '.INIT'); +$end + + if p_schema_object_tab is not null and p_schema_object_tab.count > 0 + then + for i_idx in p_schema_object_tab.first .. p_schema_object_tab.last + loop + begin + l_schema_object := p_schema_object_tab(i_idx); + + l_schema_object.chk(p_schema); + + l_object_key := l_schema_object.id(); + + if not l_object_lookup_tab.exists(l_object_key) + then + oracle_tools.t_schema_ddl.create_schema_ddl + ( p_obj => l_schema_object + , p_ddl_tab => oracle_tools.t_ddl_tab() + , p_schema_ddl => l_object_lookup_tab(l_object_key).schema_ddl + ); + else + raise dup_val_on_index; + end if; + +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 2 $then + l_schema_object.print(); +$end + + -- now we are going to store constraints for faster lookup in parse_ddl() + if l_schema_object.object_type() in ('CONSTRAINT', 'REF_CONSTRAINT') + then + -- not by constraint name (dbms_metadata does not supply that) but by signature + l_object_key := l_schema_object.signature(); + + if not l_constraint_lookup_tab.exists(l_object_key) + then + l_constraint_lookup_tab(l_object_key) := l_schema_object.id(); + else + raise dup_val_on_index; + end if; + end if; + exception + when others + then raise_application_error(oracle_tools.pkg_ddl_error.c_reraise_with_backtrace, 'Object id: ' || l_schema_object.id() || chr(10) || 'Object signature: ' || l_object_key, true); + end; + end loop; + end if; +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then + dbug.leave; + exception + when others + then + dbug.leave_on_error; + raise; +$end + end init; + +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then + procedure chk + is + begin + dbug.enter(g_package_prefix || l_program || '.CHK'); + l_object_key := l_object_lookup_tab.first; + while l_object_key is not null + loop + dbug.print + ( case sign(l_object_lookup_tab(l_object_key).count) + when 1 -- found by get_schema_object and fetch_ddl + then dbug."info" + else dbug."warning" + end + , 'l_object_lookup_tab(%s): %s' + , l_object_key + , l_object_lookup_tab(l_object_key).count + ); + if l_object_lookup_tab(l_object_key).count >= 1 + then + null; + else + raise_application_error(oracle_tools.pkg_ddl_error.c_no_ddl_retrieved, 'No DDL retrieved for object ' || l_object_key); + end if; + l_object_key := l_object_lookup_tab.next(l_object_key); + end loop; + dbug.leave; + exception + when others + then + dbug.leave_on_error; + raise; + end chk; +$end + begin +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then + dbug.enter(g_package_prefix || l_program); + dbug.print + ( dbug."input" + , 'p_schema: %s; p_use_schema_export: %s; p_schema_object_tab.count: %s' + , p_schema + , p_use_schema_export + , case when p_schema_object_tab is not null then p_schema_object_tab.count end + ); +$end + + init; + + l_longops_rec := longops_init(p_op_name => 'fetch', p_units => 'objects', p_target_desc => l_program, p_totalwork => l_object_lookup_tab.count); + + for r in + ( select value(t) as obj + from table + ( oracle_tools.pkg_ddl_util.fetch_ddl + ( p_schema => p_schema + , p_object_type => p_object_type + , p_object_names => p_object_names + , p_object_names_include => p_object_names_include + , p_use_schema_export => p_use_schema_export + , p_schema_object_tab => p_schema_object_tab + , p_transform_param_list => p_transform_param_list + ) + ) t + ) + loop + begin + parse_object + ( p_schema => p_schema + , p_object_type => p_object_type + , p_object_names => p_object_names + , p_object_names_include => p_object_names_include + , p_constraint_lookup_tab => l_constraint_lookup_tab + , p_object_lookup_tab => l_object_lookup_tab + , p_ku$_ddl => r.obj + , p_object_key => l_object_key + ); + + if l_object_key is not null + then + -- some checks + if not(l_object_lookup_tab.exists(l_object_key)) + then + raise_application_error + ( oracle_tools.pkg_ddl_error.c_object_not_found + , 'Can not find object with key "' || l_object_key || '"' + ); + end if; + + if not(l_object_lookup_tab(l_object_key).ready) + then + pipe row (l_object_lookup_tab(l_object_key).schema_ddl); + l_object_lookup_tab(l_object_key).ready := true; + end if; + end if; + + longops_show(l_longops_rec, 0); + exception when oracle_tools.pkg_ddl_error.e_object_not_found then $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then @@ -5880,52 +6113,30 @@ $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging > end loop object_loop; $end raise; - - when others - then -$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then - dbug.on_error; -$end - md_close(l_handle); - if r_params.object_type = 'SCHEMA_EXPORT' - then - null; - else - raise; - end if; end; + end loop fetch_loop; - find_next_params; - end loop open_handle_loop; - - -- show 100% - longops_done(l_longops_open_rec); + -- overall longops_done(l_longops_rec); $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then chk; $end - cleanup; - $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then dbug.leave; $end - commit; -- see pragma - return; -- essential for a pipelined function exception when no_data_needed then - cleanup; $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then dbug.leave; $end when no_data_found then - cleanup; $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then dbug.leave_on_error; $end @@ -5933,7 +6144,6 @@ $end when others then - cleanup; $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then dbug.leave_on_error; $end @@ -6332,15 +6542,30 @@ $end then for i_idx in l_object_by_dep_tab.first .. l_object_by_dep_tab.last loop - l_schema_object := l_schema_object_lookup_tab(l_object_by_dep_tab(i_idx)); + /* GJP 2022-08-11 + When DDL is generated with the 'sort objects by dependencies' flag, an error is raised for unknown dependencies. + See also https://github.com/paulissoft/oracle-tools/issues/47 + */ + begin +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then + dbug.print(dbug."debug", 'l_object_by_dep_tab(%s): %s', i_idx, l_object_by_dep_tab(i_idx)); +$end + l_schema_object := l_schema_object_lookup_tab(l_object_by_dep_tab(i_idx)); $if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then - dbug.print(dbug."debug", 'l_schema_object.id: %s', l_schema_object.id); + dbug.print(dbug."debug", 'l_schema_object.id: %s', l_schema_object.id); $end - pipe row(l_schema_object); + pipe row(l_schema_object); - longops_show(l_longops_rec); + longops_show(l_longops_rec); + exception + when no_data_found + then +$if oracle_tools.cfg_pkg.c_debugging and oracle_tools.pkg_ddl_util.c_debugging >= 1 $then + dbug.on_error; +$end + end; end loop; end if; diff --git a/db/app/ddl/src/full/R__18.ORACLE_TOOLS.OBJECT_GRANT.V_MY_FETCH_DDL.sql b/db/app/ddl/src/full/R__18.ORACLE_TOOLS.OBJECT_GRANT.V_MY_FETCH_DDL.sql new file mode 100644 index 00000000..711fbdc8 --- /dev/null +++ b/db/app/ddl/src/full/R__18.ORACLE_TOOLS.OBJECT_GRANT.V_MY_FETCH_DDL.sql @@ -0,0 +1,4 @@ +call dbms_application_info.set_module('R__18.ORACLE_TOOLS.OBJECT_GRANT.V_MY_FETCH_DDL.sql', null); +call dbms_application_info.set_action('SQL statement 1'); +GRANT SELECT ON "ORACLE_TOOLS"."V_MY_FETCH_DDL" TO PUBLIC; + diff --git a/jenkins/libraries/maven/steps/process.groovy b/jenkins/libraries/maven/steps/process.groovy index 4cab5142..c672934f 100644 --- a/jenkins/libraries/maven/steps/process.groovy +++ b/jenkins/libraries/maven/steps/process.groovy @@ -36,14 +36,18 @@ void call(app_env){ assert env.DB_DIR != null env.DB_ACTIONS = app_env.db_actions assert env.DB_ACTIONS != null - env.DB_USERNAME_PROPERTY = ( app_env.db_username_property != null ? app_env.db_username_property : 'db.proxy.username' ) - + if ( app_env.db_username_property != null ) { + env.DB_USERNAME_PROPERTY = app_env.db_username_property + } else if ( pipelineConfig.db_username_property != null ) { + env.DB_USERNAME_PROPERTY = pipelineConfig.db_username_property + } else { + env.DB_USERNAME_PROPERTY = 'db.proxy.username' + } + assert env.DB_USERNAME_PROPERTY != null env.APEX_DIR = ( app_env.apex_dir != null ? app_env.apex_dir : pipelineConfig.apex_dir ) assert env.APEX_DIR != null env.APEX_ACTIONS = app_env.apex_actions assert env.APEX_ACTIONS != null - - env.LOG_DIR = ( app_env.log_dir != null ? app_env.log_dir : ( pipelineConfig.log_dir != null ? pipelineConfig.log_dir : '' ) ) } withCredentials([usernamePassword(credentialsId: env.DB_CREDENTIALS, passwordVariable: 'DB_PASSWORD', usernameVariable: 'DB_USERNAME')]) { diff --git a/jenkins/process.sh b/jenkins/process.sh index 43f6f381..4530707b 100644 --- a/jenkins/process.sh +++ b/jenkins/process.sh @@ -43,8 +43,19 @@ fi test -n "$DB_ACTIONS" || export DB_ACTIONS="" test -n "$APEX_ACTIONS" || export APEX_ACTIONS="" -# ensure that -l $LOG_DIR by default does not exist so Maven will log to stdout -test -n "$LOG_DIR" || export LOG_DIR=/directory-does-not-exist +# equivalent of Maven 4 MAVEN_ARGS +test -n "$MVN_ARGS" || export MVN_ARGS="" + +# ensure that -l $MVN_LOG_DIR by default does not exist so Maven will log to stdout +if [ -n "$MVN_LOG_DIR" -a -d "$MVN_LOG_DIR" ] +then + # let MVN_LOG_DIR point to an absolute file path + MVN_LOG_DIR=`cd ${MVN_LOG_DIR} && pwd` +else + # let MVN_LOG_DIR point to a non existing directory so mvn will not create the log file + MVN_LOG_DIR=/directory-does-not-exist +fi +export MVN_LOG_DIR set -xeu @@ -53,7 +64,7 @@ db_config_dir=`cd ${CONF_DIR} && pwd` # First DB run echo "processing DB actions ${DB_ACTIONS} in ${DB_DIR} with configuration directory $db_config_dir" set -- ${DB_ACTIONS} -for profile; do mvn -f ${DB_DIR} -Doracle-tools.dir=$oracle_tools_dir -Ddb.config.dir=$db_config_dir -Ddb=${DB} -D$DB_USERNAME_PROPERTY=$DB_USERNAME -Ddb.password=$DB_PASSWORD -P$profile -l $LOG_DIR/mvn-${profile}.log; done +for profile; do mvn -f ${DB_DIR} -Doracle-tools.dir=$oracle_tools_dir -Ddb.config.dir=$db_config_dir -Ddb=${DB} -D$DB_USERNAME_PROPERTY=$DB_USERNAME -Ddb.password=$DB_PASSWORD -P$profile -l $MVN_LOG_DIR/mvn-${profile}.log ${MVN_ARGS}; done process_git "Database changes" # Both db-install and db-generate-ddl-full part of DB_ACTIONS? @@ -64,14 +75,14 @@ then DB_ACTIONS="db-install db-generate-ddl-full" echo "checking that there are no changes after a second round of ${DB_ACTIONS} (standard output is suppressed)" set -- ${DB_ACTIONS} - for profile; do mvn -f ${DB_DIR} -Doracle-tools.dir=$oracle_tools_dir -Ddb.config.dir=$db_config_dir -Ddb=${DB} -D$DB_USERNAME_PROPERTY=$DB_USERNAME -Ddb.password=$DB_PASSWORD -P$profile -l mvn-${profile}.log; rm mvn-${profile}.log; done + for profile; do mvn -f ${DB_DIR} -Doracle-tools.dir=$oracle_tools_dir -Ddb.config.dir=$db_config_dir -Ddb=${DB} -D$DB_USERNAME_PROPERTY=$DB_USERNAME -Ddb.password=$DB_PASSWORD -P$profile -l mvn-${profile}.log ${MVN_ARGS}; rm mvn-${profile}.log; done echo "there should be no files to add for Git:" test -z "`git status --porcelain`" fi echo "processing APEX actions ${APEX_ACTIONS} in ${APEX_DIR} with configuration directory $db_config_dir" set -- ${APEX_ACTIONS} -for profile; do mvn -f ${APEX_DIR} -Doracle-tools.dir=$oracle_tools_dir -Ddb.config.dir=$db_config_dir -Ddb=${DB} -D$DB_USERNAME_PROPERTY=$DB_USERNAME -Ddb.password=$DB_PASSWORD -P$profile -l $LOG_DIR/mvn-${profile}.log; done +for profile; do mvn -f ${APEX_DIR} -Doracle-tools.dir=$oracle_tools_dir -Ddb.config.dir=$db_config_dir -Ddb=${DB} -D$DB_USERNAME_PROPERTY=$DB_USERNAME -Ddb.password=$DB_PASSWORD -P$profile -l $MVN_LOG_DIR/mvn-${profile}.log ${MVN_ARGS}; done # ${APEX_DIR}/src/export/application/create_application.sql changes its p_flow_version so use git diff --stat to verify it is just that file and that line # diff --git a/pom.xml b/pom.xml index cca8e83c..2c03c55b 100644 --- a/pom.xml +++ b/pom.xml @@ -47,7 +47,8 @@ - 7.4.0 + + 9.1.6 19.3.0.0 3.1.4 ${project.version}