Finding 1st, 2nd, 3rd... Nth value by excel formula (vlookup/if/macth..)

jgopalk

New Member
Joined
Jun 14, 2011
Messages
26
Hi there,

I just wanted to fix the following problem that last few days struck my work.

Data:
ABCDEFGHIJK
110/5/2016RAM10/5/2016RAMRAHIMSUJA0000
210/5/2016RAHIM10/6/2016RAMRAHIMSUJASANGEETHA000
310/5/2016SUJA10/10/2016RAMRAHIMSUJASANGEETHAJOHN00
410/6/2016RAM
510/6/2016RAHIM
610/6/2016SUJA
710/6/2016SANGEETHA
810/10/2016RAM
910/10/2016RAHIM
1010/10/2016SUJA
1110/10/2016SANGEETHA
1210/10/2016JOHN

<tbody>
</tbody>

Black font is available data and red colour font is required data by formula.

This is for huge data so we can not change formula each time and each look up cells. kindly try to fix it by formulas and not by<acronym title="visual basic for applications" style="border-width: 0px 0px 1px; border-bottom-style: dotted; border-bottom-color: rgb(0, 0, 0); cursor: help;">VBA</acronym> code..

Kindly check and fix it.

Thanks,
Gopal
 

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)
The names i have given in order. But it is not the exact case. Names might be interchanged.
 
Upvote 0
If you don't mind the use of a helper column (I would recommend using it), then perhaps the below would work for you.

Excel Workbook
ABCDEFGHIJKL
1HelperDateName*DatesNamesNamesNamesNamesNamesNamesNames
242648-110/5/2016RAM*10/5/2016RAMRAHIMSUJA0000
342648-210/5/2016RAHIM*10/6/2016RAMRAHIMSUJASANGEETHA000
442648-310/5/2016SUJA*10/10/2016RAMRAHIMSUJASANGEETHAJOHN00
542649-110/6/2016RAM*********
642649-210/6/2016RAHIM*********
742649-310/6/2016SUJA*********
842649-410/6/2016SANGEETHA*********
942653-110/10/2016RAM*********
1042653-210/10/2016RAHIM*********
1142653-310/10/2016SUJA*********
1242653-410/10/2016SANGEETHA*********
1342653-510/10/2016JOHN*********
Sheet3
 
Last edited:
Upvote 0
Thank you very much Mr. Virus :)

It is awesome. This is what I was expecting. Great work.

Thanks,
Gopal
 
Upvote 0
Without a helper column ..

D2 is copied down.
E2 is copied across and down.


Excel 2010 32 bit
ABCDEFGHIJK
1DateNameDatesNames
25/10/2016RAM5/10/2016RAMRAHIMSUJA0000
35/10/2016RAHIM6/10/2016RAMRAHIMSUJASANGEETHA000
45/10/2016SUJA10/10/2016RAMRAHIMSUJASANGEETHAJOHN00
56/10/2016RAM
66/10/2016RAHIM
76/10/2016SUJA
86/10/2016SANGEETHA
910/10/2016RAM
1010/10/2016RAHIM
1110/10/2016SUJA
1210/10/2016SANGEETHA
1310/10/2016JOHN
14
List by date
Cell Formulas
RangeFormula
D2=IF(D1="","",IF(D1=MAX(A$2:A$13),"",SMALL(A$2:A$13,COUNTIF(A$2:A$13,"<="&D1)+1)))
E2=IF($D2="","",IF(COLUMNS($E2:E2)>COUNTIF($A$2:$A$13,$D2),0,INDEX($B$2:$B$13,MATCH($D2,$A$2:$A$13,0)+COLUMNS($E2:E2)-1)))
 
Upvote 0

Forum statistics

Threads
1,214,653
Messages
6,120,750
Members
448,989
Latest member
mariah3

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