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

Updated getIndexInfo() to include Columnstore indexes by using custom query. #2566

Open
wants to merge 9 commits into
base: main
Choose a base branch
from
Original file line number Diff line number Diff line change
Expand Up @@ -1197,39 +1197,47 @@ private ResultSet executeSPFkeys(String[] procParams) throws SQLException {
}
}

private static final String[] getIndexInfoColumnNames = { /* 1 */ TABLE_CAT, /* 2 */ TABLE_SCHEM,
/* 3 */ TABLE_NAME, /* 4 */ NON_UNIQUE, /* 5 */ INDEX_QUALIFIER, /* 6 */ INDEX_NAME, /* 7 */ TYPE,
/* 8 */ ORDINAL_POSITION, /* 9 */ COLUMN_NAME, /* 10 */ ASC_OR_DESC, /* 11 */ CARDINALITY, /* 12 */ PAGES,
/* 13 */ FILTER_CONDITION};

@Override
public java.sql.ResultSet getIndexInfo(String cat, String schema, String table, boolean unique,
boolean approximate) throws SQLServerException, SQLTimeoutException {
boolean approximate) throws SQLException {
if (loggerExternal.isLoggable(Level.FINER) && Util.isActivityTraceOn()) {
loggerExternal.finer(toString() + ACTIVITY_ID + ActivityCorrelator.getCurrent().toString());
}
checkClosed();
/*
* sp_statistics [ @table_name = ] 'table_name' [ , [ @table_owner = ] 'owner' ] [ , [ @table_qualifier = ]
* 'qualifier' ] [ , [ @index_name = ] 'index_name' ] [ , [ @is_unique = ] 'is_unique' ] [ , [ @accuracy = ]
* 'accuracy' ]
*/
String[] arguments = new String[6];
arguments[0] = table;
arguments[1] = schema;
arguments[2] = cat;
// use default for index name
arguments[3] = "%"; // index name % is default
if (unique)
arguments[4] = "Y"; // is_unique
else
arguments[4] = "N";
if (approximate)
arguments[5] = "Q";
else
arguments[5] = "E";
return getResultSetWithProvidedColumnNames(cat, CallableHandles.SP_STATISTICS, arguments,
getIndexInfoColumnNames);
* Replaced the use of the sp_statistics stored procedure with a custom query to retrieve index information.
*
* Reason for change:
* The sp_statistics procedure was not returning Columnstore indexes, which was limiting the results.
* To address this issue and include all index types (Clustered, NonClustered, and Columnstore), a direct
* SQL query using sys.indexes, sys.index_columns, and related system views was implemented.
*
* This query ensures a complete set of index information, regardless of the index type, as a workaround for
* the limitations of sp_statistics.
*
* GitHub Issue: #2546 - Columnstore indexes were missing from sp_statistics results.
*/
StringBuilder queryBuilder = new StringBuilder();
queryBuilder.append("SELECT ")
.append("db_name() AS CatalogName, ")
.append("sch.name AS SchemaName, ")
.append("t.name AS TableName, ")
.append("i.name AS IndexName, ")
.append("i.type_desc AS IndexType, ")
.append("i.is_unique AS IsUnique, ")
.append("c.name AS ColumnName, ")
.append("ic.key_ordinal AS ColumnOrder ")
.append("FROM sys.indexes i ")
.append("INNER JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id ")
.append("INNER JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id ")
.append("INNER JOIN sys.tables t ON i.object_id = t.object_id ")
.append("INNER JOIN sys.schemas sch ON t.schema_id = sch.schema_id ")
.append("WHERE t.name = '").append(table).append("' ")
.append("AND sch.name = '").append(schema).append("' ")
.append("ORDER BY t.name, i.name, ic.key_ordinal");

String query = queryBuilder.toString();
return getResultSetFromInternalQueries(cat, query);
}

@Override
Expand Down
6 changes: 5 additions & 1 deletion src/test/java/com/microsoft/sqlserver/jdbc/TestResource.java
Original file line number Diff line number Diff line change
Expand Up @@ -216,5 +216,9 @@ protected Object[][] getContents() {
{"R_expectedClassDoesNotMatchActualClass",
"Expected column class {0} does not match actual column class {1} for column {2}."},
{"R_loginFailedMI", "Login failed for user '<token-identified principal>'"},
{"R_MInotAvailable", "Managed Identity authentication is not available"},};
{"R_MInotAvailable", "Managed Identity authentication is not available"},
{"R_noSQLWarningsCreateTableConnection", "Expecting NO SQLWarnings from 'create table', at Connection."},
{"R_noSQLWarningsCreateTableStatement", "Expecting NO SQLWarnings from 'create table', at Statement."},
{"R_noSQLWarningsCreateIndexConnection", "Expecting NO SQLWarnings from 'create index', at Connection."},
{"R_noSQLWarningsCreateIndexStatement", "Expecting NO SQLWarnings from 'create index', at Statement."},};
}
Original file line number Diff line number Diff line change
@@ -0,0 +1,177 @@
package com.microsoft.sqlserver.jdbc.databasemetadata;

