Convert array formula to non-array formula in shared workbook

Deutz

Board Regular
Joined
Nov 30, 2009
Messages
191
Office Version
  1. 365
Platform
  1. Windows
Hi and thanks in advance,

I have a shared workbook with some SUMPRODUCT formulas, in the 'Finalised' column of my Stats table, which Excel is treating as array formulas (didn't know SUMPRODUCT was array) that count rows in my 'Data' sheet where the date in column N matchs the month and year in my Stats table. I would like to covert these formulas to non-array since I am unable to copy the values returned by the formulas without getting the error message: Cannot copy or move array entered formulas or data tables in a shared workbook.

=SUMPRODUCT(--(MONTH(Data!$N$2:$N$1000)=F44),--(YEAR(Data!$N$2:$N$1000)=H44))

Annotation 2021-07-16 091130.jpg


Cheers
Deutz
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
Hi and thanks in advance,

I have a shared workbook with some SUMPRODUCT formulas, in the 'Finalised' column of my Stats table, which Excel is treating as array formulas (didn't know SUMPRODUCT was array) that count rows in my 'Data' sheet where the date in column N matchs the month and year in my Stats table. I would like to covert these formulas to non-array since I am unable to copy the values returned by the formulas without getting the error message: Cannot copy or move array entered formulas or data tables in a shared workbook.

=SUMPRODUCT(--(MONTH(Data!$N$2:$N$1000)=F44),--(YEAR(Data!$N$2:$N$1000)=H44))

View attachment 42911

Cheers
Deutz
Just realised I copied the wrong formula to this post. this is the correct formula in would like to convert to non-array type: =SUMPRODUCT(--(MONTH(Data!$N$2:$N$1000)=MONTH(DATEVALUE(G45&"1"))),--(YEAR(Data!$N$2:$N$1000)=H45))
 
Upvote 0
Or try:

=SUMPRODUCT(--(TEXT(Data!$N$2:$N$1000,"mmmmyyyy")=F44&H44))
 
Upvote 0
One way:

=COUNTIFS(Data!$N$2:$N$1000,">="&(F44&"1, "&H44),Data!$N$2:$N$1000,"<"&EDATE(F44&"1, "&H44,1))
 
Upvote 0
Ok, tried entering this but keep getting the generic 'something wrong with formula' message.

Try
=COUNTIFS(Data!$N$2:$N$1000,">="&DATE(H44,MONTH(DATEVALUE(F44&"1")),1),Data!$N$2:$N$1000,"<="&EOMONTH(DATE(H44,MONTH(DATEVALUE(F44&"1")),1),0))

M.
 
Upvote 0
Solution

Forum statistics

Threads
1,213,557
Messages
6,114,291
Members
448,564
Latest member
ED38

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