Using drop down list to populate cells

ExcelBeginner34

New Member
Joined
Mar 2, 2019
Messages
41
Office Version
  1. 2016
Platform
  1. Windows
A
B
C
D

E
F
G
H
I
Tenant Name
Recovery Restrictions (Drop Down List)
Amount
Total Budget
Max Recovery
Annual Charge To Tenant
Annul Charge To Landlord
Quartely Tenant
Qaurterly Landlord
Tenant A
E.g Void
100
100
£100
£25
Tenant B
E.g Rent inclusive
200
200
£200
£50
Tenant C

None
300
300
£300
£75


<tbody>
</tbody>
Hi, I have a sheet in which I have created a drop down list. This contains 4 options Void, Rent Inclusive, Cap/Lease Defect and None. How am I able to set the sheet up so that when the user selects one of these options it automatically populates a cell in the table with a figure copied from another cell? And then if they change the drop down list option it goes back to say blank again?

My table looks like the above. So what I want is to be able to select each of the drop down list options (they will be the same for all col B) and for this to have the following result:

Void - insert the Total Budget Figure (£100) into the Annual Charge to Landlord cell and then in the Quarterly cell show the amount reflecting 25% I,e 25.
Rent inclusive - the same as void above.
None - as per void above but this time populating the Annual Charge to Tenant cell and then the Quarterly figure.
Cap/Lease Defect - no action required.

I have shown as an example in the table how the above would look.

Hope you can help.

Best regards

Iain
 
Try:
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Intersect(Target, Range("E:E,AD:AD")) Is Nothing Then Exit Sub
    Application.EnableEvents = False
    On Error GoTo errHandler
    If Target.Column = 5 Then
        Select Case Target.Value
            Case "Void", "Rent Inclusive"
                Cells(Target.Row, 30).Resize(1, 5).ClearContents
                Target.Offset(0, 27) = Target.Offset(0, 24)
                Target.Offset(0, 29) = Target.Offset(0, 24) * 0.25
            Case "None"
                Cells(Target.Row, 30).Resize(1, 5).ClearContents
                Target.Offset(0, 26) = Target.Offset(0, 24)
                Target.Offset(0, 28) = Target.Offset(0, 24) * 0.25
            Case "Select"
                Cells(Target.Row, 30).Resize(1, 5).ClearContents
            Case "Cap/Lease Defect"
                Target.Offset(0, 27) = Target.Offset(0, 24)
                Target.Offset(0, 29) = Target.Offset(0, 24) * 0.25
        End Select
    ElseIf Target.Column = 30 Then
        If Range("E" & Target.Row) = "Cap/Lease Defect" Then
            Target.Offset(0, 1) = Target
            Target.Offset(0, 2) = Target.Offset(0, -1) - Target
            Target.Offset(0, 3) = Target * 0.25
            Target.Offset(0, 4) = Target.Offset(0, 2) * 0.25
        End If
    End If
errHandler:
    Application.EnableEvents = True
End Sub
 
Upvote 0

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
That's it - working perfectly. Thanks so much for your help. I would never have been able to do this myself. How did you learn the coding? Did you use if professionally? I am thinking about buying a beginners book and learning myself.
 
Upvote 0

Forum statistics

Threads
1,213,494
Messages
6,113,974
Members
448,537
Latest member
Et_Cetera

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