![]() |
why does userform close after programming worksheet event with CreateEventProc or AddFromString
THE CODE:
ThisWorkbook -- Private Sub Workbook_Open() UserForm1.Show End Sub UserForm1 -- Private Sub CommandButton1_Click() Module1.DoStuff End Sub Module1 -- Public Sub DoStuff() Dim VBProj As VBProject Dim VBComp As VBComponent Dim VBCodeMod As CodeModule Dim StartLine As Long Dim testCodeString As String Application.ScreenUpdating = False ''Add a new worksheet to the workbook Worksheets.Add ''rename the worksheet per the user's textbox input value ActiveSheet.name = UserForm1.TextBox1.Value ''write event for the new worksheet Set VBProj = ThisWorkbook.VBProject For Each VBComp In VBProj.VBComponents If VBComp.Type = vbext_ct_Document Then If (VBComp.Properties("Name").Value = ActiveSheet.name) Then Set VBCodeMod = VBComp.CodeModule ' ''-------------------------------------------------------------------------------------- ' ''METHOD 1: Use .CreateEventProc ' ''-------------------------------------------------------------------------------------- ' ''create Worksheet_SelectionChagne event ' With VBCodeMod ' StartLine = .CreateEventProc("SelectionChange", "WorkSheet") + 1 ' .InsertLines StartLine, _ ' " ''test line - comment 1" & vbCr & _ ' End With ' ' ''create Worksheet_Calculate event ' With VBCodeMod 'ActiveWorkbook.VBProject.VBComponents(ActiveSheet .CodeName).CodeModule ' StartLine = .CreateEventProc("Calculate", "Worksheet") + 1 ' .InsertLines StartLine, _ ' " ''test line - comment 1" & vbCr & _ ' " ''test line - comment 2" & vbCr & _ ' " 'UserForm1.Show vbModeless" ' End With ' ''--END METHOD 1 CODE------------------------------------------------------------------- ''-------------------------------------------------------------------------------------- '' METHOD 2: Use .AddFromString ''-------------------------------------------------------------------------------------- testCodeString = _ "Public Sub Worksheet_Calculate()" & vbCr & _ " ''test line - comment 1" & vbCr & _ "End Sub" VBCodeMod.AddFromString testCodeString ''--END METHOD 2 CODE------------------------------------------------------------------- End If End If Next Application.ScreenUpdating = True End Sub ** THE END ** ...no other code required. If anyone has trouble getting this to run, please let me know. Thanks again for any help I can get. Troy |
why does userform close after programming worksheet event with CreateEventProc or AddFromString
Hello I hope this helps you Public Sub DoStuff() Dim VBProj As VBProject Dim VBComp As VBComponent Dim VBCodeMod As CodeModule Dim StartLine As Long Dim testCodeString As String Application.ScreenUpdating = False If UserForm1.TextBox1.Value = "" Then Exit Sub ''Add a new worksheet to the workbook Worksheets.Add ''rename the worksheet per the user's textbox input value ActiveSheet.Name = UserForm1.TextBox1.Value ''write event for the new worksheet Set VBProj = ThisWorkbook.VBProject Set VBComp = VBProj.VBComponents(ActiveSheet.CodeName) Set VBCodeMod = VBComp.CodeModule With VBCodeMod StartLine = .CreateEventProc("SelectionChange", "WorkSheet") + 1 ..InsertLines StartLine, _ " ''test line - comment 1" & vbCr End With With VBCodeMod StartLine = .CreateEventProc("Calculate", "Worksheet") + 1 ..InsertLines StartLine, _ " ''test line - comment 1" & vbCr & _ " ''test line - comment 2" & vbCr & _ " 'UserForm1.Show vbModeless" End With Set VBProj = Nothing Set VBComp = Nothing Set VBCodeMod = Nothing Application.ScreenUpdating = True Application.VBE.MainWindow.Visible = False 'UserForm1.TextBox1.SetFocus End Sub Regards, michel -- michelxld ------------------------------------------------------------------------ michelxld's Profile: http://www.excelforum.com/member.php...o&userid=17367 View this thread: http://www.excelforum.com/showthread...hreadid=508333 |
why does userform close after programming worksheet event with CreateEventProc or AddFromString
Thanks to everyone who replied here and sent emails. I finally got it
all figured out and just wanted to post the result to help others who might have a similar problem. First the code, then the explanation. THE CODE: Public Sub DoStuff() Dim VBProj As VBProject Dim VBComp As VBComponent Dim VBCodeMod As CodeModule Dim StartLine As Long Dim testCodeString As String Application.ScreenUpdating = False ''add a new (temporary) workbook Workbooks.Add ''rename the activesheet per the user's textbox input value ActiveSheet.Name = UserForm1.TextBox1.Value ''write event for the new worksheet Set VBProj = ActiveWorkbook.VBProject For Each VBComp In VBProj.VBComponents If VBComp.Type = vbext_ct_Document Then If (VBComp.Properties("Name").Value = ActiveSheet.Name) Then Set VBCodeMod = VBComp.CodeModule ''-------------------------------------------------------- '' METHOD 2: Use .AddFromString ''-------------------------------------------------------- testCodeString = _ "Public Sub Worksheet_Calculate()" & vbCr & _ " Dim prompt As String" & vbCr & vbCr & _ " ''test line - comment 1" & vbCr & _ " prompt = ""RUNNING: Worksheet_Calculate""" & vbCr & _ " MsgBox prompt" & vbCr & _ "End Sub" VBCodeMod.AddFromString testCodeString ''--END METHOD 2 CODE------------------------------------- End If End If Next ''move the new sheet with event code to the other workbook Sheets(1).Move Befo=Workbooks("TestWorkbook.xls").Sheets(1) ''activate and close/delete the previously added (temporary) workbook Workbooks(Workbooks.Count).Activate ActiveWorkbook.Close (False) Application.ScreenUpdating = True End Sub THE EXPLANATION: I got this idea from another post where the post-er mentioned being able to write code to a worksheet in a different workbook, but not the workbook running the userform. So, I decided to try creating a temporary workbook, writing the Worksheet event code in a sheet in the new workbook and then just moving the worksheet to the old workbook. This worked...Now, the original workbook contains a new sheet (named by the user), the new sheet contains the appropriate event code, and the userform stays open - ready for another user input (worksheet name). If anyone would like to chat about this further, please email me since i'll probably stop watching this thread. Happy programming... Troy |
All times are GMT +1. The time now is 02:02 PM. |
Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
ExcelBanter.com