Return Value In Another Cell Based on Notation and Date

MrDB4Excel

Active Member
Joined
Jan 29, 2004
Messages
334
Office Version
  1. 2013
Platform
  1. Windows
Based upon the notation "rd" in column "A" and the associated date in column "B" I want to get the value in column "G" and have it populate the corresponding cell on sheet "2020 BudgetSheet" in column "E".
The corresponding formula in the relevant cell in column "E" of the "2020 BudgetSheet" is where the vlookup formula resides, thereby retrieving the value in column "G" in the corresponding dated cell per the relevant month on sheet "Example1".
Is this doable without VBA?
Obviously these payment amounts, deposit amounts, debit amounts, income amounts, transaction descriptions, and bank balances are all bogus, entered here as such for explanation purposes only. Thus no private information is contained in this workbook.

Range capture from "Example1" sheet

Return Value In Another Cell.xlsx
ABCDEFGHIJ
1NUMBER OR CODEDateTRANSACTION DESCRIPTIONPAYMENT AMOUNTüüDEPOSIT AMOUNT or returnsBALANCE
2DebitCredit
3$10,000.00Based upon the notation "rd" in column "A" and the associated date in column "B" I want to get the value in column "G" and have it populate the corresponding cell on sheet "2020 BudgetSheet" in column "E". The corresponding formula in the relevant cell in column "E" of the "2020 BudgetSheet" is where the vlookup formula resides, thereby retrieving the value in column "G" in the corresponding dated cell per the relevant month on sheet "Example1". Is this doable without VBA? Obviously these payment amounts, deposit amounts, debit amounts, income amounts, transaction descriptions, and bank balances are all bogus, entered here as such for explanation purposes only. Thus no private information is contained in this workbook.
4rdJan/06/2020$3,000.00$13,000.00
5ebpJan/11/2020$500.00$12,500.00
6ebpJan/14/2020$500.00$12,000.00
7ebpJan/14/2020$500.00$11,500.00
8ebpJan/14/2020$500.00$11,000.00
9$11,000.00
10rdFeb/05/2020$3,000.00$14,000.00
11ebpFeb/10/2020$500.00$13,500.00
12ebpFeb/14/2020$500.00$13,000.00
13ebpFeb/14/2020$500.00$12,500.00
14$12,500.00
15rdMar/05/2020$3,000.00$15,500.00
16ebpMar/10/2020$500.00$15,000.00
17ebpMar/13/2020$500.00$14,500.00
18ebpMar/13/2020$500.00$14,000.00
Example1
Cell Formulas
RangeFormula
H4,H15,H10H4=SUM(H3+G4)
H16:H18,H11:H14,H5:H9H5=SUM(H4-D5)



Range capture from "2020 BudgetSheet" sheet

Return Value In Another Cell.xlsx
ABCDEFG
1MonthDateDescriptionCategoryIncomeDebitsRunning Balance
21Jan/01/2020Bank Balance @ Beginning of January 2020Bank Balance$10,000.00
31Jan/01/2020Income For January 2020Income$3,000.00$13,000.00
41Jan/01/2020Building UtilityBuilding Utility$100.00$12,900.00
51Jan/01/2020ElectricElectric$100.00$12,800.00
61Jan/01/2020Cell Phone Service #1Mobile Phone$100.00$12,700.00
71Jan/01/2020Cell Phone Service #2Mobile Phone$100.00$12,600.00
81Jan/01/2020ProductProduct$100.00$12,500.00
91Jan/01/2020RestaurantRestaurant$100.00$12,400.00
101Jan/01/2020InternetInternet$100.00$12,300.00
111Jan/01/2020Property TaxesProperty Taxes$100.00$12,200.00
121Jan/01/2020Basement StorageBasement Storage$100.00$12,100.00
131Jan/01/2020MiscellaneousMiscellaneous$100.00$12,000.00
141Jan/01/2020Medical/ Health CareMedical$100.00$11,900.00
151Jan/01/2020Bank Account ChargesMisc Expenses$100.00$11,800.00
161Jan/01/2020Train FareMisc Expenses$100.00$11,700.00
171Jan/01/2020Bus FareMisc Expenses$100.00$11,600.00
182Feb/01/2020Bank Balance @ Beginning of February 2020Bank Balance$11,600.00
192Feb/01/2020Income For February 2020Income$3,000.00$14,600.00
202Feb/01/2020Building UtilityBuilding Utility$100.00$14,500.00
212Feb/01/2020ElectricElectric$100.00$14,400.00
222Feb/01/2020Cell Phone Service #1Mobile Phone$100.00$14,300.00
232Feb/01/2020Cell Phone Service #2Mobile Phone$100.00$14,200.00
242Feb/01/2020ProductProduct$100.00$14,100.00
252Feb/01/2020RestaurantRestaurant$100.00$14,000.00
262Feb/01/2020InternetInternet$100.00$13,900.00
272Feb/01/2020Property TaxesProperty Taxes$100.00$13,800.00
282Feb/01/2020Basement StorageBasement Storage$100.00$13,700.00
292Feb/01/2020MiscellaneousMiscellaneous$100.00$13,600.00
302Feb/01/2020Medical/ Health CareMedical$100.00$13,500.00
312Feb/01/2020Bank Account ChargesMisc Expenses$100.00$13,400.00
322Feb/01/2020Train FareMisc Expenses$100.00$13,300.00
332Feb/01/2020Bus FareMisc Expenses$100.00$13,200.00
343Mar/01/2020Bank Balance @ Beginning of March 2020Bank Balance$13,200.00
353Mar/01/2020Income For March 2020Income$3,000.00$16,200.00
363Mar/01/2020Building UtilityBuilding Utility$100.00$16,100.00
373Mar/01/2020ElectricElectric$100.00$16,000.00
383Mar/01/2020Cell Phone Service #1Mobile Phone$100.00$15,900.00
393Mar/01/2020Cell Phone Service #2Mobile Phone$100.00$15,800.00
403Mar/01/2020ProductProduct$100.00$15,700.00
413Mar/01/2020RestaurantRestaurant$100.00$15,600.00
423Mar/01/2020InternetInternet$100.00$15,500.00
433Mar/01/2020Property TaxesProperty Taxes$100.00$15,400.00
443Mar/01/2020Basement StorageBasement Storage$100.00$15,300.00
453Mar/01/2020MiscellaneousMiscellaneous$100.00$15,200.00
463Mar/01/2020Medical/ Health CareMedical$100.00$15,100.00
473Mar/01/2020Bank Account ChargesMisc Expenses$100.00$15,000.00
483Mar/01/2020Train FareMisc Expenses$100.00$14,900.00
493Mar/01/2020Bus FareMisc Expenses$100.00$14,800.00
504Apr/01/2020Bank Balance @ Beginning of April 2020Bank Balance$14,800.00
514Apr/01/2020Income For April 2020Income$3,000.00$17,800.00
2020 BudgetSheet
Cell Formulas
RangeFormula
C2,C50,C34,C18C2="Bank Balance @ Beginning of "&TEXT(B2,"MMMM")&TEXT(B2," YYYY")
C3,C51,C35,C19C3="Income For "&TEXT(B3,"MMMM")&TEXT(B3," YYYY")
G3,G51,G35,G19G3=SUM(E2,E3)
G36:G49,G20:G33,G4:G17G4=SUM(G3-F4)
E18,E50,E34E18=G17
A2:A51A2=MONTH('2020 BudgetSheet'!$B2)
Cells with Data Validation
CellAllowCriteria
D1:D51List=ValidationList
 

