Substring search in a lookup on a Pivot

TheBigEgg

New Member
Joined
Dec 27, 2017
Messages
2
Hi,
Currently have this formula that works to a point:
=IFERROR(GETPIVOTDATA("Var1",Data!$K$1,"Var2",$AD18222,"Var3",I$2,"Var4",$AB18222),0)

I need to be able to substring Var4 so it finds for example "VF11" VF12" etc when the cell it refers to ($AB18222 for example) has "VF1" in it.

Anyone able to help?

Much appreciated,
Scott
 

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"
Welcome to the forum.

You can't use wildcards in GETPIVOTDATA I'm afraid. Could there be more than one match and if so, should the result be the sum of them or something else?
 
Upvote 0
Hi Rory,

yes, the result should be a sum. I was just trying to see if I could get away without adding in the extra breakdowns in to the lookup as the spreadsheet is already very large but if it can't be worked around I can go down that route.
As a somewhat basic Excel user I thought it would be best to ask before going down that route!

Thanks for the help!
 
Upvote 0
If there's a limit to the possible options, you could use an array formula with INDIRECT to create all possible number combinations like this:

=SUM(IFERROR(GETPIVOTDATA("Var1",Data!$K$1,"Var2",$AD18222,"Var3",I$2,"Var4",$AB18222&TEXT(ROW(INDIRECT("1:1000"))-1,"0;;;")),0))

which will essentially try and sum the values for VF1, VF11, VF12, VF13 and so on up to VF1999. Would that work for you?
 
Upvote 0

Forum statistics

Threads
1,215,323
Messages
6,124,244
Members
449,149
Latest member
mwdbActuary

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