Extract text from text string

aslante

New Member
Joined
Jul 6, 2015
Messages
2
I have a text string that looks like this:

[FONT=&quot]RRULE:FREQ=WEEKLY;WKST=MO;UNTIL=[/FONT][FONT=&quot]20190627[/FONT][FONT=&quot];BYDAY=[/FONT][FONT=&quot]SA,TH[/FONT][FONT=&quot]

I want to extract

1) the text in red which is essentially a date. After extracting it, it should convert into dd/mm/yyyy (06/06/2019) format.

2) the text in blue which are the days

Any help is greatly appreciated!

Thanks in advance!


[/FONT]
 

Excel Facts

Who is Mr Spreadsheet?
Author John Walkenbach was Mr Spreadsheet until his retirement in June 2019.
try PowerQuery (Get&Transform)

[Table="width:, class:head"]
[tr=bgcolor:#FFFFFF][td=bgcolor:#5B9BD5]source[/td][td][/td][td=bgcolor:#70AD47]Date[/td][td=bgcolor:#70AD47]Days[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]RRULE:FREQ=WEEKLY;WKST=MO;UNTIL=20190627;BYDAY=SA,TH[/td][td][/td][td=bgcolor:#E2EFDA]20190627[/td][td=bgcolor:#E2EFDA]SA,TH[/td][/tr]
[/table]


Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Between = Table.AddColumn(Source, "Date", each Text.BetweenDelimiters([source], "UNTIL=", ";"), type text),
    After = Table.AddColumn(Between, "Days", each Text.AfterDelimiter([source], "=", {0, RelativePosition.FromEnd}), type text),
    ROC = Table.SelectColumns(After,{"Date", "Days"})
in
    ROC[/SIZE]
 
Last edited:
Upvote 0
Hi, it's usually best to give a few varying examples of the strings with these types of questions.

Here are some formula based options you can try. For the date field you can format as desired.


Excel 2013/2016
ABC
2RRULE:FREQ=WEEKLY;WKST=MO;UNTIL=20190627;BYDAY=SA,TH27/06/2019SA,TH
Sheet1
Cell Formulas
RangeFormula
B2=0+TEXT(MID(A2,FIND("UNTIL=",A2)+6,8),"0000-00-00")
C2=TRIM(RIGHT(SUBSTITUTE(A2,"=",REPT(" ",255)),255))
 
Upvote 0

Forum statistics

Threads
1,223,214
Messages
6,170,772
Members
452,353
Latest member
strainu

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