Van Gysel asked in a recent post at Chandoo.org for a way to calculate the costs of running a plantation. The twist is that the costs vary by year, and based on the age of the trees.
The following is a slightly simplified version of the solution I offered:
=SUM(IFERROR(LOOKUP(“Year”&MMULT(N($B$3:B$7>0),TRANSPOSE(COLUMN($B$3:B$7)^0)), $B$11:$I$11, $B12:$I12),0)*B$3:B$7) Ctrl+Shift+Enter
Today I am going to try and explain how the formula works.
As always at Formula Forensics, you can follow along with a sample file: Download Here
The Problem
In a plantation, the costs for planting and maintaining trees vary based on the age of the trees and by year. The table below shows the acres of trees planted per year and the yield and costs per year that vary based on the age of the trees.

Let us look at the calculations needed for each year.
Year 2013
- 300 acres of trees were planted in 2013. Calculations for 2013 are as follows. (Only Yield calculation is shown, but the process is similar for Nursery costs, Fertilizers, etc.)
- The trees do not yield any fruits in the first year. As such, Yield for year1=300*0=0
That was easy!
Year 2014
- 700 additional acres of trees will be planted in 2014. Calculations for 2014 are as follows. (Again, only Yield calculation is shown, but others are calculated similarly.)
- 300 acres of trees are 2 years old. 700 acres are 1 year old.
- The 300 acres from 2013 now yield fruit since it is year2. However, the new trees (700 acres) do not yield any fruits yet. So total yield for 2014=300*Year2Yield+700*Year1Yield=300*5+700*0
Year 2015
- 1000 additional acres are to be planted in 2015. Calculations for 2015 are as follows:
- 300 acres are from 2013 (3 years old); 700 acres are from 2014 (2 years old); 1000 acres are from 2015 (1 year old).
- Yield for 2015=300*Year3Yield + 700*Year2Yield + 1000*Year1Yield = 300*10 + 700*5 + 1000*0
Year 2016
- 1000 additional acres are to be planted in 2016. Calculations for 2016 are as follows:
- Yield for 2016=300*15+700*10+1000*5+1000*0
How do we simulate the above calculation in an Excel formula?
A Solution
Let us first look at how we performed the calculations above manually, using the 2016 Yield as an example.
- We took each acreage value in 2016, and determined its age by counting how many years it has been since that acreage was planted. You might have observed that the age can be counted by the number of times a value has been repeated up to that point. (In other words, if I planted 300 acres in 2013, I should see that same amount in 2014, 2015 and 2016.) As such, 300 acres is repeated 4 times. 700 acres is repeated 3 times. 1000 acres is repeated 2 times. And the latest planting of 1000 acres exists only once.
- Once we determine the age for a given acreage, we looked up the yield for that age in the second table
- We then multiplied the acreage with the corresponding yield value.
Calculation #1 can be expressed as follows:
- Age for acreage 1 (first planted in 2013)=count of B3:E3 where value is greater than zero. i.e. COUNTIF(B3:E3,”>0”)
- Age for acreage 2 (planted in 2014)=count of B4:E4 where value is greater than zero. i.e. COUNTIF(B4:E4,”>0”)
- Age for acreage 3 (planted in 2015)=count of B5:E5 where value is greater than zero. i.e. COUNTIF(B5:E5,”>0”)
- Age for acreage 4 (planted in 2016)=count of B6:E6 where value is greater than zero. i.e. COUNTIF(B6:E6,”>0”)
- Age for acreage 5 is zero since nothing has been planted for 2017 yet in 2016
The above approach would work if we were calculating the age one row at a time. However, that can become tedious really fast. We need to perform the calculation for the full range (B3:E7) together, but return the counts for each row individually.
Excel’s MMULT function comes to the rescue!
MMULT (which stands for Matrix Multiply) multiplies two matrices and returns a third matrix based on rules for matrix multiplication. I am planning to devote a whole article to explain the MMULT function. As such, for this article, we will summarize the utility of the function as “take a 2-dimensional array, add each column’s value for each row, and return a 1-column array”.
MMULT requires that its arguments be numeric.
So to obtain the counts for the year 2016, we can use the following:
MMULT(N($B$3:E$7>0),TRANSPOSE(COLUMN($B$3:E$7)^0))
As you can see from the picture below, MMULT’s results are the addition of each column for each row.
In the above formula, you may have noticed that the range uses absolute and relative referencing (signified by the $ sign or lack thereof). This is to ensure that the range grows or shrinks as needed. The upper left address is held constant ($B$3). However, the lower right address for the range has columns that vary but row that is fixed on row #7. This ensures that the formula would work if we copy to the left, right, etc. in the final results.
Now that we have the age for each acreage value, we can look up the corresponding yield value using (what else?) LOOKUP function.
But before we can use LOOKUP, we will need to convert the numeric values returned from MMULT into the strings Year1, Year2, etc. found in the Costs table. Of course, you know how to do that… concatenate the string “Year” to the result from MMULT
“Year”&MMULT(N($B$3:E$7>0),TRANSPOSE(COLUMN($B$3:E$7)^0))
For the 2016 example, we get {“Year4″;”Year3″;”Year2″;”Year1″;”Year0”}
We can now use LOOKUP as follows:
LOOKUP(“Year”&MMULT(N($B$3:E$7>0),TRANSPOSE(COLUMN($B$3:E$7)^0)), $B$11:$I$11, $B12:$I12)
You may recall that LOOKUP looks up a value in the array indicated by the second argument, and returns the corresponding value from the third array argument. In this case, instead of looking up a single value, we look up an array of values (supplied in the first argument) to the function.
The above formula translates to the following:
LOOKUP({“Year4″;”Year3″;”Year2″;”Year1″;”Year0”}, {“Year1″,”Year2″,”Year3″,”Year4″,”Year5″,”Year6″,”Year7″,”Year8”}, {0,5,10,15,20,25,30,35})
The result from LOOKUP is {15;10;5;0;#N/A}
(The last value is #N/A because there is no acreage value for 2017 yet (as of 2016 column). The concatenation resulted in Year0 which does not exist in the “Age of The Trees” range (B11:I11) above.)
By using IFERROR(LOOKUP(…),0) we get {15;10;5;0;0}
We can now multiply the above result with the acreage values for 2016 to get {4500;7000;5000;0;0}
Finally, we SUM the values to get 16500
Putting it all together, we get the following formula (shown for Production for year 2016)
=SUM(IFERROR(LOOKUP(“Year”&MMULT(N($B$3:E$7>0),TRANSPOSE(COLUMN($B$3:E$7)^0)), $B$11:$I$11, $B12:$I12),0)*E$3:E$7)
One of the benefits of the above formula is that you can copy the same formula to calculate values for additional years, as well as other plantation costs.
Download
You can download a copy of the above file and follow along: Download sample file.
Let me know (using the comments below) what you think of the above approach and solution, as well as any other approaches you have utilized to solve a similar problem. In the meantime, I wish you continued Excellence!
-Sajan.
Other Posts in this Series
The Formula Forensics Series contains a wealth of useful solutions and information.
Visit the Formula Forensics Home Page to read other articles in this series.




















23 Responses to “Displaying Text Values in Pivot Tables without VBA”
Its possible to display up to 4 text values.
Have a look at the screen shot of an example that I had posted way back at the EHA and figure out how its done !
http://tinypic.com/r/muzywk/6
With Excel 2010 you can use Conditional Formatting to apply custom number formats which can display text. (In older versions you can only modify text color and cell background color, but not number formats.) Using CF allows for an even larger number of different display values.
[...] Display text values in Pivot Tables without VBA [...]
Hey,
Thanks, this helps. But how do you do it for multiple values where there is a huge amount of non repeating text?
@Soumya
The only way to do more than 4 values is to make the Pivot Table manually with formulas, of course then it isn't a Pivot table
You can of course do it with VBA
You may want to have a look at this description of how to do it here: http://www.clearlyandsimply.com/clearly_and_simply/2011/06/emulate-excel-pivot-tables-with-texts-in-the-value-area-using-vba.html
@Soumya
The only way to do more than 4 values is to make the Pivot Table manually with formulas, of course then it isn’t a Pivot table
You can of course do it with VBA
You may want to have a look at this description of how to do it here: http://www.clearlyandsimply.com/clearly_and_simply/2011/06/emulate-excel-pivot-tables-with-texts-in-the-value-area-using-vba.html
[...] Pivot Tables take tables of data and allow the user to summarise and consolidate the data at the same time. This is a great and very fast method of analysis but is restricted to handling mathematical functions on the value field resulting in numerical summaries. – read more [...]
[…] Read more here: Displaying Text Values in Pivot Tables without VBA […]
There is a very good way actually for handling text inside values area.
First you create a special column on the very left side and call it ID, and put unique ID (numbers only), and then create a pivot table with:
Row Labels and Column labels as you like, and in the Values labels use the unique ID number.
Move the unique ID number (copy paste) somewhere to the right and use vlookup to load the data you need using the ID as reference.
It is a bit longer way but for me it works perfectly to combine values as you like in any moment.
hope helps.
Regards,
Jon
Thank you! I finally understand pivot tables thanks to your clear, concise explanations and examples.
Good Day. This is exactly what i have been looking for. However when i try it on my pivot table or even when i try to recreate this exercise using the sample worksheet, i get this error:
"Microsoft Excel cannot use the number format you typed. Try using one of the built-in number formats."
Same thing here, Excel quite did not like the format in my PowerPivot. Any clues as to what may be going on? Thanks.
I have the same thing happening on my end. I'm running a normal pivot table on a .xlsm file.
@Danzi
What format did you use?
can you post the file ?
pls. help in table there is name, pan. amount. i have to make pivot table for example
NAME PAN AMOUNT
MR.X AAAAC1254T 500.00
MR.Y AAABR1258C
MR.A CFVDE2458T
MR.Z AAVCR12548C
MR.X AAAAC1254T
MR.Z AADCD245T
pls. help in table there is name, pan. amount. i have to make pivot table for example
NAME PAN AMOUNT
MR.X AAAAC1254T 500.00
MR.Y AAABR1258C 1000
MR.A CFVDE2458T 2000
MR.Z AAVCR12548C 5451
MR.X AAAAC1254T 45564
MR.Z AADCD245T 4500
how to get pivot tabe so i get PAN no. against Name.
I found an easy way to get text values in pivot table.
I create an other worksheet in wich each cell has a formula that copy the pivot table. The trick is that the formula does a lookup for the numbers in the pivot table.
The formula looks like that:
=IF(ISNUMBER(table!A1);VLOOKUP(table!A1;Code!$A$1:$B$65;2);IF(ISBLANK(table!A1);" ";table!A1))
Code is a worksheet where there is a liste of text /numbers correspondance.
As a bonus The new sheet is easier to format
Additional trick:
In my case, i encoded differents codeid with a power(2, codeId-1) so that summing then is equivalent to concatenate them.
1-A
2-B
4-C
8-D
yields :
5 - AC
14 - BCD
Hi
I want to ask if pivot can display dates in pivot field. As in a column i have customers and in row different items i want to know there last purchase date. anyone help in this??
Hello Guys, Need your help
I am doing some analysis of the cycle time of the product i.e how much time a product takes from manufacturing to the central warehouse.
I have batch numbers for the product and against them i have to pull out the diff. dates
Like the base date is from where the manufacturing start. So i have the batch number,against it's manuf. date. Now i have to pull out the date when it was quality released.
I have the quality released data but the data have duplicates, like i will have two dates or may be three for the same batch. So my main objective is to pull out the date which is latest among them.
BATCH NO. DATE of Mfg. DATE of Quality release
A1 12/4/2014 (HERE I HAVE TO PULL value)
Next Sheet
BATCH NO. DATE of Quality Release
A1 14/5/2014
a2 23/5/2016
A1 12/5/2014
A1 13/6/2014
From this sheet i have to pull up the latest date format of date here is dd/mm/yyy
TIA
[…] needed to present text instead of counts in a pivot table value column. Here is an excellent resource for Excel manipulation, in addition to an overview of pivot […]
This is great thank you.
Wow!!! Excellent!! It helped me a lot.
I am developing training tracking sheet for 200 employees with training completed date. Each employee will be attending 25 courses. How to indicate actual dates in pivot table value field.