Skip to content

Commit 531bbd2

Browse files
authored
Fix DatabaseMetaData.getIndexInfo() CachedRowSet invalid cursor position exception (#2763) (#2780)
* Fix DatabaseMetaData.getIndexInfo() CachedRowSet invalid cursor position exception * removed unused imports * Fix ADO getIndexInfo test failures * Reverted INDEX_QUALIFIER to return table name instead of database name as per sp_statistics official documentation * Fix catalog switching in getIndexInfo to handle cross-database queries and fix ADO regression test failure * Fix Azure DW getIndexInfo to include columnstore indexes via UNION ALL * Fix getIndexInfo ORDER BY clause to match sp_statistics server implementation
1 parent 35e0958 commit 531bbd2

File tree

2 files changed

+201
-72
lines changed

2 files changed

+201
-72
lines changed

src/main/java/com/microsoft/sqlserver/jdbc/SQLServerDatabaseMetaData.java

Lines changed: 168 additions & 72 deletions
Original file line numberDiff line numberDiff line change
@@ -26,9 +26,6 @@
2626
import java.util.concurrent.locks.ReentrantLock;
2727
import java.util.logging.Level;
2828

29-
import javax.sql.rowset.CachedRowSet;
30-
import javax.sql.rowset.RowSetProvider;
31-
3229

3330
/**
3431
* Provides the JDBC database meta data.
@@ -268,15 +265,24 @@ private void checkClosed() throws SQLServerException {
268265

269266
private static final String SQL_KEYWORDS = createSqlKeyWords();
270267

271-
private static final String INDEX_INFO_QUERY = "SELECT db_name() AS TABLE_CAT, " +
272-
"sch.name AS TABLE_SCHEM, " +
273-
"t.name AS TABLE_NAME, " +
274-
"CASE WHEN i.is_unique = 1 THEN 0 ELSE 1 END AS NON_UNIQUE, " +
275-
"t.name AS INDEX_QUALIFIER, " +
276-
"i.name AS INDEX_NAME, " +
277-
"i.type AS TYPE, " +
278-
"ic.key_ordinal AS ORDINAL_POSITION, " +
279-
"c.name AS COLUMN_NAME, " +
268+
// Combined query using UNION ALL to merge sp_statistics and columnstore index results
269+
private static final String INDEX_INFO_COMBINED_QUERY =
270+
"DECLARE @temp_sp_statistics TABLE(" +
271+
"TABLE_QUALIFIER sysname NULL, TABLE_OWNER sysname NULL, TABLE_NAME sysname NULL, " +
272+
"NON_UNIQUE smallint NULL, INDEX_QUALIFIER sysname NULL, INDEX_NAME sysname NULL, " +
273+
"TYPE smallint NULL, ORDINAL_POSITION smallint NULL, COLUMN_NAME sysname NULL, " +
274+
"ASC_OR_DESC varchar(1) NULL, CARDINALITY int NULL, PAGES int NULL, FILTER_CONDITION varchar(128) NULL" +
275+
"); " +
276+
"INSERT INTO @temp_sp_statistics " +
277+
"EXEC sp_statistics ?, ?, ?, ?, ?, ?; " +
278+
"SELECT TABLE_QUALIFIER AS TABLE_CAT, TABLE_OWNER AS TABLE_SCHEM, " +
279+
"TABLE_NAME, NON_UNIQUE, INDEX_QUALIFIER, INDEX_NAME, TYPE, " +
280+
"ORDINAL_POSITION, COLUMN_NAME, ASC_OR_DESC, CARDINALITY, PAGES, FILTER_CONDITION " +
281+
"FROM @temp_sp_statistics " +
282+
"UNION ALL " +
283+
"SELECT db_name() AS TABLE_CAT, sch.name AS TABLE_SCHEM, t.name AS TABLE_NAME, " +
284+
"CASE WHEN i.is_unique = 1 THEN 0 ELSE 1 END AS NON_UNIQUE, t.name AS INDEX_QUALIFIER, i.name AS INDEX_NAME, " +
285+
"i.type AS TYPE, ic.key_ordinal AS ORDINAL_POSITION, c.name AS COLUMN_NAME, " +
280286
"CASE WHEN ic.is_descending_key = 1 THEN 'D' ELSE 'A' END AS ASC_OR_DESC, " +
281287
"CASE WHEN i.index_id <= 1 THEN ps.row_count ELSE NULL END AS CARDINALITY, " +
282288
"CASE WHEN i.index_id <= 1 THEN ps.used_page_count ELSE NULL END AS PAGES, " +
@@ -287,33 +293,9 @@ private void checkClosed() throws SQLServerException {
287293
"INNER JOIN sys.tables t ON i.object_id = t.object_id " +
288294
"INNER JOIN sys.schemas sch ON t.schema_id = sch.schema_id " +
289295
"LEFT JOIN sys.dm_db_partition_stats ps ON ps.object_id = i.object_id AND ps.index_id = i.index_id AND ps.index_id IN (0,1) " +
290-
"WHERE t.name = ? " +
291-
"AND sch.name = ? " +
292-
"AND ic.key_ordinal = 0 " +
293-
"ORDER BY t.name, i.name, ic.key_ordinal";
294-
295-
private static final String INDEX_INFO_QUERY_DW = "SELECT db_name() AS TABLE_CAT, " +
296-
"sch.name AS TABLE_SCHEM, " +
297-
"t.name AS TABLE_NAME, " +
298-
"CASE WHEN i.is_unique = 1 THEN 0 ELSE 1 END AS NON_UNIQUE, " +
299-
"t.name AS INDEX_QUALIFIER, " +
300-
"i.name AS INDEX_NAME, " +
301-
"i.type AS TYPE, " +
302-
"ic.key_ordinal AS ORDINAL_POSITION, " +
303-
"c.name AS COLUMN_NAME, " +
304-
"CASE WHEN ic.is_descending_key = 1 THEN 'D' ELSE 'A' END AS ASC_OR_DESC, " +
305-
"NULL AS CARDINALITY, " +
306-
"NULL AS PAGES, " +
307-
"NULL AS FILTER_CONDITION " +
308-
"FROM sys.indexes i " +
309-
"INNER JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id " +
310-
"INNER JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id " +
311-
"INNER JOIN sys.tables t ON i.object_id = t.object_id " +
312-
"INNER JOIN sys.schemas sch ON t.schema_id = sch.schema_id " +
313-
"WHERE t.name = ? " +
314-
"AND sch.name = ? " +
315-
"AND ic.key_ordinal = 0 " +
316-
"ORDER BY t.name, i.name, ic.key_ordinal";
296+
"WHERE t.name = ? AND sch.name = ? AND ic.key_ordinal = 0 " +
297+
"ORDER BY NON_UNIQUE, TYPE, INDEX_NAME, ORDINAL_POSITION";
298+
317299

318300
// Use LinkedHashMap to force retrieve elements in order they were inserted
319301
/** getColumns columns */
@@ -1278,44 +1260,158 @@ public java.sql.ResultSet getIndexInfo(String cat, String schema, String table,
12781260
arguments[5] = "Q";
12791261
else
12801262
arguments[5] = "E";
1281-
ResultSet spStatsResultSet = getResultSetWithProvidedColumnNames(cat, CallableHandles.SP_STATISTICS, arguments,
1282-
getIndexInfoColumnNames);
1283-
12841263
/*
1285-
* This change was made to address the issue of missing Columnstore indexes in the
1286-
* sp_statistics result set. The original implementation relied on the sp_statistics
1287-
* stored procedure to retrieve index information, which did not include Columnstore
1288-
* indexes. As a result, the query was limited to only Clustered and NonClustered indexes.
1289-
*
1290-
* GitHub Issue: #2546 - Columnstore indexes were missing from sp_statistics results.
1291-
*/
1292-
String columnstoreIndexQuery = this.connection.isAzureDW() ? INDEX_INFO_QUERY_DW : INDEX_INFO_QUERY;
1293-
PreparedStatement pstmt = (SQLServerPreparedStatement) this.connection.prepareStatement(columnstoreIndexQuery);
1294-
pstmt.setString(1, table);
1295-
pstmt.setString(2, schema);
1296-
ResultSet customResultSet = pstmt.executeQuery();
1297-
1298-
/*
1299-
* Create a CachedRowSet to hold the results of the sp_statistics query and
1300-
* the custom query. The CachedRowSet allows us to combine the results from both
1301-
* queries into a single result set.
1264+
* Fix for GitHub Issue #2546: Missing Columnstore indexes in sp_statistics results.
1265+
*
1266+
* Problem: The sp_statistics stored procedure does not return Columnstore indexes,
1267+
* limiting results to only Clustered and Nonclustered B-tree indexes.
1268+
*
1269+
* Solution:
1270+
* - Azure DW: Execute sp_statistics separately and build dynamic result set with UNION ALL
1271+
* - Regular SQL Server: Use INDEX_INFO_COMBINED_QUERY with UNION ALL to merge sp_statistics
1272+
* results with sys.indexes data, ensuring comprehensive index coverage including Columnstore
13021273
*/
1303-
CachedRowSet rowSet = RowSetProvider.newFactory().createCachedRowSet();
1304-
// Populate with first result set
1305-
rowSet.populate(spStatsResultSet);
1306-
1307-
while (customResultSet.next()) {
1308-
rowSet.moveToInsertRow();
1309-
for (String columnName : getIndexInfoColumnNames) {
1310-
Object value = customResultSet.getObject(columnName);
1311-
rowSet.updateObject(columnName, value);
1274+
1275+
String orgCat = null;
1276+
try {
1277+
orgCat = switchCatalogs(cat);
1278+
1279+
if (this.connection.isAzureDW()) {
1280+
return getIndexInfoAzureDW(arguments, table, schema);
1281+
} else {
1282+
PreparedStatement pstmt = (SQLServerPreparedStatement) this.connection.prepareStatement(INDEX_INFO_COMBINED_QUERY);
1283+
pstmt.setString(1, arguments[0]); // table name for sp_statistics
1284+
pstmt.setString(2, arguments[1]); // schema name for sp_statistics
1285+
pstmt.setString(3, arguments[2]); // catalog for sp_statistics
1286+
pstmt.setString(4, arguments[3]); // index name pattern for sp_statistics
1287+
pstmt.setString(5, arguments[4]); // is_unique for sp_statistics
1288+
pstmt.setString(6, arguments[5]); // accuracy for sp_statistics
1289+
pstmt.setString(7, table); // table name for columnstore query
1290+
pstmt.setString(8, schema); // schema name for columnstore query
1291+
1292+
return pstmt.executeQuery();
1293+
}
1294+
} finally {
1295+
if (null != orgCat) {
1296+
connection.setCatalog(orgCat);
13121297
}
1313-
rowSet.insertRow();
13141298
}
1315-
rowSet.moveToCurrentRow();
1316-
rowSet.beforeFirst();
1299+
}
13171300

1318-
return rowSet;
1301+
/**
1302+
* Azure DW specific implementation for getIndexInfo that executes sp_statistics
1303+
* and combines results with columnstore indexes from sys.indexes using UNION ALL.
1304+
*
1305+
* This approach works around Azure DW JDBC limitations with INSERT INTO...EXEC syntax
1306+
* by executing sp_statistics separately and building a dynamic result set.
1307+
*/
1308+
private java.sql.ResultSet getIndexInfoAzureDW(String[] arguments, String table, String schema) throws SQLException {
1309+
// Use LinkedHashMap for index info columns in the correct order
1310+
LinkedHashMap<Integer, String> getIndexInfoDWColumns = new LinkedHashMap<>();
1311+
getIndexInfoDWColumns.put(1, TABLE_CAT);
1312+
getIndexInfoDWColumns.put(2, TABLE_SCHEM);
1313+
getIndexInfoDWColumns.put(3, TABLE_NAME);
1314+
getIndexInfoDWColumns.put(4, NON_UNIQUE);
1315+
getIndexInfoDWColumns.put(5, INDEX_QUALIFIER);
1316+
getIndexInfoDWColumns.put(6, INDEX_NAME);
1317+
getIndexInfoDWColumns.put(7, TYPE);
1318+
getIndexInfoDWColumns.put(8, ORDINAL_POSITION);
1319+
getIndexInfoDWColumns.put(9, COLUMN_NAME);
1320+
getIndexInfoDWColumns.put(10, ASC_OR_DESC);
1321+
getIndexInfoDWColumns.put(11, CARDINALITY);
1322+
getIndexInfoDWColumns.put(12, PAGES);
1323+
getIndexInfoDWColumns.put(13, FILTER_CONDITION);
1324+
1325+
LinkedHashMap<Integer, String> getIndexInfoTypesDWColumns = new LinkedHashMap<>();
1326+
getIndexInfoTypesDWColumns.put(1, NVARCHAR); // TABLE_CAT
1327+
getIndexInfoTypesDWColumns.put(2, NVARCHAR); // TABLE_SCHEM
1328+
getIndexInfoTypesDWColumns.put(3, NVARCHAR); // TABLE_NAME
1329+
getIndexInfoTypesDWColumns.put(4, SMALLINT); // NON_UNIQUE
1330+
getIndexInfoTypesDWColumns.put(5, NVARCHAR); // INDEX_QUALIFIER
1331+
getIndexInfoTypesDWColumns.put(6, NVARCHAR); // INDEX_NAME
1332+
getIndexInfoTypesDWColumns.put(7, SMALLINT); // TYPE
1333+
getIndexInfoTypesDWColumns.put(8, SMALLINT); // ORDINAL_POSITION
1334+
getIndexInfoTypesDWColumns.put(9, NVARCHAR); // COLUMN_NAME
1335+
getIndexInfoTypesDWColumns.put(10, VARCHAR); // ASC_OR_DESC
1336+
getIndexInfoTypesDWColumns.put(11, INTEGER); // CARDINALITY
1337+
getIndexInfoTypesDWColumns.put(12, INTEGER); // PAGES
1338+
getIndexInfoTypesDWColumns.put(13, VARCHAR); // FILTER_CONDITION
1339+
1340+
try (PreparedStatement storedProcPstmt = this.connection
1341+
.prepareStatement("EXEC sp_statistics ?,?,?,?,?,?;")) {
1342+
storedProcPstmt.setString(1, arguments[0]); // table name
1343+
storedProcPstmt.setString(2, arguments[1]); // schema
1344+
storedProcPstmt.setString(3, arguments[2]); // catalog
1345+
storedProcPstmt.setString(4, arguments[3]); // index name pattern
1346+
storedProcPstmt.setString(5, arguments[4]); // is_unique
1347+
storedProcPstmt.setString(6, arguments[5]); // accuracy
1348+
1349+
SQLServerResultSet userRs = null;
1350+
PreparedStatement resultPstmt = null;
1351+
try (ResultSet rs = storedProcPstmt.executeQuery()) {
1352+
StringBuilder azureDwSelectBuilder = new StringBuilder();
1353+
boolean isFirstRow = true;
1354+
1355+
// Process sp_statistics results
1356+
while (rs.next()) {
1357+
if (!isFirstRow) {
1358+
azureDwSelectBuilder.append(" UNION ALL ");
1359+
}
1360+
azureDwSelectBuilder.append(generateAzureDWSelect(rs, getIndexInfoDWColumns, getIndexInfoTypesDWColumns));
1361+
isFirstRow = false;
1362+
}
1363+
1364+
// Add columnstore indexes from sys.indexes
1365+
if (!isFirstRow) {
1366+
azureDwSelectBuilder.append(" UNION ALL ");
1367+
}
1368+
azureDwSelectBuilder.append(
1369+
"SELECT db_name() AS TABLE_CAT, " +
1370+
"sch.name AS TABLE_SCHEM, " +
1371+
"t.name AS TABLE_NAME, " +
1372+
"CASE WHEN i.is_unique = 1 THEN 0 ELSE 1 END AS NON_UNIQUE, " +
1373+
"t.name AS INDEX_QUALIFIER, " +
1374+
"i.name AS INDEX_NAME, " +
1375+
"i.type AS TYPE, " +
1376+
"ic.key_ordinal AS ORDINAL_POSITION, " +
1377+
"c.name AS COLUMN_NAME, " +
1378+
"CASE WHEN ic.is_descending_key = 1 THEN 'D' ELSE 'A' END AS ASC_OR_DESC, " +
1379+
"NULL AS CARDINALITY, " +
1380+
"NULL AS PAGES, " +
1381+
"NULL AS FILTER_CONDITION " +
1382+
"FROM sys.indexes i " +
1383+
"INNER JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id " +
1384+
"INNER JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id " +
1385+
"INNER JOIN sys.tables t ON i.object_id = t.object_id " +
1386+
"INNER JOIN sys.schemas sch ON t.schema_id = sch.schema_id " +
1387+
"WHERE t.name = '" + table + "' AND sch.name = '" + schema + "' AND ic.key_ordinal = 0"
1388+
);
1389+
1390+
if (0 == azureDwSelectBuilder.length()) {
1391+
azureDwSelectBuilder.append(generateAzureDWEmptyRS(getIndexInfoDWColumns));
1392+
} else {
1393+
azureDwSelectBuilder.append(" ORDER BY NON_UNIQUE, TYPE, INDEX_NAME, ORDINAL_POSITION");
1394+
}
1395+
1396+
resultPstmt = (SQLServerPreparedStatement) this.connection
1397+
.prepareStatement(azureDwSelectBuilder.toString());
1398+
userRs = (SQLServerResultSet) resultPstmt.executeQuery();
1399+
resultPstmt.closeOnCompletion();
1400+
} catch (SQLException e) {
1401+
if (null != resultPstmt) {
1402+
try {
1403+
resultPstmt.close();
1404+
} catch (SQLServerException ignore) {
1405+
if (loggerExternal.isLoggable(Level.FINER)) {
1406+
loggerExternal.finer(
1407+
"getIndexInfo() threw an exception when attempting to close PreparedStatement");
1408+
}
1409+
}
1410+
}
1411+
throw e;
1412+
}
1413+
return userRs;
1414+
}
13191415
}
13201416

13211417
@Override

src/test/java/com/microsoft/sqlserver/jdbc/databasemetadata/DatabaseMetaDataTest.java

Lines changed: 33 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1349,6 +1349,39 @@ public void testGetIndexInfoCaseSensitivity() throws SQLException {
13491349
}
13501350
}
13511351
}
1352+
1353+
@Test
1354+
public void testGetIndexInfoResultSetNextAfterFalse() throws SQLException {
1355+
try (Connection connection = getConnection()) {
1356+
String catalog = connection.getCatalog();
1357+
String schema = "dbo";
1358+
String table = "DBMetadataTestTable";
1359+
DatabaseMetaData dbMetadata = connection.getMetaData();
1360+
1361+
try (ResultSet rs = dbMetadata.getIndexInfo(catalog, schema, table, false, false)) {
1362+
// First, enumerate all rows
1363+
int rowCount = 0;
1364+
while (rs.next()) {
1365+
rowCount++;
1366+
assertNotNull(rs.getString("TABLE_NAME"));
1367+
}
1368+
1369+
assertTrue(rowCount > 0, "Expected at least one index row");
1370+
1371+
// Now test the critical fix: calling next() after it returned false should not throw exception
1372+
boolean hasMore1 = rs.next();
1373+
assertFalse(hasMore1, "next() after end of ResultSet should return false");
1374+
1375+
// Test multiple calls to next() after end - all should return false without exception
1376+
boolean hasMore2 = rs.next();
1377+
assertFalse(hasMore2, "Second call to next() after end should also return false");
1378+
1379+
// Test the exact pattern from issue #2758 - checking completion with !rs.next()
1380+
boolean isComplete = !rs.next();
1381+
assertTrue(isComplete, "Pattern from issue: !rs.next() should return true when at end");
1382+
}
1383+
}
1384+
}
13521385
}
13531386

13541387
private void setupProcedures(String schemaName, String proc1, String proc1Body,

0 commit comments

Comments
 (0)