• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

How to define season by months that cover separate years?|General Excel Questions & Answers|Excel Forum|My Online Training Hub

You are here: Home / How to define season by months that cover separate years?|General Excel Questions & Answers|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search|Last Search Results
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumGeneral Excel Questions & Answe…How to define season by months that…
sp_PrintTopic sp_TopicIcon
How to define season by months that cover separate years?
Avatar
Brent Evans
Member
Members
Level 0
Forum Posts: 10
Member Since:
December 23, 2020
sp_UserOfflineSmall Offline
1
December 23, 2020 - 4:06 pm
sp_Permalink sp_Print

Hi,

I work as a wildlife biologist where I monitor reported encounters with waterfowl. Our hunting seasons begin in one year and end in the next year. For example, our waterfowl season begins in September 15, 2020 and ends in January 31, 2021.  I would like to create a new field that defines all the birds harvested during this period with 2020 season. I receive a large dataset from US Fish & Wildlife that contains approximately 1.3 million records from dates going back to 1937. I'm just interested in the birds harvested in my state, which equals about 180k+ over. I can easily sort this by recovery state, copy and paste this sorted data into a new worksheet.

With such a large dataset, it takes me too much time to manually assign the harvested birds to the proper season. Is there a way to group birds by season as I mentioned above? I'd prefer not to write any script, if possible.

Thanks,

HB

sp_AnswersTopicSeeAnswer See Answer
Avatar
Daniel Hayward
Portland, OR, USA

New Member
Members
Level 0
Forum Posts: 1
Member Since:
December 24, 2020
sp_UserOfflineSmall Offline
2
December 24, 2020 - 1:41 am
sp_Permalink sp_Print

If you used the following formula, you could use this to get the "season year"

=IF(MONTH(A1)&DAY(A1)*1<131,"Season "&YEAR(A1)-1,"Season "&YEAR(A1))

The formula assumes that this is a date that you're parsing (like with a serial number and that it is formatted as such). It also doesn't ignore dates outside of your mentioned range, so if you have a date like 2/5/yyyy or 6/2/yyyy the formula assumes that those belong in the current year's season. 

Let me know if that doesn't make sense. 

Avatar
Brent Evans
Member
Members
Level 0
Forum Posts: 10
Member Since:
December 23, 2020
sp_UserOfflineSmall Offline
3
December 24, 2020 - 11:04 am
sp_Permalink sp_Print

Hi Daniel,

I think I understand what you're trying to do with the formula. However, could you please break it down for me a little more. I've included a small sample of the data I'm using. I created the "season" field. There are separate fields for month (q1), day (r1), and year (s1). Additionally, I used the date function to create a date in mm/day/year (t1). Any month outside of September through January is discarded from the "season".

See rows 63 & 64. They are different years, but would be considered to be in the same season, 1994.

PS, I tried the formula you supplied, but unfortunately, I had errors associated with it.

 

Thanks for your help.

Brent

Avatar
Mynda Treacy
Admin
Level 10
Forum Posts: 4447
Member Since:
July 16, 2010
sp_UserOfflineSmall Offline
4
December 24, 2020 - 9:01 pm
sp_Permalink sp_Print

Hi Brent,

Please try uploading your file again and be sure to click 'start upload' after selecting your file.

Thanks,

Mynda

Avatar
Brent Evans
Member
Members
Level 0
Forum Posts: 10
Member Since:
December 23, 2020
sp_UserOfflineSmall Offline
5
December 26, 2020 - 2:16 am
sp_Permalink sp_Print

Ok. Let's try this again 🙂

Avatar
Mynda Treacy
Admin
Level 10
Forum Posts: 4447
Member Since:
July 16, 2010
sp_UserOfflineSmall Offline
6
December 26, 2020 - 1:13 pm
sp_Permalink sp_Print

Hi Brent,

Thanks for sharing your file. It's not clear what to do with dates that fall from February to August, so in the attached file I've treated them as relating to the previous year's season, like January.

Hope that helps.

Mynda

Avatar
Brent Evans
Member
Members
Level 0
Forum Posts: 10
Member Since:
December 23, 2020
sp_UserOfflineSmall Offline
7
December 28, 2020 - 1:27 pm
sp_Permalink sp_Print

Mynda,

Thanks for giving it a shot.

