Ver código fonte

Add compound foreign key/multicolumn foreign key support in script databases (complements commit 7a6cb086a0756abf36ea8ffdfc8215d87ff166a8)

Reinier Olislagers 11 anos atrás
pai
commit
15b5c28e66
3 arquivos alterados com 139 adições e 22 exclusões
  1. 3 3
      querywindow.pas
  2. 70 18
      scriptdb.pas
  3. 66 1
      systables.pas

+ 3 - 3
querywindow.pas

@@ -1967,7 +1967,7 @@ begin
 end;
 
 
-{ Run query, and fore its type as script }
+{ Run query, and force its type as script }
 
 procedure TfmQueryWindow.lmRunScriptClick(Sender: TObject);
 begin
@@ -2015,13 +2015,13 @@ begin
 end;
 
 
-{ Run query by pressing Ktrl + Enter }
+{ Run query by pressing Ctrl + Enter }
 
 procedure TfmQueryWindow.meQueryKeyDown(Sender: TObject; var Key: Word;
   Shift: TShiftState);
 begin
   // Execute query by pressing Ctrl + Enter
-  if (ssCtrl in shift) and (key = 13) then
+  if (ssCtrl in shift) and (key = VK_RETURN) then
   begin
     CallExecuteQuery(qtUnknown);
     key:= 0;

+ 70 - 18
scriptdb.pas

@@ -417,8 +417,14 @@ end;
 
 function ScriptAllConstraints(dbIndex: Integer; var List: TStringList): Boolean;
 var
-  Count: Integer;
-  i: Integer;
+  Count: integer;
+  ConstraintName: string;
+  CompoundClauseFK: string;
+  CompoundClauseRef: string;
+  CompoundConstraint: string;
+  CompoundCount: integer;
+  CompoundCounter: integer;
+  TableCounter: integer;
   TablesList: TStringList;
   Line: string;
 begin
@@ -426,7 +432,7 @@ begin
   try
     TablesList.CommaText:= dmSysTables.GetDBObjectNames(dbIndex, 1, Count);
     List.Clear;
-    for i:= 0 to TablesList.Count - 1 do
+    for TableCounter:= 0 to TablesList.Count - 1 do
     with dmSysTables do
     begin
       {to do: for each constraint that occurs multiple times add the fields in one line eg
@@ -435,23 +441,69 @@ begin
       alter table EMPLOYEE add constraint INTEG_29 foreign key (JOB_COUNTRY) references JOB (JOB_COUNTRY) ;
       should be 1 line
       }
-      GetTableConstraints(TablesList[i], sqQuery);
+      GetTableConstraints(TablesList[TableCounter], sqQuery);
+      CompoundConstraint:= '';
       while not sqQuery.EOF do
       begin
