Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Allowing Oracle Reverse engineering to handle individual object failures #229

Merged
merged 1 commit into from
Apr 4, 2019
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
10 changes: 10 additions & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
@@ -1,5 +1,15 @@
# Change Log

## 7.1.1

### Functionality Improvements

### Technical Improvements

### Bug Fixes
Oracle Reverse Engineering can still generate output even if a single object DDL cannot be generated.


## 7.1.0

### Functionality Improvements
Expand Down
2 changes: 1 addition & 1 deletion obevo-db-impls/obevo-db-oracle/pom.xml
Original file line number Diff line number Diff line change
Expand Up @@ -28,7 +28,7 @@
<name>${project.artifactId}</name>

<properties>
<jacoco.minCoverage>0.40</jacoco.minCoverage>
<jacoco.minCoverage>0.34</jacoco.minCoverage>
</properties>

<dependencies>
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -19,11 +19,14 @@ import com.gs.obevo.api.platform.ChangeType
import com.gs.obevo.db.apps.reveng.AbstractDdlReveng
import com.gs.obevo.db.apps.reveng.AquaRevengArgs
import com.gs.obevo.db.impl.core.jdbc.JdbcHelper
import com.gs.obevo.impl.changetypes.UnclassifiedChangeType
import com.gs.obevo.impl.util.MultiLineStringSplitter
import com.gs.obevo.util.inputreader.Credential
import org.apache.commons.io.IOUtils
import org.apache.commons.lang3.exception.ExceptionUtils
import org.eclipse.collections.api.block.function.Function
import org.eclipse.collections.api.list.ImmutableList
import org.eclipse.collections.api.list.MutableList
import org.eclipse.collections.impl.block.factory.StringPredicates
import org.eclipse.collections.impl.factory.Lists
import org.slf4j.LoggerFactory
Expand All @@ -33,6 +36,7 @@ import java.io.StringWriter
import java.nio.charset.Charset
import java.nio.file.Files
import java.sql.Clob
import java.sql.Connection
import java.util.regex.Pattern

internal class OracleReveng
Expand Down Expand Up @@ -73,63 +77,15 @@ internal class OracleReveng
jdbc.update(conn, "begin DBMS_METADATA.SET_TRANSFORM_PARAM(DBMS_METADATA.SESSION_TRANSFORM,'STORAGE',false); end;")
jdbc.update(conn, "begin DBMS_METADATA.SET_TRANSFORM_PARAM(DBMS_METADATA.SESSION_TRANSFORM,'SQLTERMINATOR',true); end;")

// we exclude:
// PACKAGE BODY as those are generated via package anyway
// DATABASE LINK as the get_ddl function doesn't work with it. We may support this later on
val sql = """
select CASE WHEN obj.OBJECT_TYPE = 'INDEX' THEN 2 ELSE 1 END SORT_ORDER1
, obj.OBJECT_NAME
, 1 AS SORT_ORDER2
, obj.OBJECT_TYPE
, dbms_metadata.get_ddl(REPLACE(obj.OBJECT_TYPE,' ','_'), obj.OBJECT_NAME, obj.owner) || ';' AS object_ddl
FROM DBA_OBJECTS obj
LEFT JOIN DBA_TABLES tab ON obj.OBJECT_TYPE = 'TABLE' AND obj.OWNER = tab.OWNER and obj.OBJECT_NAME = tab.TABLE_NAME
WHERE obj.OWNER = '${args.dbSchema}'
AND obj.OBJECT_TYPE NOT IN ('PACKAGE BODY', 'LOB', 'TABLE PARTITION', 'DATABASE LINK')
AND obj.OBJECT_NAME NOT LIKE 'MLOG${'$'}%' AND obj.OBJECT_NAME NOT LIKE 'RUPD${'$'}%' -- exclude the helper tables for materialized views
AND obj.OBJECT_NAME NOT LIKE 'SYS_%' -- exclude other system tables
AND (tab.NESTED is null OR tab.NESTED = 'NO')
"""

