|
[广告] VBA代码宝 - VBA编程加强工具 · VBA代码随查随用 · 内置多项VBA编程加强工具 ★ 免费下载 ★ ★ 使用手册★
使用EXCEL的VBA编程时,经常会用到数组,有时需要对数组进行排序,在这里介绍一下数字数组排序的常用方法以及带有EXCEL特色的函数排序方法(所举例子均以升序排列数组)。
在介绍具体方法之前,先给个数组生成过程。(将数组a(1 to 50)定义成公用数组)
Sub MakeArr()
For i = 1 To 50
a(i) = Int(Rnd(1) * 890 + 10)
Next i
End Sub
1、快速排序法
Sub FastSort()
M = 1
For i = 1 To 49
If a(i) <= a(i + 1) Then
If i > M Then
M = i
Else
i = M
End If
GoTo kk:
Else
x = a(i)
a(i) = a(i + 1)
a(i + 1) = x
If i <> 1 Then i = i - 2
End If
kk:
Next i
End Sub
2、冒泡排序法
Sub BubbleSort()
For i = 1 To 49
For j = i + 1 To 50
If a(i) > a(j) Then
TEMP = a(j)
a(j) = a(i)
a(i) = TEMP
End If
Next j
Next i
End Sub
3、桶排序法
Sub Bucket()
Dim Index
Dim tempnum
For i = 2 To 50
tempnum = a(i)
Index = i
Do
If Index > 1 Then
If tempnum < a(Index - 1) Then
a(Index) = a(Index - 1)
Index = Index - 1
Else
Exit Do
End If
Else
Exit Do
End If
Loop
a(Index) = tempnum
Next
End Sub
4、希尔排序法
Sub ShellSort()
Dim skipnum
Dim Index
Dim i
Dim tempnum
Size = 50
skipnum = Int((Size / 2)) - 1
Do While skipnum > 0
i = 1 + skipnum
For j = i To 50
Index = j
Do
If Index >= (1 + skipnum) Then
If a(Index) < a(Index - skipnum) Then
tempnum = a(Index)
a(Index) = a(Index - skipnum)
a(Index - skipnum) = tempnum
Index = Index - skipnum
Else
Exit Do
End If
Else
Exit Do
End If
Loop
Next
skipnum = (skipnum - 1) / 2
Loop
End Sub
5、选择排序法
Sub SelectionSort()
Dim Index
Dim Min
Dim i
Dim tempnum
BzArr
i = 1
While (i < 50)
Min = 50
Index = Min - 1
While (Index >= i)
If a(Index) < a(Min) Then
Min = Index
End If
Index = Index - 1
Wend
tempnum = a(Min)
a(Min) = a(i)
a(i) = tempnum
i = i + 1
Wend
End Sub
以上五种排序方法均是数组排序的常用方法,优点是不需借助辅助单元格。执行效率视数组成员的相对有序性的不同而不同。以附件中的50位一维数组为例,快速排序法的循环次数是745次、冒泡法的循环次数是1225次、桶排序法的循环次数是704次、希尔排序法的循环次数是347次、选择排序法的循环次数为1225次。
下面再介绍两种用EXCEL函数的排序方法,一般来说使用EXCEL自带函数或方法的执行效率会高一些,但限于函数参数的限制有的不得不借助于辅助单元格。
6、SMALL函数法
Sub SmallSort()
Dim b(1 To 50)
For i = 1 To 50
b(i) = Application.WorksheetFunction.Small(a, i)
Next
End Sub
原数组不变,生成一个新的按升序排列的数组。
同理也可以用LARGE函数。我个人觉得用这种方法较快。
7、RANK函数法
Sub RankSort()
BzArr
Dim b(1 To 50)
For i = 1 To 50
Sheet2.Cells(i, 1) = a(i)
Next
Set rankrange = Sheet2.Range("a1:a50")
For i = 1 To 50
For k = 0 To Application.WorksheetFunction.CountIf(rankrange, Sheet2.Cells(i, 1)) - 1
j = Application.WorksheetFunction.Rank(Sheet2.Cells(i, 1), rankrange, 1)
a(j + k) = Sheet2.Cells(i, 1)
Next
Next
For i = 1 To 50
Sheet1.Cells(i + 2, 7) = a(i)
Next
End Sub
此方法的缺点是需要借助辅助单元格。 |
评分
-
7
查看全部评分
-
|