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]
 

sandy666

Well-known Member
Joined
Oct 24, 2015
Messages
3,837
try PowerQuery (Get&Transform)

sourceDateDays
RRULE:FREQ=WEEKLY;WKST=MO;UNTIL=20190627;BYDAY=SA,TH20190627SA,TH

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:

FormR

MrExcel MVP
Joined
Aug 18, 2011
Messages
6,220
Office Version
365
Platform
Windows
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.

<b>Excel 2013/2016</b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>A</th><th>B</th><th>C</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">2</td><td style=";">RRULE:FREQ=WEEKLY;WKST=MO;UNTIL=20190627;BYDAY=SA,TH</td><td style="text-align: right;;">27/06/2019</td><td style=";">SA,TH</td></tr></tbody></table><p style="width:4.8em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Sheet1</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: rgb(255,255,255)" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: rgb(255,255,255);border-collapse: collapse; border-color: rgb(187,187,187)"><thead><tr style=" background-color: rgb(218,231,245);color: rgb(22,17,32)"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">B2</th><td style="text-align:left">=0+TEXT(<font color="Blue">MID(<font color="Red">A2,FIND(<font color="Green">"UNTIL=",A2</font>)+6,8</font>),"0000-00-00"</font>)</td></tr><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">C2</th><td style="text-align:left">=TRIM(<font color="Blue">RIGHT(<font color="Red">SUBSTITUTE(<font color="Green">A2,"=",REPT(<font color="Purple">" ",255</font>)</font>),255</font>)</font>)</td></tr></tbody></table></td></tr></table><br />
 

Forum statistics

Threads
1,082,380
Messages
5,365,124
Members
400,824
Latest member
Themilkybarkid

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top