-        // We're using fieldbyname here instead of fields[x] because of maintainability and probably
-        // low performance impact.
-        // If performance is an issue, define field variables outside the loop and reference them instead
-        Line:= 'alter table ' + TablesList[i] +
-          ' add constraint ' + sqQuery.FieldByName('ConstName').AsString +
-          ' foreign key (' + sqQuery.FieldByName('CurrentFieldName').AsString +
-          ') references ' +  sqQuery.FieldByName('OtherTableName').AsString +
-          ' (' + sqQuery.FieldByName('OtherFieldName').AsString +
-          ')';
-        if Trim(sqQuery.FieldByName('UpdateRule').AsString) <> 'RESTRICT' then
-          Line:= Line + ' on update ' + Trim(sqQuery.FieldByName('UpdateRule').AsString);
-        if Trim(sqQuery.FieldByName('DeleteRule').AsString) <> 'RESTRICT' then
-          Line:= Line + ' on delete ' + Trim(sqQuery.FieldByName('DeleteRule').AsString);
-        List.Add(Line + ';');
+        ConstraintName:= sqQuery.FieldByName('ConstName').AsString;
+        CompoundCount:= GetCompoundFKConstraints(TablesList[TableCounter],ConstraintName);
+        if CompoundCount>0 then
+        begin
+          // Multiple columns form a compound foreign key index.
+          if ConstraintName<>CompoundConstraint then
+          begin
+            // A new contraint just started
+            CompoundConstraint:= ConstraintName;
+            CompoundCounter:= 1;
+            CompoundClauseFK:= sqQuery.FieldByName('CurrentFieldName').AsString+', ';
+            CompoundClauseRef:= sqQuery.FieldByName('OtherFieldName').AsString+', ';
+          end
+          else
+          begin
+            inc(CompoundCounter);
+            if CompoundCounter=CompoundCount then
+            begin
+              // Last record for this constraint, so write out
+              CompoundClauseFK:= CompoundClauseFK + sqQuery.FieldByName('CurrentFieldName').AsString;
+              CompoundClauseRef:= CompoundClauseRef + sqQuery.FieldByName('OtherFieldName').AsString;
+              Line:= 'alter table ' + TablesList[TableCounter] +
+                ' add constraint ' + ConstraintName +
+                ' foreign key (' + CompoundClauseFK +
+                ') references ' + sqQuery.FieldByName('OtherTableName').AsString +
+                ' (' + CompoundClauseRef +
+                ')';
+              if Trim(sqQuery.FieldByName('UpdateRule').AsString) <> 'RESTRICT' then
+                Line:= Line + ' on update ' + Trim(sqQuery.FieldByName('UpdateRule').AsString);
+              if Trim(sqQuery.FieldByName('DeleteRule').AsString) <> 'RESTRICT' then
+                Line:= Line + ' on delete ' + Trim(sqQuery.FieldByName('DeleteRule').AsString);
+              List.Add(Line + ';');
+            end
+            else
+            begin
+              // In middle of clause, so keep adding
+              CompoundClauseFK:= CompoundClauseFK + sqQuery.FieldByName('CurrentFieldName').AsString + ', ';
+              CompoundClauseRef:= CompoundClauseRef + sqQuery.FieldByName('OtherFieldName').AsString + ', ';
+            end;
+          end;
+        end
+        else
+        begin
+          // Normal, non-compound foreign key which we can write out based on one record in the query
+          // We're using fieldbyname here instead of fields[x] because of maintainability and probably
+          // low performance impact.
+          // If performance is an issue, define field variables outside the loop and reference them instead
+          Line:= 'alter table ' + TablesList[TableCounter] +
+            ' add constraint ' + ConstraintName +
+            ' foreign key (' + sqQuery.FieldByName('CurrentFieldName').AsString +
+            ') references ' + sqQuery.FieldByName('OtherTableName').AsString +
+            ' (' + sqQuery.FieldByName('OtherFieldName').AsString +
+            ')';
+          if Trim(sqQuery.FieldByName('UpdateRule').AsString) <> 'RESTRICT' then
+            Line:= Line + ' on update ' + Trim(sqQuery.FieldByName('UpdateRule').AsString);
+          if Trim(sqQuery.FieldByName('DeleteRule').AsString) <> 'RESTRICT' then
+            Line:= Line + ' on delete ' + Trim(sqQuery.FieldByName('DeleteRule').AsString);
+          List.Add(Line + ';');
+        end;
         sqQuery.Next;
       end;
       sqQuery.Close;

+ 66 - 1
systables.pas

@@ -32,6 +32,10 @@ type
 
     function GetAllConstraints(dbIndex: Integer; ConstraintsList, TablesList: TStringList): Boolean;
 
+    // Returns non-0 if foreign key constraint has a compound index (multiple fields)
+    // Returns 0 otherwise
+    function GetCompoundFKConstraints(TableName, ConstraintName: string): integer;
+
     function GetConstraintInfo(dbIndex: Integer; ATableName, ConstraintName: string; var KeyName,
         CurrentTableName, CurrentFieldName, OtherTableName, OtherFieldName, UpdateRule, DeleteRule: string): Boolean;
 
@@ -120,7 +124,8 @@ end;
 
 (*****  GetDBObjectNames, like Table names, Triggers, Generators, etc according to TVIndex  ****)
 
-function TdmSysTables.GetDBObjectNames(DatabaseIndex, TVIndex: Integer; var count: Integer): string;
+function TdmSysTables.GetDBObjectNames(DatabaseIndex, TVIndex: Integer;
+  var Count: Integer): string;
 begin
   Init(DatabaseIndex);
   sqQuery.Close;
