Results 1 to 1 of 1

Thread: PQ - transform text string to proper date

Hybrid View

Previous Post Previous Post   Next Post Next Post
  1. #1
    Sir Moderator sandy666's Avatar
    Join Date
    May 2018
    Posts
    238
    Rep Power
    7

    Cool PQ - transform text string to proper date

    Text Text Date
    02012021 02012021
    02/01/2021


    Code:
    // Table1
    let
        //(CC)sandy666
        Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
        Date = Table.AddColumn(Source, "Date", each 
            Date.FromText
            (
            Text.Format("#[day]/#[month]/#[year]", 
                [
                day = Text.Start([Text],2), 
                month = Text.Middle([Text],2,2), 
                year = Text.End([Text],4) 
                ], 
            "en-GB")
            ),
        type date)
    in
        Date
    Let's break down the code step by step:

    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content]

    This line assigns the content of the table named "Table1" in the current workbook to the variable named "Source". It retrieves the data from the table.
    Date = Table.AddColumn(Source, "Date", each ...)
    This line creates a new column named "Date" in the "Source" table using the "Table.AddColumn" function. The values in this new column will be calculated using the expression specified within the "each" keyword.
    Date.FromText(...)
    This is a function that converts a text value into a date value. It takes the following arguments:
    Text.Format(...) - This function formats a text string using a specified pattern. It takes two arguments:
    The pattern: "#[day]/#[month]/#[year]"
    The values to replace the placeholders in the pattern. In this case, it uses the values extracted from the "Text" column:
    day = Text.Start([Text],2) - This extracts the first 2 characters from the "Text" column, representing the day.
    month = Text.Middle([Text],2,2) - This extracts the middle 2 characters from the "Text" column starting from the third character, representing the month.
    year = Text.End([Text],4) - This extracts the last 4 characters from the "Text" column, representing the year.
    "en-GB" - This specifies the locale or language (English - Great Britain) for the date format.
    type date
    This line specifies that the result of the previous expression should be of type "date", ensuring that the values in the "Date" column are treated as date values.
    in Date
    This line specifies the expression to return as the result of the entire formula, which is the "Date" column created in step 2.

    Overall, this formula extracts the day, month, and year from the "Text" column, formats them into a date string using the specified pattern, and then converts the formatted string into date values. The resulting date values are stored in the newly created "Date" column of the "Table1" table.
    Last edited by sandy666; 07-12-2023 at 01:20 AM.
    sandy
    I know you know but I forgot my Crystal Ball and don't know what you know also I may not remember what I did weeks, months or years ago so answer asap. Thinking doesn't hurt

Similar Threads

  1. Replies: 109
    Last Post: 03-29-2024, 07:01 PM
  2. Extract Only Numbers & TEXT From Text String
    By mahmoud-lee in forum Excel Help
    Replies: 9
    Last Post: 11-02-2013, 02:49 PM
  3. Replies: 7
    Last Post: 08-29-2013, 12:01 PM
  4. VBA Macro To Convert Text To Proper Case
    By Howardc in forum Excel Help
    Replies: 4
    Last Post: 05-31-2013, 12:38 AM
  5. Find the First or Last So Many Words in a Text String
    By Rick Rothstein in forum Rick Rothstein's Corner
    Replies: 6
    Last Post: 06-21-2012, 09:42 PM

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •