Array Formula Referencing a string??

dariushou

Board Regular
Joined
Feb 17, 2008
Messages
126
Hi there,

I'm having a problem with the below array. The column heading in cells E7:H7 Never change and i would like to sum up the appropriate data below those headings according to the what is in cell D4. The formula in cell A9 works but only if the string is exactly the same as what is listed in cell D4. Is there a way to reference cell D4 like i have in cell B9. I'm looking to get the formula in B9 to work, but i'm missing something.

Sheet1

<TABLE style="PADDING-RIGHT: 2pt; PADDING-LEFT: 2pt; FONT-SIZE: 10pt; FONT-FAMILY: Arial,Arial; BACKGROUND-COLOR: #ffffff" cellSpacing=0 cellPadding=0 border=1><COLGROUP><COL style="FONT-WEIGHT: bold; WIDTH: 30px"><COL style="WIDTH: 122px"><COL style="WIDTH: 75px"><COL style="WIDTH: 64px"><COL style="WIDTH: 122px"><COL style="WIDTH: 92px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"></COLGROUP><TBODY><TR style="FONT-WEIGHT: bold; FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center"><TD> </TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD><TD>E</TD><TD>F</TD><TD>G</TD><TD>H</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">2</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center" colSpan=2>Assumptions</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">3</TD><TD>Collateral Sample 1</TD><TD>{60;90;FCL}</TD><TD> </TD><TD>MACRO Populates</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">4</TD><TD>Collateral Sample 2</TD><TD>{90;FCL}</TD><TD> </TD><TD>{60;90;FCL}</TD><TD style="FONT-WEIGHT: bold"> </TD><TD> </TD><TD> </TD><TD> </TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">5</TD><TD>Collateral Sample 3</TD><TD>{FCL}</TD><TD> </TD><TD> </TD><TD style="FONT-WEIGHT: bold"> </TD><TD> </TD><TD> </TD><TD> </TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">6</TD><TD>Collateral Sample 4</TD><TD>{60;90;FCL}</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">7</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD style="TEXT-ALIGN: center">Current</TD><TD style="TEXT-ALIGN: center">60</TD><TD style="TEXT-ALIGN: center">90</TD><TD>FCL</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">8</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">9</TD><TD style="TEXT-ALIGN: right">9</TD><TD style="TEXT-ALIGN: right">0</TD><TD> </TD><TD> </TD><TD style="TEXT-ALIGN: right">1</TD><TD style="TEXT-ALIGN: right">2</TD><TD style="TEXT-ALIGN: right">3</TD><TD style="TEXT-ALIGN: right">4</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">10</TD><TD style="TEXT-ALIGN: right">20</TD><TD style="TEXT-ALIGN: right">0</TD><TD> </TD><TD> </TD><TD style="TEXT-ALIGN: right">6</TD><TD style="TEXT-ALIGN: right">5</TD><TD style="TEXT-ALIGN: right">8</TD><TD style="TEXT-ALIGN: right">7</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">11</TD><TD style="TEXT-ALIGN: right">36</TD><TD style="TEXT-ALIGN: right">0</TD><TD> </TD><TD> </TD><TD style="TEXT-ALIGN: right">4</TD><TD style="TEXT-ALIGN: right">6</TD><TD style="TEXT-ALIGN: right">8</TD><TD style="TEXT-ALIGN: right">22</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">12</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD></TR></TBODY></TABLE>
<TABLE style="FONT-SIZE: 10pt; BORDER-LEFT-COLOR: #00ff00; BORDER-BOTTOM-COLOR: #00ff00; COLOR: #000000; BORDER-TOP-STYLE: groove; BORDER-TOP-COLOR: #00ff00; FONT-FAMILY: Arial; BORDER-RIGHT-STYLE: groove; BORDER-LEFT-STYLE: groove; BACKGROUND-COLOR: #fffcf9; BORDER-RIGHT-COLOR: #00ff00; BORDER-BOTTOM-STYLE: groove"><TBODY><TR><TD>Spreadsheet Formulas</TD></TR><TR><TD><TABLE style="FONT-SIZE: 9pt; FONT-FAMILY: Arial" cellSpacing=0 cellPadding=2 border=1><TBODY><TR style="FONT-SIZE: 10pt; BACKGROUND-COLOR: #cacaca"><TD>Cell</TD><TD>Formula</TD></TR><TR><TD>A9</TD><TD>{=SUM(IF($E$7:$H$7={60;90;"FCL"},$E9:$H9))}</TD></TR><TR><TD>B9</TD><TD>{=SUM(IF($E$7:$H$7=$D$4,$E9:$H9))}</TD></TR><TR><TD>A10</TD><TD>{=SUM(IF($E$7:$H$7={60;90;"FCL"},$E10:$H10))}</TD></TR><TR><TD>B10</TD><TD>{=SUM(IF($E$7:$H$7=$D$4,$E10:$H10))}</TD></TR><TR><TD>A11</TD><TD>{=SUM(IF($E$7:$H$7={60;90;"FCL"},$E11:$H11))}</TD></TR><TR><TD>B11</TD><TD>{=SUM(IF($E$7:$H$7=$D$4,$E11:$H11))}</TD></TR></TBODY></TABLE></TD></TR><TR><TD>Formula Array:
Produce enclosing
{ } by entering
formula with CTRL+SHIFT+ENTER!
</TD></TR></TBODY></TABLE>