val commentSql = """
SELECT 1 SORT_ORDER1 -- group comment ordering with tables and other objects, and ahead of indices
, obj.OBJECT_NAME
, 2 AS SORT_ORDER2 -- sort comments last compared to other table changes
, 'COMMENT' as OBJECT_TYPE
, dbms_metadata.get_dependent_ddl('COMMENT', obj.OBJECT_NAME, obj.OWNER) || ';' AS object_ddl
FROM (
-- inner table is needed to extract all the object names that have comments (we cannot determine this solely from DBA_OBJECTS)
-- use DISTINCT as DBA_COL_COMMENTS may have multiple rows for a single table
SELECT DISTINCT obj.OWNER, obj.OBJECT_NAME, obj.OBJECT_TYPE
FROM DBA_OBJECTS obj
LEFT JOIN DBA_TAB_COMMENTS tabcom ON obj.OWNER = tabcom.OWNER and obj.OBJECT_NAME = tabcom.TABLE_NAME and tabcom.COMMENTS IS NOT NULL
LEFT JOIN DBA_COL_COMMENTS colcom ON obj.OWNER = colcom.OWNER and obj.OBJECT_NAME = colcom.TABLE_NAME and colcom.COMMENTS IS NOT NULL
WHERE obj.OWNER = '${args.dbSchema}'
and (tabcom.OWNER is not null OR colcom.OWNER is not null)
) obj
ORDER BY 1, 2
"""

// note - need comments grouped in order with tables, but indexes
/* keeping this for the future as we support more object types with comments
LEFT JOIN DBA_OPERATOR_COMMENTS opcom ON obj.OWNER = opcom.OWNER and obj.OBJECT_NAME = opcom.OPERATOR_NAME and opcom.COMMENTS IS NOT NULL
LEFT JOIN DBA_INDEXTYPE_COMMENTS indexcom ON obj.OWNER = indexcom.OWNER and obj.OBJECT_NAME = indexcom.INDEXTYPE_NAME and indexcom.COMMENTS IS NOT NULL
LEFT JOIN DBA_MVIEW_COMMENTS mviewcom ON obj.OWNER = mviewcom.OWNER and obj.OBJECT_NAME = mviewcom.MVIEW_NAME and mviewcom.COMMENTS IS NOT NULL
LEFT JOIN DBA_EDITION_COMMENTS edcom ON obj.OBJECT_NAME = edcom.EDITION_NAME and edcom.COMMENTS IS NOT NULL -- note - no OWNER supported here
*/


// Sorting algorithm:
// - We use SORT_ORDER1 to split between table and index changes, as we want index changes to come after tables,
// but the SQL query only gives the object name as the index name; hence, we can't group easily.
// - We use SORT_ORDER2 for having comments come after regular table changes.
val queryResults = listOf(sql, commentSql)
.flatMap { jdbc.queryForList(conn, it) }
val queryResults = queryObjects(jdbc, conn, args.dbSchema).plus(queryComments(jdbc, conn, args.dbSchema))
.sortedWith(compareBy({ it["SORT_ORDER1"] as Comparable<*> }, { it["OBJECT_NAME"] as String }, { it["SORT_ORDER2"] as Comparable<*> }))
queryResults.forEach { map ->
val objectType = map["OBJECT_TYPE"] as String
val clobObject = map["OBJECT_DDL"] as Clob
var clobAsString = clobToString(clobObject)
var clobAsString = clobToString(map["OBJECT_DDL"]!!)

// TODO all parsing like this should move into the core AbstractReveng logic so that we can do more unit-test logic around this parsing
clobAsString = clobAsString.trimEnd()
Expand Down Expand Up @@ -160,11 +116,107 @@ ORDER BY 1, 2
return true
}

