Getting value on Y axis by putting X axis value

kashifjillani

New Member
Joined
Jul 26, 2011
Messages
47
Hello to all the experts of Excel,

I still can not figure out the way to get the values in a chart/graph by putting an specific X axis value.

e.g.

There is relation between Gauge height and Flow

<TABLE style="WIDTH: 96pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=128><COLGROUP><COL style="WIDTH: 48pt" span=2 width=64><TBODY><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; WIDTH: 48pt; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" height=20 width=64>Gauge</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; WIDTH: 48pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" width=64>Flow </TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" height=20 align=right>0.305</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" align=right>0</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" height=20 align=right>0.32</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" align=right>0.10022</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" height=20 align=right>0.341388</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" align=right>0.27539</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" height=20 align=right>0.381347</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" align=right>0.85528</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" height=20 align=right>0.401708</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" align=right>1.32224</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" height=20 align=right>0.413752</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" align=right>1.69248</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" height=20 align=right>0.433354</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" align=right>2.46828</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" height=20 align=right>0.452996</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" align=right>3.43106</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" height=20 align=right>0.482379</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" align=right>5.3022</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" height=20 align=right>0.511557</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" align=right>7.77429</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" height=20 align=right>0.522962</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" align=right>8.9451</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" height=20 align=right>0.561209</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" align=right>13.53592</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" height=20 align=right>0.589</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" align=right>17.68</TD></TR></TBODY></TABLE>


If I draw the curve with Flow on X-axis and Gage on Y-axis and then want to know the flow at Gage 0.53m.

OR

By putting flow value to know Gage height.

Regards,:rolleyes:
 

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number



Hi Jon,

I knowit's an old post but this seems to be a solution for my problem.
However I have a problem. This is my data:

[TABLE="width: 60"]
<tbody>[TR]
[TD="width: 40, bgcolor: transparent"]x[/TD]
[TD="width: 40, bgcolor: transparent"]y[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]39[/TD]
[TD="bgcolor: transparent, align: right"]1000[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]42[/TD]
[TD="bgcolor: transparent, align: right"]500[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]48[/TD]
[TD="bgcolor: transparent, align: right"]200[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]56[/TD]
[TD="bgcolor: transparent, align: right"]100[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]70[/TD]
[TD="bgcolor: transparent, align: right"]50[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]110[/TD]
[TD="bgcolor: transparent, align: right"]20[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]125[/TD]
[TD="bgcolor: transparent, align: right"]10[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]125[/TD]
[TD="bgcolor: transparent, align: right"]5[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]125[/TD]
[TD="bgcolor: transparent, align: right"]2[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]125[/TD]
[TD="bgcolor: transparent, align: right"]1[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]125[/TD]
[TD="bgcolor: transparent, align: right"]0,5[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]125[/TD]
[TD="bgcolor: transparent, align: right"]0,2[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]125[/TD]
[TD="bgcolor: transparent, align: right"]0,1[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]151[/TD]
[TD="bgcolor: transparent, align: right"]0,05[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]500[/TD]
[TD="bgcolor: transparent, align: right"]0,02[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]12500[/TD]
[TD="bgcolor: transparent, align: right"]0,01[/TD]
[/TR]
</tbody>[/TABLE]

When i try to find y for x=2000 for example, the y that is calculated is not exact. It is giving an y value that is higher.
Now i added a trendline of the line 500-12500/0,02/0,01 (where my x=2000 is in between), and I can see that the y that was estimated according to the trendline somehow.
The trendline is set to ''Lineair'', so i guess thats how your formule calculates the y, when i set the trendline to ''power'', it gives a correct trendline, but of course it doent change the calculated y value.
Now the question is, how can i change it to get it working?


Red=data
Green=calculated y for x=2000
Purple=test line with trendline

I already tried changing the matchtype to -1 (for decreasing values),that didnt work.

Hope someone can help me,

Regards,

Jos
 
Last edited by a moderator:
Upvote 0
The interpolation routine here is a linear interpolation not because of any trendline setting, but because those are the formulas presented. A linear interpolation finds a point on a straight line connecting two points on a chart with linear axes.

UHhKe5t.png


To interpolate a power law, you need to take logarithms of the X and Y values and repeat the linear interpolation. This will find a point on a straight line connecting two points on logarithmic X and Y axes.

TtBYkoH.png


No need to change the MATCH type to -1, because you are searching through increasing X values (column 1) to find the match. Here are the formulas:

A2: X value for which you want to find Y (or log X for which you want to find log Y)
A3: =MATCH(A2,A6:A21,1)
B2: =(A2-INDEX(A6:A21,A3))/(INDEX(A6:A21,A3+1)-INDEX(A6:A21,A3))*(INDEX(B6:B21,A3+1)-INDEX(B6:B21,A3))+INDEX(B6:B21,A3)
 
Upvote 0
The interpolation routine here is a linear interpolation not because of any trendline setting, but because those are the formulas presented. A linear interpolation finds a point on a straight line connecting two points on a chart with linear axes.

UHhKe5t.png


To interpolate a power law, you need to take logarithms of the X and Y values and repeat the linear interpolation. This will find a point on a straight line connecting two points on logarithmic X and Y axes.

TtBYkoH.png


No need to change the MATCH type to -1, because you are searching through increasing X values (column 1) to find the match. Here are the formulas:

A2: X value for which you want to find Y (or log X for which you want to find log Y)
A3: =MATCH(A2,A6:A21,1)
B2: =(A2-INDEX(A6:A21,A3))/(INDEX(A6:A21,A3+1)-INDEX(A6:A21,A3))*(INDEX(B6:B21,A3+1)-INDEX(B6:B21,A3))+INDEX(B6:B21,A3)

Thanks Jon,

I fixed it on a similar way, not by adding a table with the log values but by changing the lineair interpolation formula to the logarithmic one, which is basically the same. But i needed the original values on the x and y axis. It all works. :)

Thanks for the respond!
 
Upvote 0

Forum statistics

Threads
1,223,894
Messages
6,175,250
Members
452,623
Latest member
Techenthusiast

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