Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
1tntla
New Member

How to handle mixed data format in the same column

Hello guys,

 

There are 10 files in a folder.

They are all CSVs

They all have the same number of headers, in the same order, but different header names (eg: one is in Franch and the other is in Eng)

Issue is that when I combine all of them into a single table in PowerBI, the "Date" column has mixed formatting based on the region.

 

Example:

 

yyyy/mm/dd

yy/mm/dd

mm/dd/yyyy

 

etc. 

 

I could import them separately and correctly format the dates one by one and then combine them. However, is there a way to do this with all of them combined first?

 

Cheers,

 

Rok

 

 

2 REPLIES 2
MarcelBeug
Community Champion
Community Champion

Somehow you need to indicate the date format.

 

The code below contains a function embedded in sample code from an Excel file where datestrings are converted to dates based on an associated 3-letter sequence string (dmy, mdy, ymd or ydm, case insensitive) and date delimiters one of: slash (/), dash (-), period (.).

 

The year part must have 2 or 4 digits; in case of 2 digits it is assumed that the year is in this century (20yy).

The year part must be at the beginning or at the end (not in the middle).

The day and month parts may have 1 or 2 digits and may appear at any position.

 

let
    fnConvertDate = (DateString as text, Sequence as text) as date =>
    let
        Year1 = if Text.PositionOfAny(Sequence,{"y","Y"}) = 0 
                    then Text.Middle(DateString,0,4)
                    else Text.Middle(DateString,Text.PositionOfAny(DateString,{"/","-","."},Occurrence.Last)+1,4),

        Year2 = if Text.PositionOfAny(Year1,{"/","-","."}) = -1 
                    then Text.End("20"&Year1,4)
                    else Text.End("20"&Text.Start(Year1,Text.PositionOfAny(Year1,{"/","-","."})),4),

        Year = Number.From(Year2),

        Month1 = if Text.PositionOfAny(Sequence,{"m","M"}) = 0 
                    then Text.Middle(DateString,0,2)
                    else if Text.PositionOfAny(Sequence,{"m","M"}) = 1
                         then Text.Middle(DateString,Text.PositionOfAny(DateString,{"/","-","."})+1,2)
                         else Text.Middle(DateString,Text.PositionOfAny(DateString,{"/","-","."},Occurrence.Last)+1,2),

        Month = if Text.PositionOfAny(Month1,{"/","-","."}) = -1
                    then Number.From(Month1)
                    else Number.From(Text.Start(Month1,1)),

        Day1 = if Text.PositionOfAny(Sequence,{"d","D"}) = 0 
                    then Text.Middle(DateString,0,2)
                    else if Text.PositionOfAny(Sequence,{"d","D"}) = 1
                         then Text.Middle(DateString,Text.PositionOfAny(DateString,{"/","-","."})+1,2)
                         else Text.Middle(DateString,Text.PositionOfAny(DateString,{"/","-","."},Occurrence.Last)+1,2),

        Day = if Text.PositionOfAny(Day1,{"/","-","."}) = -1
                    then Number.From(Day1)
                    else Number.From(Text.Start(Day1,1))

    in
       #date(Year,Month,Day),

    Source = Excel.CurrentWorkbook(){[Name="DatesTable"]}[Content],
    Typed = Table.TransformColumnTypes(Source,{{"Dates", type text}, {"Sequence", type text}}),
    DateConverted = Table.AddColumn(Typed, "Date", each fnConvertDate([Dates],[Sequence]), type date)

in
    DateConverted
Specializing in Power Query Formula Language (M)

As far as I can see, Marcel's solution would work, if you manage to create a "Sequence"-column in the table that the "From-Folder" returns. So if you are able to describe the condition that identifies the format or merge with a lookup-table that contains that value, you could use this function.

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.