Vlookup and hlookup combination

leopardhawk

Well-known Member
Joined
May 31, 2007
Messages
611
Office Version
  1. 2016
Platform
  1. Windows
Hello forum friends,

I am using Excel 2016, XLOOKUP is not an option for me (I think).

I have a worksheet that is linked to a website where the actual location of the data returned 'might' change over time. The formula I am currently using is INDEX/MATCH (embedded within a CONCATENATE) which has worked fine up to this point but the data I am accessing recently moved upwards by five rows (currently in row 68) and this has created a problem for me because the data was in row 73. The formula looks like this:
Code:
=CONCATENATE("The " &YEAR(TODAY())&" OAS Recovery Tax minimum threshold is "&TEXT(INDEX(oas_web!B73:G73,MATCH(YEAR(TODAY()),oas_web!B39:G39,0)),"$#,##0.00")&".  If your net income is below this amount, the tax will not apply to you.")

To solve this, I believe a combination of VLOOKUP and HLOOKUP might work better however, I can't seem to get the syntax right and I am hoping someone can help. The data I am retrieving from the web is what you see below:

Book1
ABCDE
39Description2020201920182017
40Indexation increase1.90%2.20%1.50%1.40%
41Tax bracket thresholds
42Taxable income above which the 20.5% bracket begins48,53547,63046,60545,916
43Taxable income above which the 26% bracket begins97,06995,25993,20891,831
44Taxable income above which the 29% bracket begins150,473147,667144,489142,353
45Taxable income above which the 33% bracket begins214,368210,371205,842202,800
46Amounts relating to non-refundable tax credits
47Basic personal amount12,29812,06911,80911,635
48Age amount7,6377,4947,3337,225
49Net income threshold for age amount38,50837,79036,97636,430
50Spouse or common-law partner amount (maximum)12,29812,06911,80911,635
51Spouse or common-law partner amount (maximum if eligible for the Canada caregiver amount for a dependent)14,57114,29913,99113,785
52Amount for an eligible dependant (maximum)12,29812,06911,80911,635
53Amount for an eligible dependant (maximum if eligible for the Canada caregiver amount for a dependent)14,57114,29913,99113,785
54Canada caregiver amount for children under age 182,2732,2302,1822,150
55Canada employment amount (maximum)1,2451,2221,1951,178
56Canada caregiver amount for other infirm dependants age 18 or older (maximum amount)7,2767,1406,9866,883
57Net income threshold for Canada caregiver amount17,08516,76616,40516,163
58Disability amount8,5768,4168,2358,113
59Supplement for children with disabilities (maximum)5,0034,9094,8044,733
60Threshold relating to allowable child care and attendant care expenses2,9302,8752,8142,772
61Adoption expenses (maximum per adoption)16,56316,25515,90515,670
62Medical expense tax credit (3% of net income ceiling)2,3972,3522,3022,268
63Refundable medical expense supplement
64Maximum supplement1,2721,2481,2221,203
65Minimum earnings threshold3,7143,6453,5663,514
66Family net income threshold28,16427,63927,04426,644
67Old age security repayment
68Old age security repayment threshold79,05477,58075,91074,788
69Certain board and lodging allowances paid to players on sports teams or members of recreation programs
70Income exclusion (maximum per month)373366359353
71Tradesperson’s tools deduction
72Threshold amount relating to cost of eligible tools1,2451,2221,1951,178
73Canada training credit (CTC)Footnote 1
74Minimum working income threshold10,000
75Maximum net income147,667
76Goods and services tax/harmonized sales tax credit
77Adult maximum296290284280
78Child maximum155153149147
79Single supplement155153149147
80Phase-in threshold for the single supplement9,5909,4129,2099,073
81Family net income at which credit begins to phase out38,50737,78936,97636,429
82Tax-free savings account
83Annual TFSA dollar limit Footnote 26,0006,0005,5005,500
84Lifetime capital gains exemption for qualified farm or fishing property and qualified small business corporation shares Footnote 3
85Exemption limit883,384866,912848,252835,716
86Deduction limit (since ½ of the capital gain is taxable)441,692433,456424,126417,858
87Additional exemption amount for qualified farm or fishing property116,616133,088151,748164,284
88Additional deduction amount for qualified farm or fishing property (since ½ of the capital gain is taxable)58,30866,54475,87482,142
89Canada child benefit (CCB) Footnote 4
90CCB (base benefit, child under age 6)6,7656,6396,4966,400
91CCB (base benefit, child aged 6 to 17)5,7085,6025,4815,400
92Adjusted family net income at which phase out begins31,71131,12030,45030,000
93Second phase out threshold68,70867,42665,97565,000
94Base phase out amount for one eligible child2,5902,5412,4872,450
95Base phase out amount for two eligible children4,9954,9014,7964,725
96Base phase out amount for three eligible children7,0296,8986,7506,650
97Base phase out amount for four or more eligible children8,5098,3518,1718,050
98Child disability benefit (CDB)
99Maximum benefit2,8862,8322,7712,730
100Family net income threshold for phase out68,70867,42665,97565,000
oas_web


