hardeep.kanwar

Well-known Member
Joined
Aug 13, 2008
Messages
691
Hi Experts

I need to extract Invoice number and Dates in two Columns i.e. Invoice Number and Dates (DD-MMM-YY) format.

I can use text to column but the problem is that every cell have different range or length.

Can you Please help on this.

Invoice Number
P-03/18-485 / 31-3-2018
P-03/18-486 / 31-3-2018
A-02-2018 / 4-4-2018
A-01-2018 / 4-4-2018
A-03-2018 / 4-4-2018
P-04/18-015 / 10-4-2018
P-04/18-016 / 10-4-2018
74/INC 2017-18 / 11-4-2018
18-19-1005 / 13-4-2018
18-19-1006 / 13-4-2018
SA/18-19/06 / 16-4-2018
916 / 29-3-2018
917 / 29-3-2018
918 / 29-3-2018
919 / 29-3-2018
LC GS 06/2018-2019 / 17-5-2018
LC GS 12/2018-2019 / 17-5-2018
DIP-2018-19-002 / 21-5-2018
BBMA/18-19/030 / 11-7-2018

<colgroup><col></colgroup><tbody>
</tbody>
 

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.
This is a simple column Split in Power Query. Here is the Mcode for that exercise

Code:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Invoice Number", type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "Invoice Number", Splitter.SplitTextByEachDelimiter({"/"}, QuoteStyle.Csv, true), {"Invoice Number.1", "Invoice Number.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Invoice Number.1", type text}, {"Invoice Number.2", type text}}),
    #"Renamed Columns" = Table.RenameColumns(#"Changed Type1",{{"Invoice Number.2", "DATE"}}),
    #"Trimmed Text" = Table.TransformColumns(#"Renamed Columns",{{"DATE", Text.Trim, type text}})
in
    #"Trimmed Text"
 
Upvote 0
first: there is Excel 2007
second: enough Split by " / " (space/space) :)

as example:
Code:
let
    Source = Excel.CurrentWorkbook(){[Name="Table3"]}[Content],
    Split = Table.SplitColumn(Source, "Invoice Number", Splitter.SplitTextByDelimiter(" / ", QuoteStyle.Csv), {"Invoice Number", "Date"}),
    Type = Table.TransformColumnTypes(Split,{{"Invoice Number", type text}, {"Date", type date}})
in
    Type

Invoice NumberDate
P-03/18-485
31/03/2018​
P-03/18-486
31/03/2018​
A-02-2018
04/04/2018​
A-01-2018
04/04/2018​
A-03-2018
04/04/2018​
P-04/18-015
10/04/2018​
P-04/18-016
10/04/2018​
74/INC 2017-18
11/04/2018​
18-19-1005
13/04/2018​
18-19-1006
13/04/2018​
SA/18-19/06
16/04/2018​
916
29/03/2018​
917
29/03/2018​
918
29/03/2018​
919
29/03/2018​
LC GS 06/2018-2019
17/05/2018​
LC GS 12/2018-2019
17/05/2018​
DIP-2018-19-002
21/05/2018​
BBMA/18-19/030
11/07/2018​
 
Last edited:
Upvote 0
with formula:

F
G
H
I
1
Invoice numberDate
2
P-03/18-48531-3-2018F2:=LEFT(A2,SEARCH(" /",A2)-1)
3
P-03/18-48631-3-2018
4
A-02-20184-4-2018G2:=MID(SUBSTITUTE(A2,F2,""),4,999)
5
A-01-20184-4-2018
6
A-03-20184-4-2018
7
P-04/18-01510-4-2018
8
P-04/18-01610-4-2018
9
74/INC 2017-1811-4-2018
10
18-19-100513-4-2018
11
18-19-100613-4-2018
12
SA/18-19/0616-4-2018
13
91629-3-2018
14
91729-3-2018
15
91829-3-2018
16
91929-3-2018
17
LC GS 06/2018-201917-5-2018
18
LC GS 12/2018-201917-5-2018
19
DIP-2018-19-00221-5-2018
20
BBMA/18-19/03011-7-2018
 
Last edited:
Upvote 0
Thanks for the Help sandy666 and alansidman

I have no idea about Power query but seems if very useful ,will try my best to learn this function

Sandy666 your formula help me lot
 
Upvote 0
Power Query. Look at this book. M is for (Data) Monkey by Ken Puls and Miguel Escobar. Very good learning tool.
 
Upvote 0

Forum statistics

Threads
1,213,517
Messages
6,114,085
Members
448,548
Latest member
harryls

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