Skip to content

Commit

Permalink
Detect foreign keys in MS SQL, and provide foreign values drop down i…
Browse files Browse the repository at this point in the history
…n data grid. Closes #150
  • Loading branch information
ansgarbecker committed Jan 26, 2020
1 parent c79be62 commit 7ab47a3
Show file tree
Hide file tree
Showing 3 changed files with 71 additions and 12 deletions.
39 changes: 39 additions & 0 deletions source/dbconnection.pas
Expand Up @@ -571,6 +571,7 @@ TAdoDBConnection = class(TDBConnection)
function GetLastResults: TDBQueryList; override;
property LastRawResults: TAdoRawResults read FLastRawResults;
function GetTableColumns(Table: TDBObject): TTableColumnList; override;
function GetTableForeignKeys(Table: TDBObject): TForeignKeyList; override;
end;

TPGRawResults = Array of PPGresult;
Expand Down Expand Up @@ -5024,6 +5025,44 @@ function TDBConnection.GetTableForeignKeys(Table: TDBObject): TForeignKeyList;
end;


function TAdoDbConnection.GetTableForeignKeys(Table: TDBObject): TForeignKeyList;
var
ForeignQuery: TDBQuery;
ForeignKey: TForeignKey;
begin
// MS SQL: see #150
Result := TForeignKeyList.Create(True);
ForeignQuery := GetResults('SELECT'+
' f.name AS foreign_key_name,'+
' COL_NAME(fc.parent_object_id, fc.parent_column_id) AS constraint_column_name,'+
' OBJECT_NAME (f.referenced_object_id) AS referenced_object,'+
' COL_NAME(fc.referenced_object_id, fc.referenced_column_id) AS referenced_column_name,'+
' update_referential_action_desc,'+
' delete_referential_action_desc'+
' FROM sys.foreign_keys AS f'+
' INNER JOIN sys.foreign_key_columns AS fc'+
' ON f.object_id = fc.constraint_object_id'+
' WHERE f.parent_object_id = OBJECT_ID('+EscapeString(Table.Name)+')'
);
ForeignKey := nil;
while not ForeignQuery.Eof do begin
if (not Assigned(ForeignKey)) or (ForeignKey.KeyName <> ForeignQuery.Col('foreign_key_name')) then begin
ForeignKey := TForeignKey.Create(Self);
Result.Add(ForeignKey);
ForeignKey.KeyName := ForeignQuery.Col('foreign_key_name');
ForeignKey.OldKeyName := ForeignKey.KeyName;
ForeignKey.ReferenceTable := ForeignQuery.Col('referenced_object');
ForeignKey.OnUpdate := ForeignQuery.Col('update_referential_action_desc');
ForeignKey.OnDelete := ForeignQuery.Col('delete_referential_action_desc');
end;
ForeignKey.Columns.Add(ForeignQuery.Col('constraint_column_name'));
ForeignKey.ForeignColumns.Add(ForeignQuery.Col('referenced_column_name'));
ForeignQuery.Next;
end;
ForeignQuery.Free;
end;


function TSQLiteConnection.GetTableForeignKeys(Table: TDBObject): TForeignKeyList;
var
ForeignQuery: TDBQuery;
Expand Down
19 changes: 13 additions & 6 deletions source/main.pas
Expand Up @@ -9531,7 +9531,7 @@ procedure TMainForm.AnyGridCreateEditor(Sender: TBaseVirtualTree; Node:
Results.RecNo := RowNum^;
Conn := Results.Connection;

// Find foreign key values on InnoDB table cells
// Find foreign key values
if AppSettings.ReadBool(asForeignDropDown) and (Sender = DataGrid) then begin
for ForeignKey in SelectedTableForeignKeys do begin
idx := ForeignKey.Columns.IndexOf(DataGrid.Header.Columns[Column].Text);
Expand All @@ -9557,11 +9557,18 @@ procedure TMainForm.AnyGridCreateEditor(Sender: TBaseVirtualTree; Node:
end;

KeyCol := Conn.QuoteIdent(ForeignKey.ForeignColumns[idx]);
SQL := 'SELECT '+KeyCol;
if TextCol <> '' then SQL := SQL + ', ' + Format(Conn.GetSQLSpecifity(spFuncLeft), [Conn.QuoteIdent(TextCol), 256]);
SQL := SQL + ' FROM '+Conn.QuoteIdent(ForeignKey.ReferenceTable, True, '.')+' GROUP BY '+KeyCol+' ORDER BY ';
if TextCol <> '' then SQL := SQL + Conn.QuoteIdent(TextCol) else SQL := SQL + KeyCol;
SQL := SQL + ' LIMIT ' + ForeignItemsLimit.ToString;
if TextCol <> '' then begin
SQL := KeyCol+', ' + Format(Conn.GetSQLSpecifity(spFuncLeft), [Conn.QuoteIdent(TextCol), 256])+
' FROM '+Conn.QuoteIdent(ForeignKey.ReferenceTable, True, '.')+
' GROUP BY '+KeyCol+', '+Conn.QuoteIdent(TextCol)+ // MSSQL complains if the text columns is not grouped
' ORDER BY '+Conn.QuoteIdent(TextCol);
end else begin
SQL := KeyCol+
' FROM '+Conn.QuoteIdent(ForeignKey.ReferenceTable, True, '.')+
' GROUP BY '+KeyCol+
' ORDER BY '+KeyCol;
end;
SQL := Conn.ApplyLimitClause('SELECT', SQL, ForeignItemsLimit, 0);

ForeignResults := Conn.GetResults(SQL);
if ForeignResults.RecordCount < ForeignItemsLimit then begin
Expand Down
25 changes: 19 additions & 6 deletions source/table_editor.pas
Expand Up @@ -2250,6 +2250,7 @@ procedure TfrmTableEditor.listForeignKeysEditing(Sender: TBaseVirtualTree; Node:
Column: TColumnIndex; var Allowed: Boolean);
var
Key: TForeignKey;
ExistsQuery: String;
begin
// Disallow editing foreign columns when no reference table was selected.
// Also, check for existance of reference table and warn if it's missing.
Expand All @@ -2260,7 +2261,11 @@ procedure TfrmTableEditor.listForeignKeysEditing(Sender: TBaseVirtualTree; Node:
ErrorDialog(_('Please select a reference table before selecting foreign columns.'))
else begin
try
DBObject.Connection.GetVar('SELECT 1 FROM '+DBObject.Connection.QuoteIdent(Key.ReferenceTable, True, '.')+' LIMIT 1');
ExistsQuery := DBObject.Connection.ApplyLimitClause(
'SELECT',
'1 FROM '+DBObject.Connection.QuoteIdent(Key.ReferenceTable, True, '.'),
1, 0);
DBObject.Connection.GetVar(ExistsQuery);
Allowed := True;
except
// Leave Allowed = False
Expand All @@ -2282,8 +2287,10 @@ procedure TfrmTableEditor.listForeignKeysCreateEditor(
DBObjects: TDBObjectList;
Key: TForeignKey;
ColNode: PVirtualNode;
Col: PTableColumn;
PCol: PTableColumn;
Col: TTableColumn;
Obj: TDBObject;
Columns: TTableColumnList;
begin
// Init grid editor in foreign key list
VT := Sender as TVirtualStringTree;
Expand All @@ -2293,8 +2300,8 @@ procedure TfrmTableEditor.listForeignKeysCreateEditor(
SetEditor := TSetEditorLink.Create(VT);
ColNode := listColumns.GetFirst;
while Assigned(ColNode) do begin
Col := listColumns.GetNodeData(ColNode);
SetEditor.ValueList.Add(Col.Name);
PCol := listColumns.GetNodeData(ColNode);
SetEditor.ValueList.Add(PCol.Name);
ColNode := listColumns.GetNextSibling(ColNode);
end;
EditLink := SetEditor;
Expand All @@ -2304,15 +2311,21 @@ procedure TfrmTableEditor.listForeignKeysCreateEditor(
EnumEditor.AllowCustomText := True;
DBObjects := DBObject.Connection.GetDBObjects(DBObject.Connection.Database);
for Obj in DBObjects do begin
if (Obj.NodeType = lntTable) and (LowerCase(Obj.Engine) = 'innodb') then
if (Obj.NodeType = lntTable) then
EnumEditor.ValueList.Add(Obj.Name);
end;
EditLink := EnumEditor;
end;
3: begin
Key := FForeignKeys[Node.Index];
SetEditor := TSetEditorLink.Create(VT);
SetEditor.ValueList := DBObject.Connection.GetCol('SHOW COLUMNS FROM '+DBObject.Connection.QuoteIdent(Key.ReferenceTable, True, '.'));
Obj := DBObject.Connection.FindObject(DBObject.Database, Key.ReferenceTable);
if Obj <> nil then begin
Columns := Obj.TableColumns;
for Col in Columns do begin
SetEditor.ValueList.Add(Col.Name);
end;
end;
EditLink := SetEditor;
end;
4, 5: begin
Expand Down

0 comments on commit 7ab47a3

Please sign in to comment.