XL97: Problem Using Sort Method with More Than One KeyID: Q229107
|
When you attempt to programmatically sort a range using more than one key, all but the first sort key is ignored. This problem occurs when you call the Sort method using positional arguments, which is common with automation. The problem does not occur if you used named arguments.
According to the Excel type library and the Excel VBA Help file, the Sort method has the following syntax:
Sort ([Key1], [Order1], [Key2], [Type], [Order2], [Key3], [Order3],
[Header], [OrderCustom], [MatchCase], [Orientation], [SortMethod])
The documentation is incorrect: the Key2 and Type arguments are reversed.
Sort ([Key1], [Order1], [Type], [Key2], [Order2], [Key3], [Order3],
[Header], [OrderCustom], [MatchCase], [Orientation], [SortMethod])
To correct this problem, you can:
This bug was corrected in Microsoft Excel 2000.
Letter Number
A 8
B 5
A 6
B 1
B 10
Sub Test()
Range("A1:B6").Sort Range("A1"), , Range("B1"), , , , , xlYes
End Sub
Range("A1:B6").Sort Key1:=Range("A1"), Key2:=Range("B1"), Header:=xlYes
or you can change the order of the arguments:
Range("A1:B6").Sort Range("A1"), , , Range("B1"), , , , xlYes
The data will then sort correctly:
Letter Number
A 6
A 8
B 1
B 5
B 10
Additional query words: XL97 Automation OLE
Keywords : kbdta kbdtacode xlvbainfo kbExcel kbGrpDSO
Version : WINDOWS:97
Platform : WINDOWS
Issue type : kbbug
Last Reviewed: July 20, 1999