Excel tables to the web >> http://www.excel-jeanie-html.de/index.php?f=1" target="_blank"> Excel Jeanie HTML 4
 

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
This thing is killing me.

I tried this but it didn't work. Thought substitute would of worked.
formula was entered by cse

Code:
SUM(IF($E$7:$H$7=SUBSTITUTE(D4,,),$E9:$H9))
 
Upvote 0
First define the following...

Code:
Insert > Name > Define

Name:  Array

Refers to:

=EVALUATE(SUBSTITUTE(SUBSTITUTE(UPPER(Sheet1!$D$4),"FCL","""FCL"""),"CURRENT","""CURRENT"""))

Click Ok

Then try...

Code:
B9, copied down:

=SUMPRODUCT(--ISNUMBER(MATCH($E$7:$H$7,Array,0)),E9:H9)

Hope this helps!
 
Upvote 0
try this in B9
make sure you press the "Ctrl + Alt + Enter" to complete the formula
Code:
{=SUMPRODUCT(IF(ISERR(SEARCH(e7:h7,d4)),0,1),e9:h9)}
 
Upvote 0
Since your formula works if there is an exact match, you could put list validation on D4, so any entry came from $E$7:$H$7
 
Upvote 0
Since your formula works if there is an exact match, you could put list validation on D4, so any entry came from $E$7:$H$7
i'm sorry ,but i didn't understand your meaning bcuz i'm not good in english . I have a question for u, i'll very appreciate it if u explain it as plain as u can .

why the function Find(e7:h7,d4) can't return a array,but SEARCH(e7:h7,d4) did ? i'm very confused about this.
 
Upvote 0
try this in B9
make sure you press the "Ctrl + Alt + Enter" to complete the formula
Code:
{=SUMPRODUCT(IF(ISERR(SEARCH(e7:h7,d4)),0,1),e9:h9)}

Here's a variation on the above formula...

B9, confirmed with just ENTER, and copied down:

=SUMPRODUCT(--ISNUMBER(SEARCH($E$7:$H$7,$D$4)),E9:H9)

Note, however, in the unlikely event that E7:H7 contains values such as 6 and 9, or D4 contains text such as 600 and 900, the formula will return an incorrect result.

why the function Find(e7:h7,d4) can't return a array,but SEARCH(e7:h7,d4) did ? i'm very confused about this

Actually, FIND can indeed return an array. The difference between FIND and SEARCH, though, is that the former is case-sensitive, whereas the latter is not.

Hope this helps!
 
Last edited:
Upvote 0
I want to thank you two. This was exactly what i was looking for. Now i don't have to embed 7+ if statements.
 
Upvote 0

Forum statistics

Threads
1,214,636
Messages
6,120,664
Members
448,976
Latest member
sweeberry

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