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

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
kruizing
Frequent Visitor

Split two kinds of data in one colums into two columns

Hi!

I have two types of data from my electricity meter in one column. You can find an example of what the table looks like in the first table below. I would like to have the data of the meter split into two columns, like in the second table.

Does anyone have a solution for this?

 

Kinds regards!

 

Date/TimeMeter 1_2
26-10-2020 01:00

200

26-10-2020 02:00215
26-10-2020 03:00220
26-10-2020 04:0050
26-10-2020 05:0055
26-10-2020 06:00225
26-10-2020 07:0060
26-10-2020 08:00230
26-10-2020 09:0065

 

Date/TimeMeter 1Meter 2
26-10-2020 01:00

200

50

26-10-2020 02:0021550
26-10-2020 03:0022050
26-10-2020 04:00

220

50
26-10-2020 05:0022055
26-10-2020 06:0022555
26-10-2020 07:0022560
26-10-2020 08:0023060
26-10-2020 09:0023065

 

1 ACCEPTED SOLUTION
Jimmy801
Community Champion
Community Champion

Hello @kruizing 

 

what is the logic of the split?

How do you get at the data of 01:00 from this

Jimmy801_0-1603701494634.png

 

to this?

Jimmy801_1-1603701520653.png

the only logic I found is this... but I don't know if suits

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Zcy7CcAwDIThVYJqG6RzpDxWMd5/DRusFOGaaz7u710Q1bRCoYfaqypFsHaUPyHJnKglgV/nJmfxFM7Fl2O6NgXn7jw1pidPKzcm", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Date/Time" = _t, #"Meter 1_2" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date/Time", type datetime}, {"Meter 1_2", Int64.Type}}),
    TransfromMeter = Table.TransformColumns
    (
        #"Changed Type",
        {
            {
                "Meter 1_2",
                each if _>100 then Text.From(_)&",0" else "0,"&Text.From(_)
            }
        }
    ),
    #"Split Column by Delimiter" = Table.SplitColumn(TransfromMeter, "Meter 1_2", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Meter 1_2.1", "Meter 1_2.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Meter 1_2.1", Int64.Type}, {"Meter 1_2.2", Int64.Type}}),
    #"Replaced Value" = Table.ReplaceValue(#"Changed Type1",0,null,Replacer.ReplaceValue,{"Meter 1_2.1", "Meter 1_2.2"}),
    #"Filled Down" = Table.FillDown(#"Replaced Value",{"Meter 1_2.1"}),
    #"Filled Up" = Table.FillUp(#"Filled Down",{"Meter 1_2.2"})
in
   #"Filled Up"

 

Jimmy801_2-1603701803807.png

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

 

View solution in original post

1 REPLY 1
Jimmy801
Community Champion
Community Champion

Hello @kruizing 

 

what is the logic of the split?

How do you get at the data of 01:00 from this

Jimmy801_0-1603701494634.png

 

to this?

Jimmy801_1-1603701520653.png

the only logic I found is this... but I don't know if suits

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Zcy7CcAwDIThVYJqG6RzpDxWMd5/DRusFOGaaz7u710Q1bRCoYfaqypFsHaUPyHJnKglgV/nJmfxFM7Fl2O6NgXn7jw1pidPKzcm", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Date/Time" = _t, #"Meter 1_2" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date/Time", type datetime}, {"Meter 1_2", Int64.Type}}),
    TransfromMeter = Table.TransformColumns
    (
        #"Changed Type",
        {
            {
                "Meter 1_2",
                each if _>100 then Text.From(_)&",0" else "0,"&Text.From(_)
            }
        }
    ),
    #"Split Column by Delimiter" = Table.SplitColumn(TransfromMeter, "Meter 1_2", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Meter 1_2.1", "Meter 1_2.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Meter 1_2.1", Int64.Type}, {"Meter 1_2.2", Int64.Type}}),
    #"Replaced Value" = Table.ReplaceValue(#"Changed Type1",0,null,Replacer.ReplaceValue,{"Meter 1_2.1", "Meter 1_2.2"}),
    #"Filled Down" = Table.FillDown(#"Replaced Value",{"Meter 1_2.1"}),
    #"Filled Up" = Table.FillUp(#"Filled Down",{"Meter 1_2.2"})
in
   #"Filled Up"

 

Jimmy801_2-1603701803807.png

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

 

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel1

Power BI Monthly Update - May 2024

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

Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.

Top Solution Authors
Top Kudoed Authors