|
[广告] Excel易用宝 - 提升Excel的操作效率 · Excel / WPS表格插件 ★ 免费下载 ★ ★ 使用帮助★
aman1516 发表于 2014-4-26 11:06
由此引出新问题:如何对增加新列动态设定列宽,而不是默认值?
以17楼附件代码为基础,个人思路:
代 ...
以下代码以工作表各列列宽做为列表框列宽的参照:
Private Sub TextBox1_Change()
Dim i%, j%, c As Long, s$, w0$, w$, wrr, arr, brr
For i = 1 To Cells(1, Cells.Columns.Count).End(xlToLeft).Column - 1
w0 = w0 & Columns(i).ColumnWidth * 5 & ";"
Next
w0 = Left(w0, Len(w0) - 1)
wrr = Split(w0, ";")
If TextBox1.Text = "" Then ListBox1.Clear: Exit Sub
For i = 1 To Cells(1, Cells.Columns.Count).End(xlToLeft).Column - 1
If InStr(TextBox1.Text, Cells(1, i).Value) > 0 Then
s = s & ":" & i
w = w & Val(wrr(i - 1)) & ";"
End If
Next i
If s <> "" Then
s = Right(s, Len(s) - 1)
Else
For i = 1 To Cells(1, Cells.Columns.Count).End(xlToLeft).Column - 1
If InStr(Cells(1, i).Value, TextBox1.Text) > 0 Then s = i: w = Val(wrr(i - 1)): Exit For
Next i
End If
arr = Split(s, ":")
ReDim brr(1 To Cells(Cells.Rows.Count, 1).End(xlUp).Row, 1 To UBound(arr) + 1)
For i = 1 To Cells(Cells.Rows.Count, 1).End(xlUp).Row
For j = 1 To UBound(arr) + 1
brr(i, j) = Cells(i, Val(arr(j - 1))).Value
Next j
Next i
With Me.ListBox1
.ColumnCount = UBound(arr) + 1
.ColumnWidths = w
.List = brr
End With
End Sub
|
评分
-
1
查看全部评分
-
|