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
PBI_newuser
Post Prodigy
Post Prodigy

Inconsistent Date Format in excel file

Hi,

The excel file extracted from system has inconsistent date format.

If import to Power BI directly, Power BI will read those with "/" (eg. 8/31/2020) as MDY and those with "-" (eg. 08-11-20) as DMY.

 

Actually all should be read as MDY.


How can I solve this issue?

 

PBI_newuser_0-1603287648302.png

 

1 ACCEPTED SOLUTION

Hi @PBI_newuser ,

Please update the formula of calculated column [Formatted Date] as below:

Formatted Date = 
IF (
    IFERROR ( FIND ( "-", 'Sample'[Complete Date] ), 0 ) > 0,
    DATE ( CONCATENATE ( "20", RIGHT ( 'Sample'[Complete Date], 2 ) ), SWITCH (
        MID ( 'Sample'[Complete Date], 4, 3 ),
        "Jan", "1",
        "Feb", "2",
        "Mar", "3",
        "Apr", "4",
        "May", "5",
        "Jun", "6",
        "Jul", "7",
        "Aug", "8",
        "Sep", "9",
        "Oct", "10",
        "Nov", "11",
        "Dec", "12"
    ), LEFT ( 'Sample'[Complete Date], 2 ) ),
    DATEVALUE ( 'Sample'[Complete Date] )
)

Best Regards
Rena
Community Support Team _ Rena Ruan
If this post helps, then please consider Accept it as the solution to help the other members find it more.

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

5 REPLIES 5
PaulDBrown
Community Champion
Community Champion

@PBI_newuser 

In Power Query, select the column, select "Replace values" in the ribbon and swap the "-" for a "/"





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






v-yiruan-msft
Community Support
Community Support

Hi @PBI_newuser ,

Assue that the date field looks like the ones in the below screenshot, you can create a calculated column to format the date field. Then set the proper date format for it.

PBI_newuser_0-1603287648302.png


Formatted date = IF (
    IFERROR ( FIND ( "-", 'Table'[Paperwork Complete Date] ), 0 ) > 0,
    DATE ( CONCATENATE ( "20", RIGHT ( 'Table'[Paperwork Complete Date], 2 ) ), MID ( 'Table'[Paperwork Complete Date], 4, 2 ), LEFT ( 'Table'[Paperwork Complete Date], 2 ) ),
    IF (
        IFERROR ( FIND ( "/", 'Table'[Paperwork Complete Date] ), 0 ) > 0,
        DATE ( RIGHT ( 'Table'[Paperwork Complete Date], 4 ), MID ( 'Table'[Paperwork Complete Date], 3, 2 ), LEFT (
            'Table'[Paperwork Complete Date],
            IFERROR ( FIND ( "/", 'Table'[Paperwork Complete Date] ), 0 ) - 1
        ) )
    )
)

Set the proper date formatSet the proper date formatBest Regards
Rena
Community Support Team _ Rena Ruan
If this post helps, then please consider Accept it as the solution to help the other members find it more.

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Hi @v-yiruan-msft ,

I follow your steps but I got the below error.
"Cannot convert value 'Ja' of type Text to type Integer.

 

PBI_newuser_0-1603373529979.png

After importing the excel file to Power BI, the data appeared to be as below.

PBI_newuser_0-1603373768264.png

 

Sample pbix:

https://wetransfer.com/downloads/fe73bebb842f94621d99ab533a13dcc220201022134225/ee50d29242a06bb91e5c...

 

Hi @PBI_newuser ,

Please update the formula of calculated column [Formatted Date] as below:

Formatted Date = 
IF (
    IFERROR ( FIND ( "-", 'Sample'[Complete Date] ), 0 ) > 0,
    DATE ( CONCATENATE ( "20", RIGHT ( 'Sample'[Complete Date], 2 ) ), SWITCH (
        MID ( 'Sample'[Complete Date], 4, 3 ),
        "Jan", "1",
        "Feb", "2",
        "Mar", "3",
        "Apr", "4",
        "May", "5",
        "Jun", "6",
        "Jul", "7",
        "Aug", "8",
        "Sep", "9",
        "Oct", "10",
        "Nov", "11",
        "Dec", "12"
    ), LEFT ( 'Sample'[Complete Date], 2 ) ),
    DATEVALUE ( 'Sample'[Complete Date] )
)

Best Regards
Rena
Community Support Team _ Rena Ruan
If this post helps, then please consider Accept it as the solution to help the other members find it more.

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Anonymous
Not applicable

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.