Sumifs based on data range and time

Translationguy

New Member
Joined
Nov 4, 2016
Messages
26
Hi All

So after lots of hurdles getting a new report sorted based on a data dump from a translation tool (over 50,000 rows per month) I've managed to get through pretty much every hurdle but this one.

I can sum the number of words against each language, budget etc including a date range because when the translation project starts, the tool lists only the date such as "02/11/2017" (this is using British dates).

The issue is that once it gets to the stages of translation such as translation, review, proofreading it starts to include times as well such as "02/11/2017 00.00.00". To finish this report, I need to sumifs everything up, per translator (I can amend the formula for proofreaders and reviewers etc).

The columns that I believe will be affected are listed here.

Report (the dump of data):
AC - One of the types of words per file, listed as numbers.
AO - The translation user, the person I have assigned the number of words to so I can pay them.
AL - The start date including British date format and the time(dd/mm/yyyy hh.mm.ss)

Invoicing (the sheet I use to total the wordcounts against each budget):
B1: The date when the entire project starts (dd/mm/yyyy)
B2: The date when the entire project ends (dd/mm/yyyy)

Translators:
C - The column where the translator's username is listed that is matches with report AO.

Here are some examples of formulas I have tried in case it helps.

"=SUMIFS(Report!AC:AC,Report!AO:AO,Translators!C20,Report!AL:AL,">="&Invoicing!B1,Report!AL:AL,"<="&Invoicing!B2)" This formula will work perfectly if I remove the space and time from Report AL.

"=SUMIFS(Report!AC:AC,Report!AO:AO,Translators!C20,Report!BK:BK,">="&Invoicing!B1,Report!BK:BK,"<="&Invoicing!B2)" For this I tried to put "=LEFT(AL20,10)" into Report BK so that I would only have the date to match against but this didn't work.

"=SUMIFS(Report!AC:AC,Report!AO:AO,Translators!C20,Report!AL:AL,">="&"*"&Invoicing!B1&"*",Report!AL:AL,"<="&"*"&Invoicing!B2&"*")"
"=SUMIFS(Report!AC:AC,Report!AO:AO,Translators!C20,Report!AL:AL,">=""*"&Invoicing!B1&"*",Report!AL:AL,"<=""*"&Invoicing!B2&"*")" Neither of these 2 formulas threw up issues but wouldn't return values either.

Let me know where you think I'm going wrong or my options, we can request development of the tool to do certain things but it would take a lot of time to resolve and I'm not sure now that the whole system has the time included, it's possible to remove it.

Many thanks!
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
"=SUMIFS(Report!AC:AC,Report!AO:AO,Translators!C20,Report!AL:AL,">="&Invoicing!B1,Report!AL:AL,"<="&Invoicing!B2)" This formula will work perfectly if I remove the space and time from Report AL.

Hi, you can try the following amendments to the above.

=SUMIFS(Report!AC:AC,Report!AO:AO,Translators!C20,Report!AL:AL,">="&Invoicing!B1,Report!AL:AL,"<"&Invoicing!B2+1)
 
Upvote 0

Forum statistics

Threads
1,214,907
Messages
6,122,181
Members
449,071
Latest member
cdnMech

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