Excel Facts

Add Bullets to Range
Select range. Press Ctrl+1. On Number tab, choose Custom. Type Alt+7 then space then @ sign (using 7 on numeric keypad)
Firstly a couple of comments.
  • Please don't write long-winded question descriptions within the worksheet when using XL2BB. It does not go well when helpers copy to their worksheets.
  • It can be a bad idea to use the worksheet name in a formula on that same worksheet. It can cause sorting the worksheet to not work correctly. I am referring to your column A formulas in '2020 BudgetSheet'.There is an example of the problem here.

Does this formula in E3 (& copied to E19, E35 etc) of '2020 BudgetSheet' do what you want?
Excel Formula:
=INDEX(Example1!G:G,AGGREGATE(15,6,ROW(Example1!G$4:G$200)/((Example1!A$4:A$200="rd")*(TEXT(Example1!B$4:B$200,"mmyy")=TEXT(B2,"mmyy"))),1))
 
Upvote 0
Firstly a couple of comments.
  • Please don't write long-winded question descriptions within the worksheet when using XL2BB. It does not go well when helpers copy to their worksheets.
  • It can be a bad idea to use the worksheet name in a formula on that same worksheet. It can cause sorting the worksheet to not work correctly. I am referring to your column A formulas in '2020 BudgetSheet'.There is an example of the problem here.

Does this formula in E3 (& copied to E19, E35 etc) of '2020 BudgetSheet' do what you want?
Excel Formula:
=INDEX(Example1!G:G,AGGREGATE(15,6,ROW(Example1!G$4:G$200)/((Example1!A$4:A$200="rd")*(TEXT(Example1!B$4:B$200,"mmyy")=TEXT(B2,"mmyy"))),1))
Many thanks, Peter_SSs, works perfectly. Now I am trying to adapt this formula to 2 separate workbooks whereby I replace Example1 (the sheet in the workbook in my original post) with a sheet 2020 in workbook 2015_CSOB-CZK.xlsx
This is what I am trying, but does not work. Any suggestions would be much appreciated.
=INDEX([2015_CSOB-CZK.xlsx]'2020'!G:G,AGGREGATE(15,6,ROW([2015_CSOB-CZK.xlsx]'2020'!G$4:G$200)/(([2015_CSOB-CZK.xlsx]'2020'!A$4:A$200="rd")*(TEXT([2015_CSOB-CZK.xlsx]'2020'!B$4:B$200,"mmyy")=TEXT(B2,"mmyy"))),1))
This is the message that comes from this attempt:
1608274858089.png

Tried removing the [ and ] brackets surrounding 2015_CSOB-CZK.xlsx and it gives this message.
1608274994485.png
 
Upvote 0
In each of the references to the other workbook, you have the first single quote mark in the wrong place
In each reference you have single quotes like this
[2015_CSOB-CZK.xlsx]'2020'!

It should be
'[2015_CSOB-CZK.xlsx]2020'!
 
Upvote 0
In each of the references to the other workbook, you have the first single quote mark in the wrong place
In each reference you have single quotes like this
[2015_CSOB-CZK.xlsx]'2020'!

It should be
'[2015_CSOB-CZK.xlsx]2020'!
Excellent Peter, that did the trick. Again thank you so much. Always a pleasure working with you guys on Mr. Excel
 
Upvote 0
Excellent Peter, that did the trick. Again thank you so much. Always a pleasure working with you guys on Mr. Excel
Excellent Peter, that did the trick. Again thank you so much. Always a pleasure working with you guys & gals on Mr. Excel
 
Upvote 0
You're welcome. Thanks for the follow-up. :)
 
Upvote 0

Forum statistics

Threads
1,214,833
Messages
6,121,857
Members
449,051
Latest member
excelquestion515

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