diff --git a/src/main/java/com/microsoft/sqlserver/jdbc/SQLServerDatabaseMetaData.java b/src/main/java/com/microsoft/sqlserver/jdbc/SQLServerDatabaseMetaData.java index 06fbab527..516a4d590 100644 --- a/src/main/java/com/microsoft/sqlserver/jdbc/SQLServerDatabaseMetaData.java +++ b/src/main/java/com/microsoft/sqlserver/jdbc/SQLServerDatabaseMetaData.java @@ -8,6 +8,7 @@ package com.microsoft.sqlserver.jdbc; +import java.sql.BatchUpdateException; import java.sql.CallableStatement; import java.sql.Connection; import java.sql.DriverPropertyInfo; @@ -17,6 +18,7 @@ import java.text.MessageFormat; import java.util.EnumMap; import java.util.Properties; +import java.util.UUID; import java.util.concurrent.atomic.AtomicInteger; import java.util.logging.Level; @@ -743,6 +745,7 @@ public java.sql.ResultSet getClientInfoProperties() throws SQLException { loggerExternal.finer(toString() + " ActivityId: " + ActivityCorrelator.getNext().toString()); } checkClosed(); + /* * sp_fkeys [ @pktable_name = ] 'pktable_name' [ , [ @pktable_owner = ] 'pktable_owner' ] [ , [ @pktable_qualifier = ] 'pktable_qualifier' ] { * , [ @fktable_name = ] 'fktable_name' } [ , [ @fktable_owner = ] 'fktable_owner' ] [ , [ @fktable_qualifier = ] 'fktable_qualifier' ] @@ -755,7 +758,9 @@ public java.sql.ResultSet getClientInfoProperties() throws SQLException { arguments[4] = schem2; arguments[5] = cat2; - return getResultSetWithProvidedColumnNames(null, CallableHandles.SP_FKEYS, arguments, pkfkColumnNames); + SQLServerResultSet fkeysRS = getResultSetWithProvidedColumnNames(null, CallableHandles.SP_FKEYS, arguments, pkfkColumnNames); + + return getResultSetForForeignKeyInformation(fkeysRS, null); } /* L0 */ public String getDatabaseProductName() throws SQLServerException { @@ -806,6 +811,7 @@ public java.sql.ResultSet getClientInfoProperties() throws SQLException { loggerExternal.finer(toString() + " ActivityId: " + ActivityCorrelator.getNext().toString()); } checkClosed(); + /* * sp_fkeys [ @pktable_name = ] 'pktable_name' [ , [ @pktable_owner = ] 'pktable_owner' ] [ , [ @pktable_qualifier = ] 'pktable_qualifier' ] { * , [ @fktable_name = ] 'fktable_name' } [ , [ @fktable_owner = ] 'fktable_owner' ] [ , [ @fktable_qualifier = ] 'fktable_qualifier' ] @@ -817,7 +823,10 @@ public java.sql.ResultSet getClientInfoProperties() throws SQLException { arguments[3] = null; // fktable_name arguments[4] = null; arguments[5] = null; - return getResultSetWithProvidedColumnNames(cat, CallableHandles.SP_FKEYS, arguments, pkfkColumnNames); + + SQLServerResultSet fkeysRS = getResultSetWithProvidedColumnNames(cat, CallableHandles.SP_FKEYS, arguments, pkfkColumnNames); + + return getResultSetForForeignKeyInformation(fkeysRS, cat); } /* L0 */ public String getExtraNameCharacters() throws SQLServerException { @@ -837,6 +846,7 @@ public java.sql.ResultSet getClientInfoProperties() throws SQLException { loggerExternal.finer(toString() + " ActivityId: " + ActivityCorrelator.getNext().toString()); } checkClosed(); + /* * sp_fkeys [ @pktable_name = ] 'pktable_name' [ , [ @pktable_owner = ] 'pktable_owner' ] [ , [ @pktable_qualifier = ] 'pktable_qualifier' ] { * , [ @fktable_name = ] 'fktable_name' } [ , [ @fktable_owner = ] 'fktable_owner' ] [ , [ @fktable_qualifier = ] 'fktable_qualifier' ] @@ -848,7 +858,147 @@ public java.sql.ResultSet getClientInfoProperties() throws SQLException { arguments[3] = table; // fktable_name arguments[4] = schema; arguments[5] = cat; - return getResultSetWithProvidedColumnNames(cat, CallableHandles.SP_FKEYS, arguments, pkfkColumnNames); + + SQLServerResultSet fkeysRS = getResultSetWithProvidedColumnNames(cat, CallableHandles.SP_FKEYS, arguments, pkfkColumnNames); + + return getResultSetForForeignKeyInformation(fkeysRS, cat); + } + + /** + * The original sp_fkeys stored procedure does not give the required values from JDBC specification. This method creates 2 temporary tables and + * uses join and other operations on them to give the correct values. + * + * @param sp_fkeys_Query + * @return + * @throws SQLServerException + */ + private ResultSet getResultSetForForeignKeyInformation(SQLServerResultSet fkeysRS, String cat) throws SQLServerException { + UUID uuid = UUID.randomUUID(); + String fkeys_results_tableName = "[#fkeys_results" + uuid + "]"; + String foreign_keys_combined_tableName = "[#foreign_keys_combined_results" + uuid + "]"; + String sys_foreign_keys = "sys.foreign_keys"; + + String fkeys_results_column_definition = "PKTABLE_QUALIFIER sysname, PKTABLE_OWNER sysname, PKTABLE_NAME sysname, PKCOLUMN_NAME sysname, FKTABLE_QUALIFIER sysname, FKTABLE_OWNER sysname, FKTABLE_NAME sysname, FKCOLUMN_NAME sysname, KEY_SEQ smallint, UPDATE_RULE smallint, DELETE_RULE smallint, FK_NAME sysname, PK_NAME sysname, DEFERRABILITY smallint"; + String foreign_keys_combined_column_definition = "name sysname, delete_referential_action_desc nvarchar(60), update_referential_action_desc nvarchar(60)," + + fkeys_results_column_definition; + + // cannot close this statement, otherwise the returned resultset would be closed too. + SQLServerStatement stmt = (SQLServerStatement) connection.createStatement(); + + /** + * create a temp table that has the same definition as the result of sp_fkeys: + * + * create table #fkeys_results ( + * PKTABLE_QUALIFIER sysname, + * PKTABLE_OWNER sysname, + * PKTABLE_NAME sysname, + * PKCOLUMN_NAME sysname, + * FKTABLE_QUALIFIER sysname, + * FKTABLE_OWNER sysname, + * FKTABLE_NAME sysname, + * FKCOLUMN_NAME sysname, + * KEY_SEQ smallint, + * UPDATE_RULE smallint, + * DELETE_RULE smallint, + * FK_NAME sysname, + * PK_NAME sysname, + * DEFERRABILITY smallint + * ); + * + */ + stmt.execute("create table " + fkeys_results_tableName + " (" + fkeys_results_column_definition + ")"); + + /** + * insert the results of sp_fkeys to the temp table #fkeys_results + */ + SQLServerPreparedStatement ps = (SQLServerPreparedStatement) connection + .prepareCall("insert into " + fkeys_results_tableName + "values(?,?,?,?,?,?,?,?,?,?,?,?,?,?)"); + try { + while (fkeysRS.next()) { + ps.setString(1, fkeysRS.getString(1)); + ps.setString(2, fkeysRS.getString(2)); + ps.setString(3, fkeysRS.getString(3)); + ps.setString(4, fkeysRS.getString(4)); + ps.setString(5, fkeysRS.getString(5)); + ps.setString(6, fkeysRS.getString(6)); + ps.setString(7, fkeysRS.getString(7)); + ps.setString(8, fkeysRS.getString(8)); + ps.setInt(9, fkeysRS.getInt(9)); + ps.setInt(10, fkeysRS.getInt(10)); + ps.setInt(11, fkeysRS.getInt(11)); + ps.setString(12, fkeysRS.getString(12)); + ps.setString(13, fkeysRS.getString(13)); + ps.setInt(14, fkeysRS.getInt(14)); + ps.execute(); + } + } + finally { + if (null != ps) { + ps.close(); + } + if (null != fkeysRS) { + fkeysRS.close(); + } + } + + /** + * create another temp table that has 3 columns from sys.foreign_keys and the rest of columns are the same as #fkeys_results: + * + * create table #foreign_keys_combined_results ( + * name sysname, + * delete_referential_action_desc nvarchar(60), + * update_referential_action_desc nvarchar(60), + * ...... + * ...... + * ...... + * ); + * + */ + stmt.addBatch("create table " + foreign_keys_combined_tableName + " (" + foreign_keys_combined_column_definition + ")"); + + /** + * right join the content of sys.foreign_keys and the content of #fkeys_results base on foreign key name and save the result to the new temp + * table #foreign_keys_combined_results + */ + stmt.addBatch("insert into " + foreign_keys_combined_tableName + + " select " + sys_foreign_keys + ".name, " + sys_foreign_keys + ".delete_referential_action_desc, " + sys_foreign_keys + ".update_referential_action_desc," + + fkeys_results_tableName + ".PKTABLE_QUALIFIER," + fkeys_results_tableName + ".PKTABLE_OWNER," + fkeys_results_tableName + ".PKTABLE_NAME," + fkeys_results_tableName + ".PKCOLUMN_NAME," + + fkeys_results_tableName + ".FKTABLE_QUALIFIER," + fkeys_results_tableName + ".FKTABLE_OWNER," + fkeys_results_tableName + ".FKTABLE_NAME," + fkeys_results_tableName + ".FKCOLUMN_NAME," + + fkeys_results_tableName + ".KEY_SEQ," + fkeys_results_tableName + ".UPDATE_RULE," + fkeys_results_tableName + ".DELETE_RULE," + fkeys_results_tableName + ".FK_NAME," + fkeys_results_tableName + ".PK_NAME," + + fkeys_results_tableName + ".DEFERRABILITY from " + sys_foreign_keys + + " right join " + fkeys_results_tableName + " on " + sys_foreign_keys + ".name=" + fkeys_results_tableName + ".FK_NAME"); + + /** + * the DELETE_RULE value and UPDATE_RULE value returned from sp_fkeys are not the same as required by JDBC spec. therefore, we need to update + * those values to JDBC required values base on delete_referential_action_desc and update_referential_action_desc returned from sys.foreign_keys + * No Action: 3 + * Cascade: 0 + * Set Null: 2 + * Set Default: 4 + */ + stmt.addBatch("update " + foreign_keys_combined_tableName + " set DELETE_RULE=3 where delete_referential_action_desc='NO_ACTION';" + + "update " + foreign_keys_combined_tableName + " set DELETE_RULE=0 where delete_referential_action_desc='Cascade';" + + "update " + foreign_keys_combined_tableName + " set DELETE_RULE=2 where delete_referential_action_desc='SET_NULL';" + + "update " + foreign_keys_combined_tableName + " set DELETE_RULE=4 where delete_referential_action_desc='SET_DEFAULT';" + + "update " + foreign_keys_combined_tableName + " set UPDATE_RULE=3 where update_referential_action_desc='NO_ACTION';" + + "update " + foreign_keys_combined_tableName + " set UPDATE_RULE=0 where update_referential_action_desc='Cascade';" + + "update " + foreign_keys_combined_tableName + " set UPDATE_RULE=2 where update_referential_action_desc='SET_NULL';" + + "update " + foreign_keys_combined_tableName + " set UPDATE_RULE=4 where update_referential_action_desc='SET_DEFAULT';"); + + try { + stmt.executeBatch(); + } + catch (BatchUpdateException e) { + throw new SQLServerException(e.getMessage(), e.getSQLState(), e.getErrorCode(), null); + } + + /** + * now, the #foreign_keys_combined_results table has the correct values for DELETE_RULE and UPDATE_RULE. Then we can return the result of + * the table with the same definition of the resultset return by sp_fkeys (same column definition and same order). + */ + return stmt.executeQuery( + "select PKTABLE_QUALIFIER as 'PKTABLE_CAT',PKTABLE_OWNER as 'PKTABLE_SCHEM',PKTABLE_NAME,PKCOLUMN_NAME,FKTABLE_QUALIFIER as 'FKTABLE_CAT',FKTABLE_OWNER as 'FKTABLE_SCHEM',FKTABLE_NAME,FKCOLUMN_NAME,KEY_SEQ,UPDATE_RULE,DELETE_RULE,FK_NAME,PK_NAME,DEFERRABILITY from " + + foreign_keys_combined_tableName + " order by FKTABLE_QUALIFIER, FKTABLE_OWNER, FKTABLE_NAME, KEY_SEQ"); } private final static String[] getIndexInfoColumnNames = {/* 1 */ TABLE_CAT, /* 2 */ TABLE_SCHEM, /* 3 */ TABLE_NAME, /* 4 */ NON_UNIQUE, diff --git a/src/test/java/com/microsoft/sqlserver/jdbc/databasemetadata/DatabaseMetaDataForeignKeyTest.java b/src/test/java/com/microsoft/sqlserver/jdbc/databasemetadata/DatabaseMetaDataForeignKeyTest.java new file mode 100644 index 000000000..b498a6afb --- /dev/null +++ b/src/test/java/com/microsoft/sqlserver/jdbc/databasemetadata/DatabaseMetaDataForeignKeyTest.java @@ -0,0 +1,241 @@ +/* + * Microsoft JDBC Driver for SQL Server + * + * Copyright(c) Microsoft Corporation All rights reserved. + * + * This program is made available under the terms of the MIT License. See the LICENSE file in the project root for more information. + */ +package com.microsoft.sqlserver.jdbc.databasemetadata; + +import static org.junit.jupiter.api.Assertions.assertEquals; +import static org.junit.jupiter.api.Assertions.assertTrue; +import static org.junit.jupiter.api.Assertions.fail; + +import java.sql.DriverManager; +import java.sql.SQLException; + +import org.junit.jupiter.api.AfterAll; +import org.junit.jupiter.api.BeforeAll; +import org.junit.jupiter.api.Test; +import org.junit.platform.runner.JUnitPlatform; +import org.junit.runner.RunWith; + +import com.microsoft.sqlserver.jdbc.SQLServerConnection; +import com.microsoft.sqlserver.jdbc.SQLServerDatabaseMetaData; +import com.microsoft.sqlserver.jdbc.SQLServerException; +import com.microsoft.sqlserver.jdbc.SQLServerResultSet; +import com.microsoft.sqlserver.jdbc.SQLServerStatement; +import com.microsoft.sqlserver.testframework.AbstractTest; +import com.microsoft.sqlserver.testframework.Utils; + +/** + * Test class for testing DatabaseMetaData with foreign keys. + */ +@RunWith(JUnitPlatform.class) +public class DatabaseMetaDataForeignKeyTest extends AbstractTest { + private static SQLServerConnection conn = null; + private static SQLServerStatement stmt = null; + + private static String table1 = "DatabaseMetaDataForeignKeyTest_table_1"; + private static String table2 = "DatabaseMetaDataForeignKeyTest_table_2"; + private static String table3 = "DatabaseMetaDataForeignKeyTest_table_3"; + private static String table4 = "DatabaseMetaDataForeignKeyTest_table_4"; + private static String table5 = "DatabaseMetaDataForeignKeyTest_table_5"; + + private static String schema = null; + private static String catalog = null; + + private static final String EXPECTED_ERROR_MESSAGE = "An object or column name is missing or empty."; + private static final String EXPECTED_ERROR_MESSAGE2 = "The database name component of the object qualifier must be the name of the current database."; + + + @BeforeAll + private static void setupVariation() throws SQLException { + conn = (SQLServerConnection) DriverManager.getConnection(connectionString); + SQLServerStatement stmt = (SQLServerStatement) conn.createStatement(); + + catalog = conn.getCatalog(); + schema = conn.getSchema(); + + connection.createStatement().executeUpdate("if object_id('" + table1 + "','U') is not null drop table " + table1); + + connection.createStatement().executeUpdate("if object_id('" + table2 + "','U') is not null drop table " + table2); + stmt.execute("Create table " + table2 + " (c21 int NOT NULL PRIMARY KEY)"); + + connection.createStatement().executeUpdate("if object_id('" + table3 + "','U') is not null drop table " + table3); + stmt.execute("Create table " + table3 + " (c31 int NOT NULL PRIMARY KEY)"); + + connection.createStatement().executeUpdate("if object_id('" + table4 + "','U') is not null drop table " + table4); + stmt.execute("Create table " + table4 + " (c41 int NOT NULL PRIMARY KEY)"); + + connection.createStatement().executeUpdate("if object_id('" + table5 + "','U') is not null drop table " + table5); + stmt.execute("Create table " + table5 + " (c51 int NOT NULL PRIMARY KEY)"); + + connection.createStatement().executeUpdate("if object_id('" + table1 + "','U') is not null drop table " + table1); + stmt.execute("Create table " + table1 + " (c11 int primary key," + + " c12 int FOREIGN KEY REFERENCES " + table2 + "(c21) ON DELETE no action ON UPDATE set default," + + " c13 int FOREIGN KEY REFERENCES " + table3 + "(c31) ON DELETE cascade ON UPDATE set null," + + " c14 int FOREIGN KEY REFERENCES " + table4 + "(c41) ON DELETE set null ON UPDATE cascade," + + " c15 int FOREIGN KEY REFERENCES " + table5 + "(c51) ON DELETE set default ON UPDATE no action," + + ")"); + } + + @AfterAll + private static void terminateVariation() throws SQLException { + conn = (SQLServerConnection) DriverManager.getConnection(connectionString); + stmt = (SQLServerStatement) conn.createStatement(); + + Utils.dropTableIfExists(table1, stmt); + Utils.dropTableIfExists(table2, stmt); + Utils.dropTableIfExists(table3, stmt); + Utils.dropTableIfExists(table4, stmt); + Utils.dropTableIfExists(table5, stmt); + } + + /** + * test getImportedKeys() methods + * + * @throws SQLServerException + */ + @Test + public void testGetImportedKeys() throws SQLServerException { + SQLServerDatabaseMetaData dmd = (SQLServerDatabaseMetaData) connection.getMetaData(); + + SQLServerResultSet rs1 = (SQLServerResultSet) dmd.getImportedKeys(null, null, table1); + validateGetImportedKeysResults(rs1); + + SQLServerResultSet rs2 = (SQLServerResultSet) dmd.getImportedKeys(catalog, schema, table1); + validateGetImportedKeysResults(rs2); + + SQLServerResultSet rs3 = (SQLServerResultSet) dmd.getImportedKeys(catalog, "", table1); + validateGetImportedKeysResults(rs3); + + try { + dmd.getImportedKeys("", schema, table1); + fail("Exception is not thrown."); + } + catch (SQLServerException e) { + assertTrue(e.getMessage().startsWith(EXPECTED_ERROR_MESSAGE)); + } + } + + private void validateGetImportedKeysResults(SQLServerResultSet rs) throws SQLServerException { + int expectedRowCount = 4; + int rowCount = 0; + + rs.next(); + assertEquals(4, rs.getInt("UPDATE_RULE")); + assertEquals(3, rs.getInt("DELETE_RULE")); + rowCount++; + + rs.next(); + assertEquals(2, rs.getInt("UPDATE_RULE")); + assertEquals(0, rs.getInt("DELETE_RULE")); + rowCount++; + + rs.next(); + assertEquals(0, rs.getInt("UPDATE_RULE")); + assertEquals(2, rs.getInt("DELETE_RULE")); + rowCount++; + + rs.next(); + assertEquals(3, rs.getInt("UPDATE_RULE")); + assertEquals(4, rs.getInt("DELETE_RULE")); + rowCount++; + + if(expectedRowCount != rowCount) { + assertEquals(expectedRowCount, rowCount, "number of foreign key entries is incorrect."); + } + } + + /** + * test getExportedKeys() methods + * + * @throws SQLServerException + */ + @Test + public void testGetExportedKeys() throws SQLServerException { + String[] tableNames = {table2, table3, table4, table5}; + int[][] values = { + // expected UPDATE_RULE, expected DELETE_RULE + {4, 3}, + {2, 0}, + {0, 2}, + {3, 4} + }; + + SQLServerDatabaseMetaData dmd = (SQLServerDatabaseMetaData) connection.getMetaData(); + + for (int i = 0; i < tableNames.length; i++) { + String pkTable = tableNames[i]; + SQLServerResultSet rs1 = (SQLServerResultSet) dmd.getExportedKeys(null, null, pkTable); + rs1.next(); + assertEquals(values[i][0], rs1.getInt("UPDATE_RULE")); + assertEquals(values[i][1], rs1.getInt("DELETE_RULE")); + + SQLServerResultSet rs2 = (SQLServerResultSet) dmd.getExportedKeys(catalog, schema, pkTable); + rs2.next(); + assertEquals(values[i][0], rs2.getInt("UPDATE_RULE")); + assertEquals(values[i][1], rs2.getInt("DELETE_RULE")); + + SQLServerResultSet rs3 = (SQLServerResultSet) dmd.getExportedKeys(catalog, "", pkTable); + rs3.next(); + assertEquals(values[i][0], rs3.getInt("UPDATE_RULE")); + assertEquals(values[i][1], rs3.getInt("DELETE_RULE")); + + try { + dmd.getExportedKeys("", schema, pkTable); + fail("Exception is not thrown."); + } + catch (SQLServerException e) { + assertTrue(e.getMessage().startsWith(EXPECTED_ERROR_MESSAGE)); + } + } + } + + /** + * test getCrossReference() methods + * + * @throws SQLServerException + */ + @Test + public void testGetCrossReference() throws SQLServerException { + String fkTable = table1; + String[] tableNames = {table2, table3, table4, table5}; + int[][] values = { + // expected UPDATE_RULE, expected DELETE_RULE + {4, 3}, + {2, 0}, + {0, 2}, + {3, 4} + }; + + SQLServerDatabaseMetaData dmd = (SQLServerDatabaseMetaData) connection.getMetaData(); + + for (int i = 0; i < tableNames.length; i++) { + String pkTable = tableNames[i]; + SQLServerResultSet rs1 = (SQLServerResultSet) dmd.getCrossReference(null, null, pkTable, null, null, fkTable); + rs1.next(); + assertEquals(values[i][0], rs1.getInt("UPDATE_RULE")); + assertEquals(values[i][1], rs1.getInt("DELETE_RULE")); + + SQLServerResultSet rs2 = (SQLServerResultSet) dmd.getCrossReference(catalog, schema, pkTable, catalog, schema, fkTable); + rs2.next(); + assertEquals(values[i][0], rs2.getInt("UPDATE_RULE")); + assertEquals(values[i][1], rs2.getInt("DELETE_RULE")); + + SQLServerResultSet rs3 = (SQLServerResultSet) dmd.getCrossReference(catalog, "", pkTable, catalog, "", fkTable); + rs3.next(); + assertEquals(values[i][0], rs3.getInt("UPDATE_RULE")); + assertEquals(values[i][1], rs3.getInt("DELETE_RULE")); + + try { + dmd.getCrossReference("", schema, pkTable, "", schema, fkTable); + fail("Exception is not thrown."); + } + catch (SQLServerException e) { + assertEquals(EXPECTED_ERROR_MESSAGE2, e.getMessage()); + } + } + } +}