Kal,

According to the Java 5 docs, the getIndexInfo ResultSet should contain all of the required information (INDEX_NAME, COLUMN_NAME, NON_UNIQUE) – if the index consists of multiple columns, then multiple ResultSet entries will be returned for a given INDEX_NAME, and you’ll have to use ORDINAL_POSITION to recreate the sequencing of columns within the index.

 

If not, you might try looking at the thread/link that Rick Hillegas sent (http://www.nabble.com/How-can-I-fetch-constraint-attribute-on-Column-Level-from-SYS-Tables---td19554573.html#a19554573)

 

Thomas

INFOTECH Soft, Inc.

getIndexInfo

ResultSet getIndexInfo(String catalog,

                       String schema,

                       String table,

                       boolean unique,

                       boolean approximate)

                       throws SQLException

Retrieves a description of the given table's indices and statistics. They are ordered by NON_UNIQUE, TYPE, INDEX_NAME, and ORDINAL_POSITION.

Each index column description has the following columns:

1.      TABLE_CAT String => table catalog (may be null)

2.      TABLE_SCHEM String => table schema (may be null)

3.      TABLE_NAME String => table name

4.      NON_UNIQUE boolean => Can index values be non-unique. false when TYPE is tableIndexStatistic

5.      INDEX_QUALIFIER String => index catalog (may be null); null when TYPE is tableIndexStatistic

6.      INDEX_NAME String => index name; null when TYPE is tableIndexStatistic

7.      TYPE short => index type:

o    tableIndexStatistic - this identifies table statistics that are returned in conjuction with a table's index descriptions

o    tableIndexClustered - this is a clustered index

o    tableIndexHashed - this is a hashed index

o    tableIndexOther - this is some other style of index

8.      ORDINAL_POSITION short => column sequence number within index; zero when TYPE is tableIndexStatistic

9.      COLUMN_NAME String => column name; null when TYPE is tableIndexStatistic

10.  ASC_OR_DESC String => column sort sequence, "A" => ascending, "D" => descending, may be null if sort sequence is not supported; null when TYPE is tableIndexStatistic

11.  CARDINALITY int => When TYPE is tableIndexStatistic, then this is the number of rows in the table; otherwise, it is the number of unique values in the index.

12.  PAGES int => When TYPE is tableIndexStatisic then this is the number of pages used for the table, otherwise it is the number of pages used for the current index.

13.  FILTER_CONDITION String => Filter condition, if any. (may be null)

Parameters:

catalog - a catalog name; must match the catalog name as it is stored in this database; "" retrieves those without a catalog; null means that the catalog name should not be used to narrow the search

schema - a schema name; must match the schema name as it is stored in this database; "" retrieves those without a schema; null means that the schema name should not be used to narrow the search

table - a table name; must match the table name as it is stored in this database

unique - when true, return only indices for unique values; when false, return indices regardless of whether unique or not

approximate - when true, result is allowed to reflect approximate or out of data values; when false, results are requested to be accurate

Returns:

ResultSet - each row is an index column description

Throws:

SQLException - if a database access error occurs

 

 

From: Kalyan Inuganti [mailto:kinuganti@gmail.com]
Sent: Thursday, March 05, 2009 1:44 PM
To: Thomas@infotechsoft.com; derby-user@db.apache.org
Subject: Re: Derby 10.1 -> 10.2 upgrade issue

 

Hi Thomas,

I have been doing some research on how i can get the column name(s) that the index corresponds to (see the 2nd bold section of the SQL) and haven't found anything yet. Any ideas? I would also like to know if a given index is a unique index or not? The reason I say this is because I looked at "Create Index..." statements and there are 2 flavors - ones with the Unique qualifier and the others without.

statement.executeUpdate(“CREATE UNIQUE INDEX “+indexNameString+” ON DeviceInfo (DeviceID)”);

Thanks a lot for your help!
Kal

On Thu, Mar 5, 2009 at 11:15 AM, Thomas J. Taylor <Thomas.Taylor@infotechsoft.com> wrote:

Hi Kal,

 

I’ll check to see if I can find the code/process that I used back then to solve the issue. Since I only had one (remote) Derby installation causing problems, once I figured out the way to resolve the problem (drop & recreate index), I probably (1) used DBLook to identify the corrupt (missing) indexes, then used SQurilleL to (2) identify the names of the keys through the GUI, (3) write the DDL to drop and re-create the indexes.

 

You should be able to use JDBC to get the same index information and drop/create the index that way; however, the challenge is identifying the corrupt indices. Perhaps this might work?

 

Connection connection; // existing db connection

Statement statement = connection.createStatement(); 

try {

     // test table to confirm corrupt index: SQLException is thrown if corrupt

statement.executeQuery(“SELECT DeviceID, DeviceName, DeviceType FROM DeviceInfo WHERE DeviceID=1”);

} catch (SQLException ex) {

     // retrieve index information for the corrupt table

// http://java.sun.com/j2se/1.5.0/docs/api/java/sql/DatabaseMetaData.html#getIndexInfo(java.lang.String, java.lang.String, java.lang.String, boolean, boolean)

     DatabaseMetaData databaseMetaData = conn.getMetaData();

     ResultSet resultSet = databaseMetaData.getIndexInfo(null, null, “DeviceInfo”, false, false);

     // for each index, drop & recreate the index

     while (resultSet.hasNext()) {

           // get the name of the

           String indexNameString = resultSet.getString(“INDEX_NAME”);

           statement.executeUpdate(“DROP INDEX ”+indexNameString+” ON DeviceInfo);

// recreate index: http://db.apache.org/derby/docs/10.2/ref/rrefsqlj20937.html

           statement.executeUpdate(“CREATE UNIQUE INDEX “+indexNameString+” ON DeviceInfo (DeviceID)”);

}

}

 

Thomas Taylor

INFOTECH Soft, Inc.

 

From: Kalyan Inuganti [mailto:kinuganti@gmail.com]
Sent: Thursday, March 05, 2009 11:10 AM
To: derby-user@db.apache.org
Subject: Derby 10.1 -> 10.2 upgrade issue

 

Hi,

I am reaching out to you guys for some help with a Derby indexing issue that we have run into at Monsanto, St. Louis. The issue is pretty much the same issue that was reported by Thomas J. Taylor in 2007 (The link is provided below).

Brief Description:

I have a database that was originally created with Derby 10.1.1.0 and was



 
recently upgraded to Derby 10.2.2.0. I've performed this upgrade on several



 




 
copies of the same database schema (each created on different computers,



 
but with the same version of Java (1.5.0_07) and Derby (10.1)).



 




 
For all but one of the database upgrades, it worked correctly. However, in



 




 
one case, it appears that the PRIMARY KEY and FOREIGN KEY constraints have



 
been lost/corrupted. When I use DBLook to check a 'working' database, I see



 
the appropriate constraints for keys. However, on the 'defective' database,



 




 
these constraints are missing.


We have over 80 tables in the DB and over 1000 users. Even though we have only 2 reported occurrences of this issue so far, it might be more widespread. It is a nightmare to manually identify the corrupted indexes for each occurrence. Any thoughts on how we can tackle this through a programmatic approach?

Here is the link to the old report:

http://mail-archives.apache.org/mod_mbox/db-derby-user/200704.mbox/%3C462D5DF8.80101@gmail.com%3E

Thanks,
Kal