@@ -276,6 +281,26 @@ begin
 // Note that this query differs from the way constraints are
 // presented in GetConstraintsOfTable.
 // to do: find out what the differences are and indicate better in code/comments
+{ Query sample for employee database:
+select trim(rc.rdb$constraint_name) as ConstName,
+trim(rfc.rdb$const_name_uq) as KeyName,
+trim(rc2.rdb$relation_name) as OtherTableName,
+trim(flds_pk.rdb$field_name) as OtherFieldName,
+trim(rc.rdb$relation_name) as CurrentTableName,
+trim(flds_fk.rdb$field_name) as CurrentFieldName,
+trim(rfc.rdb$update_rule) as UpdateRule,
+trim(rfc.rdb$delete_rule) as DeleteRule
+from rdb$relation_constraints AS rc
+inner join rdb$ref_constraints as rfc on (rc.rdb$constraint_name =
+rfc.rdb$constraint_name) inner join rdb$index_segments as flds_fk on (flds_fk.rdb$index_name = rc.rdb$index_name)
+inner join rdb$relation_constraints as rc2 on (rc2.rdb$constraint_name = rfc.rdb$const_name_uq)
+inner join rdb$index_segments as flds_pk on
+((flds_pk.rdb$index_name = rc2.rdb$index_name) and (flds_fk.rdb$field_position = flds_pk.rdb$field_position))
+where rc.rdb$constraint_type = 'FOREIGN KEY' and
+rc.rdb$relation_name = 'EMPLOYEE'
+order by rc.rdb$constraint_name,
+flds_fk.rdb$field_position
+}
   SQLQuery.SQL.Text:='select '+
     'trim(rc.rdb$constraint_name) as ConstName, '+
     'trim(rfc.rdb$const_name_uq) as KeyName, '+
@@ -385,6 +410,46 @@ begin
 
 end;
 
+function TdmSysTables.GetCompoundFKConstraints(TableName,
+  ConstraintName: string): integer;
+const
+  // For specified constraint, returns foreign key constraints and count
+  // if it has a compound key (i.e. multiple foreign key fields).
+  // Based on query in GetTableConstraints
+  CompoundCountSQL =
+   'select trim(rc.rdb$constraint_name) as ConstName, '+
+   'count(rfc.rdb$const_name_uq) as KeyCount '+
+   'from rdb$relation_constraints AS rc '+
+   'inner join rdb$ref_constraints as rfc on (rc.rdb$constraint_name = rfc.rdb$constraint_name) '+
+   'inner join rdb$index_segments as flds_fk on (flds_fk.rdb$index_name = rc.rdb$index_name) '+
+   'inner join rdb$relation_constraints as rc2 on (rc2.rdb$constraint_name = rfc.rdb$const_name_uq) '+
+   'inner join rdb$index_segments as flds_pk on '+
+   '((flds_pk.rdb$index_name = rc2.rdb$index_name) and (flds_fk.rdb$field_position = flds_pk.rdb$field_position)) '+
+   'where rc.rdb$constraint_type = ''FOREIGN KEY'' and '+
+   'upper(rc.rdb$relation_name) = ''%s'' '+
+   'group by rc.rdb$constraint_name '+
+   'having count(rfc.rdb$const_name_uq)>1 '+
+   'and rc.rdb$constraint_name=''%s'' '+
+   'order by rc.rdb$constraint_name ';
+var
+  CompoundQuery: TSQLQuery;
+begin
+  result:= 0;
+  CompoundQuery:=TSQLQuery.Create(nil);
+  try
+    CompoundQuery.DataBase:= ibcDatabase;
+    CompoundQuery.Transaction:= stTrans;
+    CompoundQuery.SQL.Text:=Format(CompoundCountSQL,[TableName,ConstraintName]);
+    CompoundQuery.Open;
+    if not(CompoundQuery.EOF) then
+      Result:= CompoundQuery.FieldByName('KeyCount').AsInteger;
+    CompoundQuery.Close;
+    //todo: check if this fits in with transaction management
+  finally
+    CompoundQuery.Free;
+  end;
+end;
+
 (**********  Get Constraint Info  ********************)
 
 function TdmSysTables.GetConstraintInfo(dbIndex: Integer; ATableName, ConstraintName: string; var KeyName,