+ Reply to Thread
Results 1 to 6 of 6

Run-time error 7 out of memory vba

Hybrid View

  1. #1
    Registered User
    Join Date
    08-17-2012
    Location
    Serbia
    MS-Off Ver
    Excel 2010
    Posts
    85

    Run-time error 7 out of memory vba

    This is my first post here and second day trying to use VBA to solve some problems/shortcuts in Excel (I'm learning by trial and error).
    Using macros and help from this forum I was able to sort some code that I was happy with.
    Problem is when I use second macro (that I found on the net-which is working in blank workbook) I get "Run-time error 7 out of memory"
    in first macro which I am not using at the time.

    The problem is in the third line "If Target.Column = 20 And Target.Value = "B" Then"

    Private Sub Workbook_SheetChange(ByVal Sh As Object, ByVal Target As Range)
       
    With Sh
    If Target.Column = 20 And Target.Value = "B" Then
        'ThisRow = Target.Column
        'If Target.Value = "B" Then
        ActiveCell.Offset(-1, -7).Select
        Selection.Copy
        ActiveCell.Offset(0, -3).Select
        Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
            :=False, Transpose:=False
        ActiveCell.Offset(0, 1).Select
        ActiveCell.FormulaR1C1 = "=TODAY()"
        'Range("B25").Select
        Selection.NumberFormat = "dd.mm.yyyy."
        Selection.Copy
        Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
            :=False, Transpose:=False
        Application.CutCopyMode = False
        ActiveCell.Offset(0, -9).Select
        Selection.Style = "In Position"
        Else
    If Target.Column = 20 And Target.Value = "S" Then
    ActiveCell.Offset(-1, -7).Select
        Selection.Copy
        ActiveCell.Offset(0, 8).Select
        Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
            :=False, Transpose:=False
        ActiveCell.Offset(0, 1).Select
        ActiveCell.FormulaR1C1 = "=TODAY()"
        'Range("B25").Select
        Selection.NumberFormat = "dd.mm.yyyy."
        Selection.Copy
        Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
            :=False, Transpose:=False
        Application.CutCopyMode = False
        ActiveCell.Offset(0, -20).Select
        ActiveCell.Resize(, 11).Select
        Selection.Style = "Disabled"
        Else
        If Target.Column = 20 And Target.Value = "W" Then
        ActiveCell.Offset(-1, -18).Select
        Selection.Style = "Waiting"
        End If
        End If
    End If
    End With
    End Sub
    Thanks for help in advance.
    Last edited by Jovica; 08-19-2012 at 09:09 AM.

  2. #2
    Forum Moderator - RIP Richard Buttrey's Avatar
    Join Date
    01-14-2008
    Location
    Stockton Heath, Cheshire, UK
    MS-Off Ver
    Office 365, Excel for Windows 2010 & Excel for Mac
    Posts
    29,464

    Re: Run-time error 7 out of memory vba

    Hi,

    How big is the file?
    Have you got any other applications or Excel workbooks open at the same time? If so close them all and see if that helps.
    Is there only one version of Excel open?
    Richard Buttrey

    RIP - d. 06/10/2022

    If any of the responses have helped then please consider rating them by clicking the small star icon below the post.

  3. #3
    Registered User
    Join Date
    08-17-2012
    Location
    Serbia
    MS-Off Ver
    Excel 2010
    Posts
    85

    Re: Run-time error 7 out of memory vba

    I've read that help file, tried everything and nothing...same problem.File size is 353kb.
    Code that I put in previous message (let's say Code1) is working until I start another macro (Code2) in the same Excel file.
    Code1 should perform 2-3 operations whenever I put one of 3 letters (B, S or W) into certain column.
    Code2 (that I borrowed from another site) is retrieving financial data into blank sheet.
    Both macros are working but not together, main problem is when I start Code2, the error message appears in Code1.

    Here is Code2 even though nobody had any problem with it:
    Sub GetFinvizData()
    
    Dim str As String
    
    'Delete existing data
    Sheets("Data").Activate 'Name of sheet the data will be downloaded into. Change as required.
    Range("A1").Select
    Range(Selection, Selection.End(xlToRight)).Select
    Range(Selection, Selection.End(xlDown)).Select
    Selection.ClearContents
    
    'Download stock quotes. Be patient - takes a few seconds.
    str = "http://finviz.com/export.ashx?v=151&c=1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68"
    QueryQuote:
                With Sheets("Data").QueryTables.Add(Connection:="URL;" & str, Destination:=Sheets("Data").Range("A1"))
                    .BackgroundQuery = True
                    .TablesOnlyFromHTML = False
                    .Refresh BackgroundQuery:=False
                    .SaveData = True
                End With
    
    Sheets("Data").Range("A1").CurrentRegion.TextToColumns Destination:=Sheets("Data").Range("A1"), DataType:=xlDelimited, _
    TextQualifier:=xlDoubleQuote, ConsecutiveDelimiter:=False, Tab:=False, _
    Semicolon:=False, Comma:=True, Space:=False, other:=True, OtherChar:=",", FieldInfo:=Array(1, 2)
           
    Sheets("Data").Columns("A").ColumnWidth = 10
    Sheets("Data").Columns("B").ColumnWidth = 43
    Sheets("Data").Columns("C").ColumnWidth = 18
    Sheets("Data").Columns("D").ColumnWidth = 32
    Sheets("Data").Columns("E:BP").ColumnWidth = 10
    Range("A1").Select
    
    End Sub

  4. #4
    Forum Moderator - RIP Richard Buttrey's Avatar
    Join Date
    01-14-2008
    Location
    Stockton Heath, Cheshire, UK
    MS-Off Ver
    Office 365, Excel for Windows 2010 & Excel for Mac
    Posts
    29,464

    Re: Run-time error 7 out of memory vba

    Hi,

    In the absence of the workbook we'll have to guess.

    It may be that the action of code 2 is firing the code 1 macro many times. i.e. every time the many code 2 instructions change the Data sheet.
    What happens if you start the code 2 macro with the instruction
    Application.EnableEvents = False
    and finish it with
    Application.EnableEvents = True

    Why are you using the Workbook Sheet Change event? Are you really wanting it to fire whenever anything is changed anywhere?
    If you use it on a sheet other than the Data Sheet used by code 2, use the Worksheet Change event instead.

  5. #5
    Forum Guru
    Join Date
    03-02-2006
    Location
    Los Angeles, Ca
    MS-Off Ver
    WinXP/MSO2007;Win10/MSO2016
    Posts
    12,960

    Re: Run-time error 7 out of memory vba

    Part of your problem is that you are using a workbook.sheetchange event. So, when a change is made in any cell in any sheet the event is triggered. Your second macro is changing some sheet and, therefore calling the sheetchange event code. The sheetchange event code is making further changes and, thus calling itself: the changes are calling changes that are calling changes... until you run out of memory.
    You need to turn off event handling while the code is modifying the sheets:

    Sub GetFinvizData()
         Application.EnableEvents = False
    ...
    
         Application.EnableEvents = True
    End Sub
    and:
    Private Sub Workbook_SheetChange(ByVal Sh As Object, ByVal Target As Range)
    
    '  ** Check if in Column 20 and exit if not, else turn off event handling and carry on **
    
         If Target.Column <> 20 Then Exit Sub
         Application.EnableEvents = False
    
    ' ------------------- use select case instead of If..Then's
    
         Select Case Target.Value
              Case Is = "B"
                  {do  "B" stuff}
              Case Is = "S"
                  {do "S" stuff}
              Case Is = "W"
                  {do "W" stuff"}
         End Select
         Application.EnableEvents = True
    End Sub
    Ben Van Johnson

  6. #6
    Registered User
    Join Date
    08-17-2012
    Location
    Serbia
    MS-Off Ver
    Excel 2010
    Posts
    85

    Re: Run-time error 7 out of memory vba

    Thanks you guys. @protonLeah I've tried both corrections and it worked, thank you so much.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1