Get reuslt from Tables

Dossfm0q

Banned User
Joined
Mar 9, 2009
Messages
570
Office Version
  1. 2019
Platform
  1. Windows
Hi I need Excel sheet function to find Number from "XX" column and get result from Right Second column "YY" if has decimal such 0.5, 0.7 go through below Table and get Result from right Column
get the intger Number 2212 then find 3 in Small Table
Book1
AB
101.82212.3
Sheet1


Plus 0.5
Book1
CD
2730.5
Sheet1


 

Excel Facts

What did Pito Salas invent?
Pito Salas, working for Lotus, popularized what would become to be pivot tables. It was released as Lotus Improv in 1989.
Your data is laid out awkwardly. I would recommend that the data be un=pivoted so that the XX are all in column A and the YY all in column B; also, the 'decimal data should be treated similarly.

I made this work anyway with your layout. Note that it only works with the data you provided, where the lookup value (e.g., 1.8) is of a different magnitude to the YY values. It looks strange with the two ranges that are misaligned by one column, but that is what makes it work.

J27: =INT(MAX((J26=A2:L21)*B2:M21))+MAX((ROUND(MOD(MAX((J26=A2:L21)*B2:M21),1),1)*10=C25:F29)*D25:G29)
 
Upvote 0
Solution
Just to be add as VBA Code
VBA Code:
Public Sub AddVBAGetTableFormlua()
Dim WB As Workbook: Set WB = ThisWorkbook
Dim WS1 As Worksheet, WS2 As Worksheet
Dim Target  As Range, Valuerng  As Range, Table1Rng As Range, Table2Rng As Range, Table1RngOS As Range, Table2RngOS As Range
Set WS1 = WB.Worksheets("Sheet1")
Set WS2 = WB.Worksheets("Sheet2")

Set Target = WS1.Range("J27")
Set Valuerng = WS1.Range("J26")

Set Table1Rng = WS2.Range("A2:L21")
Set Table1RngOS = WS2.Range("A2:L21").Offset(0, 1)

Set Table2Rng = WS2.Range("C25:F29")
Set Table2RngOS = WS2.Range("C25:F29")

ArrayFormlua = "=INT(MAX((J26=" & WS2.Name & "!" & Table1Rng.Address & ")*" & WS2.Name & "!" & Table1RngOS.Address & "))+MAX((ROUND(MOD(MAX((J26=" & WS2.Name & "!" & Table1Rng.Address & ")*" & WS2.Name & "!" & Table1RngOS.Address & "),1),1)*10=" & WS2.Name & "!" & Table2Rng.Address & ")*" & WS2.Name & "!" & Table2RngOS.Address & ")"

Target.FormulaArray = ArrayFormlua



End Sub
 
Upvote 0

Forum statistics

Threads
1,214,904
Messages
6,122,169
Members
449,070
Latest member
webster33

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