Excel filter / MS Query Criteria - Formula

natheplas

Board Regular
Joined
Aug 28, 2016
Messages
89
Hi All,

I am currently using this formula for 1 cell =SUMPRODUCT(--(SOPLIVE!$A$66533:$A$69522=A11), --(SOPLIVE!$H$66533:$H$69522="Oct-2017"), SOPLIVE!$C$66533:$C$69522)

This is correct and does what I need it to up to a point....

The SOPLIVE sheet is connected to a Microsoft Query. I need to add another two criterias on that MSQUERY so that the sheet does not include any cancelled orders, or completed orders. I can do this and it seems to work before I have returned the data.

However, when I then click 'return data' it returns to excel with no data on that sheet?

What I need is the =SUMPRODUCT(--(SOPLIVE!$A$66533:$A$69522=A11), --(SOPLIVE!$H$66533:$H$69522="Oct-2017"), SOPLIVE!$C$66533:$C$69522) formula to only pick up orders filtered by not including cancelled or completed.

Or for the criteria within the MSQUERY to work when I return the data.

Really stuck with this one guys! Not sure why it isn't working.

If anything is unclear, please message for more details.

All help is appreciated!

Natheplas
 

FormR

MrExcel MVP
Joined
Aug 18, 2011
Messages
6,216
Office Version
365
Platform
Windows
Hi, is there a column in the SOPLIVE sheet that contains the status of the order? If so which column and what does it contain when the order is cancelled or completed?
 

natheplas

Board Regular
Joined
Aug 28, 2016
Messages
89
Hi FormR,


Yeah there are two columns within SOPLIVE for this.


Column G, the header is DESPATCH_STATUS and it contains 'Complete' which I am trying to filter those orders out.


There is also column F, the header is ALLOCATED_STATUS and this contains 'Cancelled' which I am also trying to filter those orders out.


I hope this answers your questions - Thanks for coming back to me.

Natheplas
 

FormR

MrExcel MVP
Joined
Aug 18, 2011
Messages
6,216
Office Version
365
Platform
Windows
Hi, yes - that's exactly the detail that was needed.

You could try:

Code:
=SUMPRODUCT(--(SOPLIVE!$A$66533:$A$69522=A11), --(SOPLIVE!$H$66533:$H$69522="Oct-2017"), --(SOPLIVE!$G$66533:$G$69522<>"Complete"),--(SOPLIVE!$F$66533:$F$69522<>"Cancelled"),SOPLIVE!$C$66533:$C$69522)
Or using SUMIFS, the modern equivalent for simple multi-conditional summing:

Code:
=SUMIFS(SOPLIVE!$C$66533:$C$69522,SOPLIVE!$A$66533:$A$69522,A11,SOPLIVE!$H$66533:$H$69522,"Oct-2017",SOPLIVE!$G$66533:$G$69522,"<>Complete",SOPLIVE!$F$66533:$F$69522,"<>Cancelled")
 

natheplas

Board Regular
Joined
Aug 28, 2016
Messages
89
Hi FormR, I thought I'd replied to this apologies! Your suggestion worked. Thank you so much for your help. Huge help, looked into sumifs after you gave that one to me and they are so much better. Thank you.

Is there a formula or macro, or VBA code I can use, that adds same columns to the end of the spreadsheet, but changes to look at the next month.


For example, I've manually put it together so that it picks up until December. However, with a click of a button could it then add the same columns but change 'Dec 17' each time it appears to 'Jan 17'.

Not even sure where I'd start with something like this.
 

FormR

MrExcel MVP
Joined
Aug 18, 2011
Messages
6,216
Office Version
365
Platform
Windows
Hi, not sure I fully understand - but you could put the text Jan-17 into a cell (A1 for example) and have the formula reference that instead of hard coding the month.

Code:
=SUMIFS(SOPLIVE!$C$66533:$C$69522,SOPLIVE!$A$66533:$A$69522,A11,SOPLIVE!$H$66533:$H$69522,[B][COLOR=#FF0000]$A$1[/COLOR][/B],SOPLIVE!$G$66533:$G$69522,"<>Complete",SOPLIVE!$F$66533:$F$69522,"<>Cancelled")
Or you could put an excel date into a cell, say the 1st of the month and reference it like this.

Code:
=SUMIFS(SOPLIVE!$C$66533:$C$69522,SOPLIVE!$A$66533:$A$69522,A11,SOPLIVE!$H$66533:$H$69522,[B][COLOR=#FF0000]TEXT($A$1,MMM-YYYY)[/COLOR][/B],SOPLIVE!$G$66533:$G$69522,"<>Complete",SOPLIVE!$F$66533:$F$69522,"<>Cancelled")
You would then just change the value in A1 to update the formula results.
 

Forum statistics

Threads
1,081,981
Messages
5,362,533
Members
400,679
Latest member
alecalec202

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top