import static org.junit.jupiter.api.Assertions.assertEquals;
import static org.junit.jupiter.api.Assertions.assertNull;
import static org.junit.jupiter.api.Assertions.assertTrue;
import static org.junit.jupiter.api.Assertions.fail;

import java.sql.Connection;
import java.sql.DatabaseMetaData;
import java.sql.ResultSet;
import java.sql.SQLException;
import java.sql.Statement;

import org.junit.jupiter.api.AfterEach;
import org.junit.jupiter.api.BeforeAll;
import org.junit.jupiter.api.BeforeEach;
import org.junit.jupiter.api.Test;
import com.microsoft.sqlserver.testframework.AbstractTest;
import com.microsoft.sqlserver.jdbc.RandomUtil;
import com.microsoft.sqlserver.jdbc.SQLServerException;
import com.microsoft.sqlserver.jdbc.TestResource;
import com.microsoft.sqlserver.jdbc.TestUtils;
import com.microsoft.sqlserver.testframework.AbstractSQLGenerator;

public class DatabaseMetadataGetIndexInfoTest extends AbstractTest {

private static String tableName = AbstractSQLGenerator.escapeIdentifier("DBMetadataTestTable");
Ananya2 marked this conversation as resolved.
Show resolved Hide resolved
private static String col1Name = AbstractSQLGenerator.escapeIdentifier(RandomUtil.getIdentifier("col1"));
private static String col2Name = AbstractSQLGenerator.escapeIdentifier(RandomUtil.getIdentifier("col2"));
private static String col3Name = AbstractSQLGenerator.escapeIdentifier(RandomUtil.getIdentifier("col3"));

Ananya2 marked this conversation as resolved.
Show resolved Hide resolved
@BeforeAll
public static void setupTests() throws Exception {
setConnection();
}

@BeforeEach
public void init() throws SQLException {
try (Connection con = getConnection()) {
con.setAutoCommit(false);
try (Statement stmt = con.createStatement()) {
TestUtils.dropTableIfExists(tableName, stmt);
String createTableSQL = "CREATE TABLE " + tableName + " (" + col1Name + " INT, " + col2Name + " INT, "
+ col3Name + " INT)";

stmt.executeUpdate(createTableSQL);
assertNull(connection.getWarnings(), TestResource.getResource("R_noSQLWarningsCreateTableConnection"));
assertNull(stmt.getWarnings(), TestResource.getResource("R_noSQLWarningsCreateTableStatement"));

String createClusteredIndexSQL = "CREATE CLUSTERED INDEX IDX_Clustered ON " + tableName + "(" + col1Name
+ ")";
stmt.executeUpdate(createClusteredIndexSQL);
assertNull(connection.getWarnings(), TestResource.getResource("R_noSQLWarningsCreateIndexConnection"));
assertNull(stmt.getWarnings(), TestResource.getResource("R_noSQLWarningsCreateIndexStatement"));

String createNonClusteredIndexSQL = "CREATE NONCLUSTERED INDEX IDX_NonClustered ON " + tableName + "("
+ col2Name + ")";
stmt.executeUpdate(createNonClusteredIndexSQL);
assertNull(connection.getWarnings(), TestResource.getResource("R_noSQLWarningsCreateIndexConnection"));
assertNull(stmt.getWarnings(), TestResource.getResource("R_noSQLWarningsCreateIndexStatement"));

String createColumnstoreIndexSQL = "CREATE COLUMNSTORE INDEX IDX_Columnstore ON " + tableName + "("
+ col3Name + ")";
stmt.executeUpdate(createColumnstoreIndexSQL);
assertNull(connection.getWarnings(), TestResource.getResource("R_noSQLWarningsCreateIndexConnection"));
assertNull(stmt.getWarnings(), TestResource.getResource("R_noSQLWarningsCreateIndexStatement"));
}
con.commit();
}
}

@AfterEach
public void terminate() throws SQLException {
try (Connection con = getConnection(); Statement stmt = con.createStatement()) {
try {
TestUtils.dropTableIfExists(tableName, stmt);
} catch (SQLException e) {
fail(TestResource.getResource("R_unexpectedException") + e.getMessage());
}
}
}

@Test
public void testGetIndexInfo() throws SQLException {
ResultSet rs1, rs2 = null;
try (Connection connection = getConnection(); Statement stmt = connection.createStatement()) {
String catalog = connection.getCatalog();
String schema = "dbo";
String table = "DBMetadataTestTable";
DatabaseMetaData dbMetadata = connection.getMetaData();
rs1 = dbMetadata.getIndexInfo(catalog, schema, table, false, false);

boolean hasClusteredIndex = false;
boolean hasNonClusteredIndex = false;
boolean hasColumnstoreIndex = false;

String query = "SELECT " + " db_name() AS CatalogName, " + " sch.name AS SchemaName, "
+ " t.name AS TableName, " + " i.name AS IndexName, " + " i.type_desc AS IndexType, "
+ " i.is_unique AS IsUnique, " + " c.name AS ColumnName, "
+ " ic.key_ordinal AS ColumnOrder " + "FROM " + " sys.indexes i " + "INNER JOIN "
+ " sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id "
+ "INNER JOIN " + " sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id "
+ "INNER JOIN " + " sys.tables t ON i.object_id = t.object_id " + "INNER JOIN "
+ " sys.schemas sch ON t.schema_id = sch.schema_id " +

"WHERE t.name = '" + table + "' " + "AND sch.name = '" + schema + "' " + "ORDER BY "
+ " t.name, i.name, ic.key_ordinal;";
rs2 = stmt.executeQuery(query);

while (rs1.next() && rs2.next()) {
String indexType = rs1.getString("IndexType");
String indexName = rs1.getString("IndexName");
String catalogName = rs1.getString("CatalogName");
String schemaName = rs1.getString("SchemaName");
String tableName = rs1.getString("TableName");
boolean isUnique = rs1.getBoolean("IsUnique");
String columnName = rs1.getString("ColumnName");
int columnOrder = rs1.getInt("ColumnOrder");

assertEquals(catalogName, rs2.getString("CatalogName"));
assertEquals(schemaName, rs2.getString("SchemaName"));
assertEquals(tableName, rs2.getString("TableName"));
assertEquals(indexName, rs2.getString("IndexName"));
assertEquals(indexType, rs2.getString("IndexType"));
assertEquals(isUnique, rs2.getBoolean("IsUnique"));
assertEquals(columnName, rs2.getString("ColumnName"));
assertEquals(columnOrder, rs2.getInt("ColumnOrder"));

if (indexType.contains("COLUMNSTORE")) {
hasColumnstoreIndex = true;
} else if (indexType.equals("CLUSTERED")) {
hasClusteredIndex = true;
} else if (indexType.equals("NONCLUSTERED")) {
hasNonClusteredIndex = true;
}
}

assertTrue(hasColumnstoreIndex, "COLUMNSTORE index not found.");
assertTrue(hasClusteredIndex, "CLUSTERED index not found.");
assertTrue(hasNonClusteredIndex, "NONCLUSTERED index not found.");
}
}

@Test
public void testGetIndexInfoCaseSensitivity() throws SQLException {
ResultSet rs1, rs2 = null;
try (Connection connection = getConnection()) {
String catalog = connection.getCatalog();
String schema = "dbo";
String table = "DBMetadataTestTable";

DatabaseMetaData dbMetadata = connection.getMetaData();
rs1 = dbMetadata.getIndexInfo(catalog, schema, table, false, false);
rs2 = dbMetadata.getIndexInfo(catalog, schema, table.toUpperCase(), false, false);

while (rs1.next() && rs2.next()) {
String indexType = rs1.getString("IndexType");
String indexName = rs1.getString("IndexName");
String catalogName = rs1.getString("CatalogName");
String schemaName = rs1.getString("SchemaName");
String tableName = rs1.getString("TableName");
boolean isUnique = rs1.getBoolean("IsUnique");
String columnName = rs1.getString("ColumnName");
int columnOrder = rs1.getInt("ColumnOrder");

assertEquals(catalogName, rs2.getString("CatalogName"));
assertEquals(schemaName, rs2.getString("SchemaName"));
assertEquals(tableName, rs2.getString("TableName"));
assertEquals(indexName, rs2.getString("IndexName"));
assertEquals(indexType, rs2.getString("IndexType"));
assertEquals(isUnique, rs2.getBoolean("IsUnique"));
assertEquals(columnName, rs2.getString("ColumnName"));
assertEquals(columnOrder, rs2.getInt("ColumnOrder"));
}
}
}
}
Loading