Listing Data based on Dates

soumen21

New Member
Joined
Aug 16, 2019
Messages
17
Hi, I have a set of data like this

AAA2-May-20
BBB18-Jun-20
CCC29-Mar-20
DDD9-Feb-21
EEE9-Feb-22
FFF9-Feb-20
GGG9-Feb-23
HHH9-Feb-20
JJJ27-Feb-28
KKK2-Jan-27
MMM14-Oct-21
NNN15-Oct-19

<tbody>
</tbody>

I want to sort it like this

Before 2020Between 2020-20222023 and after
NNNFFFGGG
HHHKKK
CCCJJJ
AAA
BBB
DDD
MMM
EEE

<tbody>
</tbody>
Any formula to do that?

Regards
Soumen
 
Last edited:

Some videos you may like

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying

alansidman

Well-known Member
Joined
Feb 26, 2007
Messages
5,852
Office Version
  1. 2019
Platform
  1. Windows
Using Power Query/Get and Transform, here is Mcode

Code:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column2", type date}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1),
    #"Pivoted Column" = Table.Pivot(Table.TransformColumnTypes(#"Added Index", {{"Column3", type text}}, "en-US"), List.Distinct(Table.TransformColumnTypes(#"Added Index", {{"Column3", type text}}, "en-US")[Column3]), "Column3", "Column1"),
    #"Removed Columns" = Table.RemoveColumns(#"Pivoted Column",{"Column2", "Index"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Columns",{"2019", "2020", "2021", "2022", "2023", "2028", "2027"}),
    #"Replaced Value" = Table.ReplaceValue(#"Reordered Columns",null,"0",Replacer.ReplaceValue,{"2019", "2020", "2021", "2022", "2023", "2028", "2027"}),
    #"Added Custom" = Table.AddColumn(#"Replaced Value", "Custom", each [2020] & [2021] & [2022]),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Custom.1", each [2023] & [2028] &[2027]),
    #"Replaced Value1" = Table.ReplaceValue(#"Added Custom1","0"," ",Replacer.ReplaceText,{"Custom", "Custom.1"}),
    #"Renamed Columns" = Table.RenameColumns(#"Replaced Value1",{{"2019", "Before 2020"}}),
    #"Removed Columns1" = Table.RemoveColumns(#"Renamed Columns",{"2020", "2021", "2022", "2023", "2028", "2027"}),
    #"Renamed Columns1" = Table.RenameColumns(#"Removed Columns1",{{"Custom", "2020-2022"}, {"Custom.1", "After 2022"}}),
    #"Replaced Value2" = Table.ReplaceValue(#"Renamed Columns1","0"," ",Replacer.ReplaceText,{"Before 2020"}),
    #"Trimmed Text" = Table.TransformColumns(#"Replaced Value2",{{"2020-2022", Text.Trim, type text}, {"After 2022", Text.Trim, type text}})
in
    #"Trimmed Text"

Data Range
A
B
C
1
Before 2020​
2020-2022​
After 2022​
2
NNN​
3
FFF​
4
HHH​
5
CCC​
6
AAA​
7
BBB​
8
DDD​
9
MMM​
10
EEE​
11
GGG​
12
KKK​
13
JJJ​

If you are unsure about Power Query, then click on the link in my signature.
 

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
12,593
Office Version
  1. 2007
Platform
  1. Windows
Try this array formulas

<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:76.04px;" /><col style="width:91.25px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td><td >F</td></tr><tr style="height:47px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">VALUE</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">DATE</td><td > </td><td style="background-color:#ffff00; color:#333333; font-weight:bold; font-family:Verdana; font-size:9pt; text-align:center; ">Before 2020</td><td style="background-color:#ffff00; color:#333333; font-weight:bold; font-family:Verdana; font-size:9pt; text-align:center; ">Between 2020-2022</td><td style="background-color:#ffff00; color:#333333; font-weight:bold; font-family:Verdana; font-size:9pt; text-align:center; ">2023 and after</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">AAA</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; text-align:right; ">02-may-2020</td><td > </td><td >NNN</td><td >AAA</td><td >GGG</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">BBB</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; text-align:right; ">18-jun-2020</td><td > </td><td > </td><td >BBB</td><td >JJJ</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">CCC</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; text-align:right; ">29-mar-2020</td><td > </td><td > </td><td >CCC</td><td >KKK</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">DDD</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; text-align:right; ">09-feb-2021</td><td > </td><td > </td><td >DDD</td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">EEE</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; text-align:right; ">09-feb-2022</td><td > </td><td > </td><td >EEE</td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">FFF</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; text-align:right; ">09-feb-2020</td><td > </td><td > </td><td >FFF</td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >8</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">GGG</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; text-align:right; ">09-feb-2023</td><td > </td><td > </td><td >HHH</td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >9</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">HHH</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; text-align:right; ">09-feb-2020</td><td > </td><td > </td><td >MMM</td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >10</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">JJJ</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; text-align:right; ">27-feb-2028</td><td > </td><td > </td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >11</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">KKK</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; text-align:right; ">02-ene-2027</td><td > </td><td > </td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >12</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">MMM</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; text-align:right; ">14-oct-2021</td><td > </td><td > </td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >13</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">NNN</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; text-align:right; ">15-oct-2019</td><td > </td><td > </td><td > </td><td > </td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Array Formula</td></tr><tr><td >D2</td><td >{=IFERROR(INDEX($A$1:$A$13, SMALL(IF(YEAR($B$2:$B$13)<2020, ROW()), ROW()-1)),"")}</td></tr><tr><td >E2</td><td >{=IFERROR(INDEX($A$1:$A$13, SMALL(IF((YEAR($B$2:$B$13)>=2020)*(YEAR($B$2:$B$13)<=2022), ROW()), ROW()-1)),"")}</td></tr><tr><td >F2</td><td >{=IFERROR(INDEX($A$1:$A$13, SMALL(IF(YEAR($B$2:$B$13)>2022, ROW()), ROW()-1)),"")}</td></tr></table></td></tr></table>

Array formulas
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself.

Example:
- Copy the following formula in cell D2 copy down to D13
=SI.ERROR(INDICE($A$1:$A$13, K.ESIMO.MENOR(SI(AÑO($B$2:$B$13)<2020, FILA()), FILA()-1)),"")

- Select cells D2 to D13
- Press F2 to edit formula
- Press Ctrl+Shift+Enter

=SI.ERROR(INDICE($A$1:$A$13, K.ESIMO.MENOR(SI(AÑO($B$2:$B$13)<2020, FILA()), FILA()-1)),"")

- Repeat the same for formulas E2 and F2
 

Watch MrExcel Video

Forum statistics

Threads
1,108,768
Messages
5,524,784
Members
409,600
Latest member
Dunnowhatfor

This Week's Hot Topics

Top