Forum

Notifications
Clear all

How to define season by months that cover separate years?

13 Posts
4 Users
0 Reactions
326 Views
(@jv44heinzbar)
Posts: 11
Active Member
Topic starter
 

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

 
Posted : 24/12/2020 2:06 am
(@dhayaward)
Posts: 1
New Member
 

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. 

 
Posted : 24/12/2020 11:41 am
(@jv44heinzbar)
Posts: 11
Active Member
Topic starter
 

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

 
Posted : 24/12/2020 9:04 pm
(@mynda)
Posts: 4761
Member Admin
 

Hi Brent,

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

Thanks,

Mynda

 
Posted : 25/12/2020 7:01 am
(@jv44heinzbar)
Posts: 11
Active Member
Topic starter
 

Ok. Let's try this again 🙂

 
Posted : 26/12/2020 12:16 pm
(@mynda)
Posts: 4761
Member Admin
 

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

 
Posted : 26/12/2020 11:13 pm
(@jv44heinzbar)
Posts: 11
Active Member
Topic starter
 

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

 
Posted : 28/12/2020 11:27 pm
(@mynda)
Posts: 4761
Member Admin
 

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

 
Posted : 29/12/2020 2:07 am
(@jv44heinzbar)
Posts: 11
Active Member
Topic starter
 

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

 
Posted : 13/01/2021 3:01 am
(@debaser)
Posts: 838
Member Moderator
 

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'.

 
Posted : 13/01/2021 5:18 am
(@jv44heinzbar)
Posts: 11
Active Member
Topic starter
 

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

 
Posted : 13/01/2021 11:08 pm
(@debaser)
Posts: 838
Member Moderator
 

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.
 
Posted : 14/01/2021 6:17 am
(@debaser)
Posts: 838
Member Moderator
 

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"))
 
Posted : 14/01/2021 6:26 am
Share: