VBA Code to Retrieve Default Values for Empty Cells

FracinDean

Board Regular
Joined
Jul 11, 2011
Messages
110
Office Version
  1. 365
Platform
  1. Windows
My objective is to use the Worksheet_Change event to test if any cells requiring a value have been cleared, and then to retrieve the default values and put them in the cell. All the cells requiring a value have a named range, and all the default named ranges are the same, except with the letters "Df" appended on them. Example, a named range "Item1" has its default value in a range named "Item1Df". All of my named ranges have scope = "Workbook". I am getting a range object failure, 1004, in the line marked "Error occurs here".
Code:
    If Not Intersect(Target, Range("cellsWithDefaultValues")) Is Nothing Then
        If Target.Value = "" Then
            Dim targetName As Variant
            targetName = Target.Name.Name
            MsgBox (targetName & "Df")   'Everything is okay up to here 
            MsgBox Range(targetName & "Df").Value          'Error 1004 occurs here
            Target.Value = Range(targetName & "Df").Value  'This is what I eventually want to do
        End If
    End If
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
Code:
MsgBox Range(targetName & "Df").Value

If I understand correctly, Your ranges are name Item1, Item2, etc. The default values are then Item1Df, Item2Df...
The code statement above is trying to use the default range value as a range name and is therefore thowing the error. Remove the & Df and it will give youe the range value in the message box.
 
Upvote 0
Code:
If Not Intersect(Target, Range("cellsWithDefaultValues")) Is Nothing Then
        If Target.Value = "" Then
            Target.Value = Target.Name.Name  & "Df"
        End If
End If

This might work
 
Last edited:
Upvote 0
Try this

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    
    If Not Intersect(Target, Range("cellsWithDefaultValues")) Is Nothing Then
        If Target.Count > 1 Then Exit Sub
        If Target.Value = "" Then
            Dim targetName As Variant
            Target.Select
            targetName = Selection.Name.Name
            Application.EnableEvents = False
            Target.Value = Range(targetName & "Df").Value  'This is what I eventually want to do
            Application.EnableEvents = True
        End If
    End If
End Sub
 
Upvote 0
Solution
I eventually got this to work, but not quite in the way I was hoping. There is a key fact that I forgot to mention. The ranges with the default values are on a different worksheet. I think this is creating some sort of issue with referencing values from other sheets within the worksheet event code. I tried adding the worksheet name into the range command, checked that my ranges were "Workbook" in scope (they were), but the only way I could get this to work was by moving my default value ranges onto the same worksheet. My code is below but I'm sure some of the options you gave are fine too.

Code:
    Dim defaultTargetName As Variant
    If Not Intersect(Target, Range("cellsWithDefaultValues")) Is Nothing Then
        If Len(Target.Value) = 0 Then
            defaultTargetName = Target.Name.Name & "Df"
            Target.Value = Range(defaultTargetName).Value
        End If
    End If
 
Upvote 0
I guess I am not clear on what your named ranges are actually named. This line of code would most likely throw an error if the ranges are named as you previosly described.

Code:
Target.Value = Range(defaultTargetName).Value
Let's say the Tasget is in named range 'Item1' and that range is blank. then if you want to put the string value of "Item1Df" in that cell it would be
Code:
Target = Target.Name.Name & "Df"
to yield a value of "Item1Df"

If you are trying to re-name the range, then it requires different code altogether.
 
Last edited:
Upvote 0
I agree with Mr Whiz :)

Code:
Dim defaultTargetName As Variant
    If Not Intersect(Target, Range("cellsWithDefaultValues")) Is Nothing Then
        If Len(Target.Value) = 0 Then
            defaultTargetName = Target.Name.Name & "Df"
            [COLOR=#ff0000]Target.Value = defaultTargetName [/COLOR]
        End If
    End If
 
Upvote 0
Mr Jeffrey and Mr JLGWhiz, I think the problem is that I didn't explain very well what I want to do.

I am not trying to rename ranges. I'm just reading ranges and sometimes replacing empty values with default ones. I have two different sets of ranges with matching names, except range 2 has "Df" appended to each range name from the first range.

First group of ranges: Item1, Item2, … , ItemN (collectively these ranges have a range name "cellsWithDefaultValues")

Second group of ranges: Item1Df, Item2Df, … , ItemNDf

The algorithm that I want to do is this:

1. Use a sheet change event and test that the item is empty AND is a member of the first set of ranges.
2. If 1 is true, then retrieve the default value "ItemXDf" and set that as the new value for "ItemX".

The code I gave above is working.

Thanks.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,246
Members
452,623
Latest member
cliftonhandyman

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top