private fun clobToString(clobObject: Clob): String {
clobObject.characterStream.use {
val w = StringWriter()
IOUtils.copy(it, w)
return w.toString()
private fun queryObjects(jdbc: JdbcHelper, conn: Connection, schema: String): List<Map<String, Any>> {
try {
return jdbc.queryForList(conn, getObjectQuery(schema, true, null))
} catch (_: Exception) {
// the bulk query may fail if one of the objects cannot be rendered. Hence, we fall back to individual queries
LOG.info("Failed executing bulk query for all objects; falling back to individual queries")

// First get the objects
val objects = jdbc.queryForList(conn, getObjectQuery(schema, false, null))

// Now query each individually
return objects.flatMap {
try {
jdbc.queryForList(conn, getObjectQuery(schema, true, it["OBJECT_NAME"] as String))
} catch (e2: Exception) {
// in case of failures, write the object out for the reverse-engineering to process
val exceptionText = """OBEVO EXCEPTION ${it["OBJECT_NAME"]!!} of type ${it["OBJECT_TYPE"]!!}
/*
Please report this as an Issue on the Obevo Github page so that we can improve the reverse-engineering logic.
For now, resolve this on your side.
${ExceptionUtils.getStackTrace(e2)}
*/
end
"""
listOf(mapOf(
"SORT_ORDER1" to it["SORT_ORDER1"]!!,
"OBJECT_NAME" to it["OBJECT_NAME"]!!,
"SORT_ORDER2" to it["SORT_ORDER2"]!!,
"OBJECT_TYPE" to it["OBJECT_TYPE"]!!,
"OBJECT_DDL" to exceptionText
))
}
}.toSet().toList()
}
}

private fun getObjectQuery(schema: String, retrieveDefinitions: Boolean, objectName: String?): String {
val objectDefSql = if (retrieveDefinitions) "dbms_metadata.get_ddl(REPLACE(obj.OBJECT_TYPE,' ','_'), obj.OBJECT_NAME, obj.owner) || ';'" else " 'blank'";
val objectClause = objectName?.let { " AND obj.OBJECT_NAME = '${it}'"} ?: ""

// we exclude:
// PACKAGE BODY as those are generated via package anyway
// DATABASE LINK as the get_ddl function doesn't work with it. We may support this later on
return """
select CASE WHEN obj.OBJECT_TYPE = 'INDEX' THEN 2 ELSE 1 END SORT_ORDER1
, obj.OBJECT_NAME
, 1 AS SORT_ORDER2
, obj.OBJECT_TYPE
, ${objectDefSql} AS OBJECT_DDL
FROM DBA_OBJECTS obj
LEFT JOIN DBA_TABLES tab ON obj.OBJECT_TYPE = 'TABLE' AND obj.OWNER = tab.OWNER and obj.OBJECT_NAME = tab.TABLE_NAME
WHERE obj.OWNER = '${schema}'
AND obj.OBJECT_TYPE NOT IN ('PACKAGE BODY', 'LOB', 'TABLE PARTITION', 'DATABASE LINK')
AND obj.OBJECT_NAME NOT LIKE 'MLOG${'$'}%' AND obj.OBJECT_NAME NOT LIKE 'RUPD${'$'}%' -- exclude the helper tables for materialized views
AND obj.OBJECT_NAME NOT LIKE 'SYS_%' -- exclude other system tables
AND (tab.NESTED is null OR tab.NESTED = 'NO')
${objectClause}
"""
}

private fun queryComments(jdbc: JdbcHelper, conn: Connection, schema: String): MutableList<MutableMap<String, Any>> {
val commentSql = """
SELECT 1 SORT_ORDER1 -- group comment ordering with tables and other objects, and ahead of indices
, obj.OBJECT_NAME
, 2 AS SORT_ORDER2 -- sort comments last compared to other table changes
, 'COMMENT' as OBJECT_TYPE
, dbms_metadata.get_dependent_ddl('COMMENT', obj.OBJECT_NAME, obj.OWNER) || ';' AS OBJECT_DDL
FROM (
-- inner table is needed to extract all the object names that have comments (we cannot determine this solely from DBA_OBJECTS)
-- use DISTINCT as DBA_COL_COMMENTS may have multiple rows for a single table
SELECT DISTINCT obj.OWNER, obj.OBJECT_NAME, obj.OBJECT_TYPE
FROM DBA_OBJECTS obj
LEFT JOIN DBA_TAB_COMMENTS tabcom ON obj.OWNER = tabcom.OWNER and obj.OBJECT_NAME = tabcom.TABLE_NAME and tabcom.COMMENTS IS NOT NULL
LEFT JOIN DBA_COL_COMMENTS colcom ON obj.OWNER = colcom.OWNER and obj.OBJECT_NAME = colcom.TABLE_NAME and colcom.COMMENTS IS NOT NULL
WHERE obj.OWNER = '${schema}'
and (tabcom.OWNER is not null OR colcom.OWNER is not null)
) obj
ORDER BY 1, 2
"""

// note - need comments grouped in order with tables, but indexes
/* keeping this for the future as we support more object types with comments
LEFT JOIN DBA_OPERATOR_COMMENTS opcom ON obj.OWNER = opcom.OWNER and obj.OBJECT_NAME = opcom.OPERATOR_NAME and opcom.COMMENTS IS NOT NULL
LEFT JOIN DBA_INDEXTYPE_COMMENTS indexcom ON obj.OWNER = indexcom.OWNER and obj.OBJECT_NAME = indexcom.INDEXTYPE_NAME and indexcom.COMMENTS IS NOT NULL
LEFT JOIN DBA_MVIEW_COMMENTS mviewcom ON obj.OWNER = mviewcom.OWNER and obj.OBJECT_NAME = mviewcom.MVIEW_NAME and mviewcom.COMMENTS IS NOT NULL
LEFT JOIN DBA_EDITION_COMMENTS edcom ON obj.OBJECT_NAME = edcom.EDITION_NAME and edcom.COMMENTS IS NOT NULL -- note - no OWNER supported here
*/
return jdbc.queryForList(conn, commentSql)
}

private fun clobToString(clobObject: Any): String {
if (clobObject is String) {
return clobObject
} else if (clobObject is Clob) {
clobObject.characterStream.use {
val w = StringWriter()
IOUtils.copy(it, w)
return w.toString()
}
} else {
throw RuntimeException("Unexpected type " + clobObject.javaClass + "; expecting String or Clob")
}
}

Expand All @@ -191,6 +243,7 @@ ORDER BY 1, 2
}
}
return Lists.immutable.with(
AbstractDdlReveng.RevengPattern(UnclassifiedChangeType.INSTANCE.name, namePatternType, "(?i)obevo\\s+exception\\s+$schemaNameSubPattern"),
AbstractDdlReveng.RevengPattern(ChangeType.SEQUENCE_STR, namePatternType, "(?i)create\\s+(?:or\\s+replace\\s+)?sequence\\s+$schemaNameSubPattern").withPostProcessSql(AbstractDdlReveng.REPLACE_TABLESPACE).withPostProcessSql(AbstractDdlReveng.REMOVE_QUOTES),
AbstractDdlReveng.RevengPattern(ChangeType.TABLE_STR, namePatternType, "(?i)create\\s+table\\s+$schemaNameSubPattern").withPostProcessSql(AbstractDdlReveng.REPLACE_TABLESPACE).withPostProcessSql(AbstractDdlReveng.REMOVE_QUOTES),
AbstractDdlReveng.RevengPattern(ChangeType.TABLE_STR, namePatternType, "(?i)alter\\s+table\\s+$schemaNameSubPattern").withPostProcessSql(AbstractDdlReveng.REMOVE_QUOTES),
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -15,7 +15,8 @@
--

CREATE OR REPLACE VIEW COMMENT_VIEW AS SELECT A_ID, STRING_FIELD FROM TABLE_A WHERE A_ID = 3
;
GO
COMMENT ON COLUMN COMMENT_VIEW.A_ID
IS 'comment VIEW COL A_ID'
;
IS 'comment VIEW COL A_ID 2'
GO

Loading