Same Data (date) Validation List for 2 cells; 1 cells to be greater than other cell

JackDanIce

Well-known Member
Joined
Feb 3, 2010
Messages
9,922
Office Version
  1. 365
Platform
  1. Windows
Hi,

I have a named range [Range_Date] filled with dates Jan 2019 - Dec 2020, incrementing monthly.

On another sheet I have two cells with data validation for list with values [Range_Date], where one is the start date and other end date.

Is there a way to set data validation to ensure end date greater than start date as well as include drop down list?

TIA,
Jack
 

Excel Facts

Can a formula spear through sheets?
Use =SUM(January:December!E7) to sum E7 on all of the sheets from January through December
In this scenario...
Range_Date is on Sheet1 and is the Data Validation list for Sheet2 A1
Range_Date2 is on Sheet1 and is the Data Validation list for Sheet2 A2

To start, Range_Date and Range_Date2 can be the same list. The code will change Range_Date2.

To install the code below:
- Right-click on the sheet tab that has the DropDown lists (Sheet2)
- Select View Code from the pop-up context menu
- Paste the code from below in the Worksheet's code module
- Change the Sheet names and Data Validation cell addresses to suit

Code:
[color=darkblue]Private[/color] [color=darkblue]Sub[/color] Worksheet_Change([color=darkblue]ByVal[/color] Target [color=darkblue]As[/color] Range)
    [color=darkblue]Dim[/color] x [color=darkblue]As[/color] [color=darkblue]Variant[/color]
    [color=darkblue]If[/color] Target.Address(0, 0) = [B]"A1"[/B] [color=darkblue]Then[/color]
        Range("A2").Value = ""
        [color=darkblue]If[/color] Target <> [color=darkblue]Empty[/color] [color=darkblue]Then[/color]
            [color=darkblue]With[/color] [B]Sheets("Sheet1")[/B].Range("Range_Date")
                x = Application.Match(Target, .Cells, 0)
                [color=darkblue]If[/color] x < .Count [color=darkblue]Then[/color]
                    ThisWorkbook.Names.Add Name:="Range_Date2", RefersToR1C1:=.Cells(x + 1).Resize(.Count - x)
                [color=darkblue]Else[/color]
                    ThisWorkbook.Names.Add Name:="Range_Date2", RefersToR1C1:=""
                [color=darkblue]End[/color] [color=darkblue]If[/color]
            [color=darkblue]End[/color] [color=darkblue]With[/color]
        [color=darkblue]End[/color] [color=darkblue]If[/color]
    [color=darkblue]End[/color] [color=darkblue]If[/color]
End [color=darkblue]Sub[/color]
 
Upvote 0
Would this be any use?
I have my Start Date Validation cell as A1 on Sheet2 and End Date DV cell as A2 on Sheet2.

On Sheet 1 I have the list of dates in A1:A24 & formulas as shown, copied down.

Excel Workbook
ABC
1Jan-19Jan-19 
2Feb-19Feb-19
3Mar-19Mar-19
4Apr-19Apr-19
5May-19May-19
6Jun-19Jun-19
7Jul-19Jul-19
8Aug-19Aug-19
9Sep-19Sep-19
10Oct-19Oct-19
11Nov-19Nov-19
12Dec-19Dec-19
13Jan-20Jan-20Jan-20
14Feb-20Feb-20Feb-20
15Mar-20Mar-20Mar-20
16Apr-20Apr-20Apr-20
17May-20May-20
18Jun-20Jun-20
19Jul-20Jul-20
20Aug-20Aug-20
21Sep-20Sep-20
22Oct-20Oct-20
23Nov-20Nov-20
24Dec-20Dec-20
Sheet1



I have then created 2 new named ranges (via the name manager on the Formulas ribbon tab) & used those in my data validation as shown.


Excel Workbook
AB
1Dec-19Start
2May-20End
Sheet2
#VALUE!
</td></tr></table></td></tr></table>
 
Upvote 0
Helper column d'oh (forehead palm!) and have absolutely no reason not to have a second date range!
@thanks Peter_Ss
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,215
Members
448,554
Latest member
Gleisner2

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