So, what I need is a formula that can look at this data and return what is currently in C68 (77,580) because the current year is 2019. On January 1, 2020, the formula would return what is currently in B68 (79,054). Both the column and the row could change over time and this is why I need a formula that can find the data I need. It is extremely unlikely that the wording that is currently in A68 (Old age security repayment threshold) will ever change.

Let me know if you need any further information. Thanks in advance to anyone who can help me take this one on!
 
You're welcome & thanks for the feedback
 
Upvote 0

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
Hi Fluff, I have able to use your formula successfully as a template on a couple of others but on this one, I am getting the error "You've entered too few arguments for this function". The table I am accessing is called OAS_GIS_web and it's shown below the formula that is giving me the error. The amount I am trying to return is in B3 (613.53). I tried it with and without the double quotes around the "Regardless..."

Code:
=INDEX(OAS_GIS_web[Maximum monthly payment amount],MATCH("Regardless of your marital situation"),OAS_GIS_web[Your situation],0))

Book1
ABC
1Your situationMaximum monthly payment amountMaximum annual income to receive the OAS pension Footnote 1
2Old Age Security (OAS) pensionOld Age Security (OAS) pensionOld Age Security (OAS) pension
3Regardless of your marital status613.53$126,058 (individual income)
4Guaranteed Income Supplement (GIS) amounts for individuals receiving a full Old Age Security (OAS) pension.Guaranteed Income Supplement (GIS) amounts for individuals receiving a full Old Age Security (OAS) pension.Guaranteed Income Supplement (GIS) amounts for individuals receiving a full Old Age Security (OAS) pension.
5If you are a single, widowed or divorced pensioner916.38$18,600 (individual income)
6If your spouse/common-law partner receives the full OAS pension551.63$24,576 (combined income)
7If your spouse/common-law partner does not receive an OAS pension916.38$44,592 (combined income)
8If your spouse/common-law partner receives the Allowance551.63$44,592 (combined income)
Sheet2
 
Upvote 0
You've got an extra bracket in there that doesn't belong, you need to remove it
"Regardless of your marital situation"),OAS_GIS_web
 
Upvote 0
I must be getting tired... Thank you SO much! I also realized that I had another typo in the formula... "Regardless of your marital situation" instead of "Regardless of your marital status" Thanks for your guidance and help!
 
Upvote 0
Fluff, hopefully, the last question related to your original formula. In the table below, we have successfully written two formulas that return the amounts that are currently in B3 and B5. I thought it would be easy to combine these two formulas in a SUM formula to add those two amounts together using the same logic, but my attempt at a formula returns $0.00 when it should return $1529.91. Can you help? Thanks!

Code:
=SUM(INDEX(OAS_GIS[Maximum monthly payment amount],MATCH("Regardless of your marital status",OAS_GIS[Your situation],0)),INDEX(OAS_GIS[Maximum monthly payment amount],MATCH("If you are a single, widowed or divorced pensioner",OAS_GIS[Your situation],0)))

Book1
ABC
1Your situationMaximum monthly payment amountMaximum annual income to receive the OAS pension Footnote 1
2Old Age Security (OAS) pensionOld Age Security (OAS) pensionOld Age Security (OAS) pension
3Regardless of your marital status613.53$126,058 (individual income)
4Guaranteed Income Supplement (GIS) amounts for individuals receiving a full Old Age Security (OAS) pension.Guaranteed Income Supplement (GIS) amounts for individuals receiving a full Old Age Security (OAS) pension.Guaranteed Income Supplement (GIS) amounts for individuals receiving a full Old Age Security (OAS) pension.
5If you are a single, widowed or divorced pensioner916.38$18,600 (individual income)
6If your spouse/common-law partner receives the full OAS pension551.63$24,576 (combined income)
7If your spouse/common-law partner does not receive an OAS pension916.38$44,592 (combined income)
8If your spouse/common-law partner receives the Allowance551.63$44,592 (combined income)
Sheet2
 
Upvote 0
That formula looks fine to me. It maybe that the values in col B are text, rather than numbers.
You could try
Code:
=SUM(--INDEX(OAS_GIS[Maximum monthly payment amount],MATCH("Regardless of your marital status",OAS_GIS[Your situation],0)),--INDEX(OAS_GIS[Maximum monthly payment amount],MATCH("If you are a single, widowed or divorced pensioner",OAS_GIS[Your situation],0)))
Note the two - signs before each index
 
Upvote 0
Works perfectly! Why would the two -- make a difference?

Thanks Fluff!
 
Upvote 0
They convert a number stored as text into a number.
 
Upvote 0

Forum statistics

Threads
1,223,099
Messages
6,170,111
Members
452,302
Latest member
TaMere

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