名称的高级操作 (下面的内容整理自Chip Pearson的文章) [增大名称框的尺寸] 在Excel工作表的名称框中(如图1所示),大约只能显示16个字符,当超过它所能容纳的字符时,后面的字符将会被截取,将不能看到完整的名称,这对前面的字符相同而区别在最后几个字符的名称来说,很不方便,但是在Excel中没有改变名称框尺寸的设置。这可通过调用Windows API来解决,通过调用API来增加下拉框的宽度。 在VBE编辑器中插入一个标准模块,并输入以下的代码: Public Declare Function FindWindow Lib "user32" Alias "FindWindowA" _ (ByVal lpClassName As String, ByVal lpWindowName As String) As Long Public Declare Function FindWindowEx Lib "user32" Alias "FindWindowExA" _ (ByVal hWnd1 As Long, ByVal hWnd2 As Long, _ ByVal lpsz1 As String, ByVal lpsz2 As String) As Long Public Declare Function SendMessage Lib "user32" Alias "SendMessageA" _ (ByVal hwnd As Long, ByVal wMsg As Long, _ ByVal wParam As Long, lParam As Any) As Long ‘- - - - - - - - - - - - - - - - - - - - - - - - - Sub WidenNameBoxDrop2() Dim Res As Long Const CB_SETDROPPEDWIDTH = &H160 Const cWidth = 400 '<<<<<<<<<<<<<<<<<<<<<< Res = SendMessage( _ FindWindowEx( _ FindWindowEx( _ FindWindow("XLMAIN", Application.Caption) _ , 0, "EXCEL;", vbNullString) _ , 0, "combobox", vbNullString), _ CB_SETDROPPEDWIDTH, cWidth, 0) End Sub 示例说明:上述代码运行前后的结果如图3和图4所示。在上面的代码中,可以通过改变常量cWidth(<<<所示的代码行)的值来定义下拉框的宽度。 图3:原名称框 图4:修改后的名称框
[为名称框定义快捷键] Excel提供的快捷键中没有名称框的快捷键。但是,您能使用VBA代码设置快捷键,以方便能快速定位到名称框。 在VBE编辑器中,插入一个标准模块,并输入以下代码: Public Declare Function SetFocus Lib "user32" (ByVal hwnd As Long) As Long Public Declare Function FindWindow Lib "user32" Alias "FindWindowA" _ (ByVal lpClassName As String, ByVal lpWindowName As String) As Long Public Declare Function FindWindowEx Lib "user32" Alias "FindWindowExA" _ (ByVal hWnd1 As Long, ByVal hWnd2 As Long, _ ByVal lpsz1 As String, ByVal lpsz2 As String) As Long ‘- - - - - - - - - - - - - - - - - - - - - - - - - Sub SetFocusNameBox() Dim Res As Long Res = SetFocus( _ FindWindowEx( _ FindWindowEx( _ FindWindow("XLMAIN", Application.Caption) _ , 0, "EXCEL;", vbNullString) _ , 0, "combobox", vbNullString)) End Sub 在Excel中,选择菜单“工具——宏——宏”命令,调出“宏”对话框,为刚创建的SetFocusNameBox代码指定快捷键,如Ctrl+Shift+N。那么,以后在该工作簿中,按下Ctrl+Shift+N组合键,即可定位到名称对话框。By fanjy in 2006-11-16
|