Zeos 7.0 Interbase GetIndexInfo for all ind. in SQLMetadata
Posted: 01.04.2011, 23:11
function TZInterbase6DatabaseMetadata.UncachedGetIndexInfo(const Catalog: string;
const Schema: string; const Table: string; Unique: Boolean;
Approximate: Boolean): IZResultSet;
var
SQL : string;
begin
Result := ConstructVirtualResultSet(IndexInfoColumnsDynArray);
SQL := ' SELECT I.RDB$RELATION_NAME, I.RDB$UNIQUE_FLAG, I.RDB$INDEX_NAME,'
+ ' ISGMT.RDB$FIELD_POSITION, ISGMT.RDB$FIELD_NAME, I.RDB$INDEX_TYPE,'
+ ' I.RDB$SEGMENT_COUNT, COUNT (DISTINCT P.RDB$PAGE_NUMBER) '
+ ' FROM RDB$INDICES I JOIN RDB$INDEX_SEGMENTS ISGMT ON'
+ ' I.RDB$INDEX_NAME = ISGMT.RDB$INDEX_NAME JOIN RDB$RELATIONS R ON'
+ ' (R.RDB$RELATION_NAME = I.RDB$RELATION_NAME) JOIN RDB$PAGES P ON'
+ ' (P.RDB$RELATION_ID = R.RDB$RELATION_ID AND P.RDB$PAGE_TYPE = 7'
+ ' OR P.RDB$PAGE_TYPE = 6) WHERE ';
if Unique then
SQL := SQL + ' I.RDB$UNIQUE_FLAG = 1 AND ';
if ( Table = '' ) then //Added by EgonHugeist to show all indices 30.03.2011
SQL := SQL + 'I.RDB$RELATION_NAME != '''' GROUP BY '+
'I.RDB$RELATION_NAME, ISGMT.RDB$FIELD_NAME, I.RDB$INDEX_NAME, '+
'I.RDB$UNIQUE_FLAG, ISGMT.RDB$FIELD_POSITION, I.RDB$INDEX_TYPE, '+
'I.RDB$SEGMENT_COUNT ORDER BY 1,2,3,4'
else
SQL := SQL + ' I.RDB$RELATION_NAME = ''' + Table + ''' GROUP BY '
+ ' I.RDB$INDEX_NAME, I.RDB$RELATION_NAME, I.RDB$UNIQUE_FLAG, '
+ ' ISGMT.RDB$FIELD_POSITION, ISGMT.RDB$FIELD_NAME, I.RDB$INDEX_TYPE, '
+ ' I.RDB$SEGMENT_COUNT ORDER BY 2,3,4';
with GetConnection.CreateStatement.ExecuteQuery(SQL) do
begin
while Next do
begin
Result.MoveToInsertRow;
Result.UpdateNull(1); //TABLE_CAT
Result.UpdateNull(2); //TABLE_SCHEM
Result.UpdateString(3, GetString(1)); //TABLE_NAME, RDB$RELATION_NAME
Result.UpdateBoolean(4, not GetBoolean(2)); //NON_UNIQUE, RDB$UNIQUE_FLAG
Result.UpdateNull(5); //INDEX_QUALIFIER
Result.UpdateString(6, GetString(3)); //INDEX_NAME, RDB$INDEX_NAME
Result.UpdateInt(7, Ord(ntNoNulls)); //TYPE
Result.UpdateInt(8, GetInt(4) + 1); //ORDINAL_POSITION, RDB$FIELD_POSITION
Result.UpdateString(9, GetString(5)); //COLUMN_NAME, RDB$FIELD_NAME
Result.UpdateNull(10); //ASC_OR_DESC
Result.UpdateNull(11); //CARDINALITY
Result.UpdateInt(12, GetInt(7)); //PAGES, RDB$SEGMENT_COUNT
Result.UpdateNull(13); //FILTER_CONDITION
Result.InsertRow;
end;
Close;
end;
end;
Just an example for Interbase
const Schema: string; const Table: string; Unique: Boolean;
Approximate: Boolean): IZResultSet;
var
SQL : string;
begin
Result := ConstructVirtualResultSet(IndexInfoColumnsDynArray);
SQL := ' SELECT I.RDB$RELATION_NAME, I.RDB$UNIQUE_FLAG, I.RDB$INDEX_NAME,'
+ ' ISGMT.RDB$FIELD_POSITION, ISGMT.RDB$FIELD_NAME, I.RDB$INDEX_TYPE,'
+ ' I.RDB$SEGMENT_COUNT, COUNT (DISTINCT P.RDB$PAGE_NUMBER) '
+ ' FROM RDB$INDICES I JOIN RDB$INDEX_SEGMENTS ISGMT ON'
+ ' I.RDB$INDEX_NAME = ISGMT.RDB$INDEX_NAME JOIN RDB$RELATIONS R ON'
+ ' (R.RDB$RELATION_NAME = I.RDB$RELATION_NAME) JOIN RDB$PAGES P ON'
+ ' (P.RDB$RELATION_ID = R.RDB$RELATION_ID AND P.RDB$PAGE_TYPE = 7'
+ ' OR P.RDB$PAGE_TYPE = 6) WHERE ';
if Unique then
SQL := SQL + ' I.RDB$UNIQUE_FLAG = 1 AND ';
if ( Table = '' ) then //Added by EgonHugeist to show all indices 30.03.2011
SQL := SQL + 'I.RDB$RELATION_NAME != '''' GROUP BY '+
'I.RDB$RELATION_NAME, ISGMT.RDB$FIELD_NAME, I.RDB$INDEX_NAME, '+
'I.RDB$UNIQUE_FLAG, ISGMT.RDB$FIELD_POSITION, I.RDB$INDEX_TYPE, '+
'I.RDB$SEGMENT_COUNT ORDER BY 1,2,3,4'
else
SQL := SQL + ' I.RDB$RELATION_NAME = ''' + Table + ''' GROUP BY '
+ ' I.RDB$INDEX_NAME, I.RDB$RELATION_NAME, I.RDB$UNIQUE_FLAG, '
+ ' ISGMT.RDB$FIELD_POSITION, ISGMT.RDB$FIELD_NAME, I.RDB$INDEX_TYPE, '
+ ' I.RDB$SEGMENT_COUNT ORDER BY 2,3,4';
with GetConnection.CreateStatement.ExecuteQuery(SQL) do
begin
while Next do
begin
Result.MoveToInsertRow;
Result.UpdateNull(1); //TABLE_CAT
Result.UpdateNull(2); //TABLE_SCHEM
Result.UpdateString(3, GetString(1)); //TABLE_NAME, RDB$RELATION_NAME
Result.UpdateBoolean(4, not GetBoolean(2)); //NON_UNIQUE, RDB$UNIQUE_FLAG
Result.UpdateNull(5); //INDEX_QUALIFIER
Result.UpdateString(6, GetString(3)); //INDEX_NAME, RDB$INDEX_NAME
Result.UpdateInt(7, Ord(ntNoNulls)); //TYPE
Result.UpdateInt(8, GetInt(4) + 1); //ORDINAL_POSITION, RDB$FIELD_POSITION
Result.UpdateString(9, GetString(5)); //COLUMN_NAME, RDB$FIELD_NAME
Result.UpdateNull(10); //ASC_OR_DESC
Result.UpdateNull(11); //CARDINALITY
Result.UpdateInt(12, GetInt(7)); //PAGES, RDB$SEGMENT_COUNT
Result.UpdateNull(13); //FILTER_CONDITION
Result.InsertRow;
end;
Close;
end;
end;
Just an example for Interbase