Is there a way to have the year = blank or something to indicate that the month falls outside of the hunting season?  Ex. If the month does not equal months between Sept to January, then "blank" or "Outside Season"?

I've banged my head against this problem for a month now and can't really find a solution. The only way I know to do this is to sort the data by year, then month. Typically, I'll use the YEAR function in a new field, ie. "Recovery Season". I then manually clear the data if it falls outside the appropriate hunting season months. Since I do this every year, and I having to go through 100K+ records, I was hoping for a more elegant solution.

Thanks,

Brent

Avatar
Mynda Treacy
Admin
Level 10
Forum Posts: 4447
Member Since:
July 16, 2010
sp_UserOfflineSmall Offline
8
December 28, 2020 - 4:07 pm
sp_Permalink sp_Print

Hi Brent,

You can change the formula in cell U2 to this and copy down:

=IF(AND(MONTH(T2)>1,MONTH(T2)<9),"Outside Season",IF(MONTH(T2)<9,YEAR(T2)-1,YEAR(T2)))

 

Mynda

sp_AnswersTopicAnswer
Answers Post
Avatar
Brent Evans
Member
Members
Level 0
Forum Posts: 10
Member Since:
December 23, 2020
sp_UserOfflineSmall Offline
9
January 12, 2021 - 5:01 pm
sp_Permalink sp_Print

Thanks Mynda. That's what I was wanting to do. Sorry for the late reply.

Avatar
Velouria
London or thereabouts
Moderator
Members


Trusted Members

Moderators
Level 4
Forum Posts: 617
Member Since:
November 1, 2018
sp_UserOfflineSmall Offline
10
January 12, 2021 - 7:18 pm
sp_Permalink sp_Print

Just FYI, that would treat the whole of September as part of your season, not just 15th onwards. I don't know how important that is? There is at least one record in your example file that is dated 14th Sept for example and the current formula will return the same year, rather than 'Out of season'.

Avatar
Brent Evans
Member
Members
Level 0
Forum Posts: 10
Member Since:
December 23, 2020
sp_UserOfflineSmall Offline
11
January 13, 2021 - 1:08 pm
sp_Permalink sp_Print

Hi Velouria,

I didn't think you could mix more than one logical statement in a nested IF/AND? At least I've never been able to make it work. I'm thinking if I make the statement <15, then that would be applied to all the months, which would filter out a lot of true results.

For my purpose, the day component is very small and of little consequence. However, it would be nice to see how to write the statement out of curiosity.

Thanks,

Brent

Avatar
Velouria
London or thereabouts
Moderator
Members


Trusted Members

Moderators
Level 4
Forum Posts: 617
Member Since:
November 1, 2018
sp_UserOfflineSmall Offline
12
January 13, 2021 - 8:17 pm
sp_Permalink sp_Print

I'd do something like this:

 

=IF(AND(MONTH(T2)>1,TEXT(T2,"mmdd")<"0915"),"Outside Season",IF(MONTH(T2)<9,YEAR(T2)-1,YEAR(T2)))

By formatting the month and day that way, you can do a straight < comparison.
Avatar
Velouria
London or thereabouts
Moderator
Members


Trusted Members

Moderators
Level 4
Forum Posts: 617
Member Since:
November 1, 2018
sp_UserOfflineSmall Offline
13
January 13, 2021 - 8:26 pm
sp_Permalink sp_Print

For what it's worth, you could also do this:

 

=IF(MONTH(T2)=1,YEAR(T2)-1,IF(TEXT(T2,"mmdd")>="0915",YEAR(T2),"Out of season"))
sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Aislinn Mellamphy, Lynnette Altomari, Jessica Stewart, Roy Lutke, Dieneba NDIAYE, Darrell Hodge, Tucker Oakley, Natasha Smith
Guest(s) 10
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 870
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
A.Maurizio: 202
Jessica Stewart: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
Sopi Yuniarti
sandra parker
LAFONSO HERNANDEZ
Hayden Hao
Angela chen
Sean Moore
John Chisholm
vexokeb sdfg
John Jack
Malcolm Toy
Forum Stats:
Groups: 3
Forums: 24
Topics: 6214
Posts: 27243

 

Member Stats:
Guest Posters: 49
Members: 31894
Moderators: 3
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.