OpenOffice.org Forum at OOoForum.orgThe OpenOffice.org Forum
 
 [Home]   [FAQ]   [Search]   [Memberlist]   [Usergroups]   [Register
 [Profile]   [Log in to check your private messages]   [Log in

Calc Avg Number of Days Btwn Two Dates w/Multiple Criteria

 
Post new topic   Reply to topic    OOoForum.org Forum Index -> OpenOffice.org Calc
View previous topic :: View next topic  
Author Message
kissellj
Newbie
Newbie


Joined: 25 May 2011
Posts: 2

PostPosted: Wed May 25, 2011 11:07 am    Post subject: Calc Avg Number of Days Btwn Two Dates w/Multiple Criteria Reply with quote

This is my first post and hope I can explain our need clearly.

I need help trying to find average number of days between two ranges of dates based on multiple criteria.

We operate an events company and we'd like to find the difference between our client's event dates and the date they contacted us so that we can get an idea of how far out our client's are contacting us before their event.

We collect a variety of data from our clients: Date of First Contact, Date of Event, Type of Event (wedding, birthday, etc.), Service Needed (DJ, photography, etc), Did the Client Book (Yes, No, Potential).

I've been trying to come up with a function to do the following:
1- Determine if the client is a WEDDING CLIENT and a DJ CLIENT
2- If so, find the difference btwn the DATE OF FIRST CONTACT and the DATE OF EVENT
3- Find the average of these dates

COLUMN A = DATE OF FIRST CONTACT
COLUMN B = DATE OF EVENT
COLUMN C= TYPE OF EVENT (Wedding, Birthday, etc.)
COLUMN D= TYPE OF SERVICE (DJ, Photography, etc.)

Any help is much appreciated!
Back to top
View user's profile Send private message
Villeroy
Super User
Super User


Joined: 04 Oct 2004
Posts: 10106
Location: Germany

PostPosted: Wed May 25, 2011 11:22 am    Post subject: Reply with quote

Subtract the dates and the result will be the difference in days.
_________________
Rest in peace, oooforum.org
Get help on https://forum.openoffice.org
Back to top
View user's profile Send private message
kissellj
Newbie
Newbie


Joined: 25 May 2011
Posts: 2

PostPosted: Wed May 25, 2011 11:39 am    Post subject: Reply with quote

Thank you for the reply.

I have created an array to subtract the EVENT DATE from the DATE OF FIRST CONTACT:

EVENT DATE: =SUMPRODUCT(('Leads Sheet'.F1:F9999=Wedding)*('Leads Sheet'.K1:K9999=DJ)*('Leads Sheet'.E1:E9999))

DATE OF FIRST CONTACT: =SUMPRODUCT(('Leads Sheet'.F1:F9999=Wedding)*('Leads Sheet'.K1:K9999=DJ)*('Leads Sheet'.A1:A9999))

Where Column A is the range of dates for Date of First Contact and Column E is range of Dates for Date of Event.

I was hoping to take these sums and subtract them but I get a negative number. The sum of DATE OF FIRST CONTACT that meet my criteria is 7587585 and the sum of EVENT DATES that meet my criteria is 6875203.

Even if this number was positive, we have received 145 total wedding clients interested in DJ services this year. When I divide the difference of these dates by 145 I get 15,830 days which is incorrect.

Thoughts???
Back to top
View user's profile Send private message
ken johnson
Super User
Super User


Joined: 23 Apr 2009
Posts: 2032
Location: Sydney, Australia

PostPosted: Wed May 25, 2011 3:01 pm    Post subject: Reply with quote

Try...
Code:
=SUMPRODUCT('Leads Sheet'.F1:F9999="Wedding";'Leads Sheet'.K1:K9999="DJ";'Leads Sheet'.E1:E9999-'Leads Sheet'.A1:A9999)/sumproduct('Leads Sheet'.F1:F9999="Wedding";'Leads Sheet'.K1:K9999="DJ")

Ken Johnson
_________________
If your problem has been solved please add "[Solved]" to the beginning of your first post title (edit button).
Back to top
View user's profile Send private message
Display posts from previous:   
Post new topic   Reply to topic    OOoForum.org Forum Index -> OpenOffice.org Calc All times are GMT - 8 Hours
Page 1 of 1

 
Jump to:  
You cannot post new topics in this forum
You cannot reply to topics in this forum
You cannot edit your posts in this forum
You cannot delete your posts in this forum
You cannot vote in polls in this forum


Powered by phpBB © 2001, 2005 phpBB Group