How to transform data using Date/Time as unique identifier

Ro_Mr_B

New Member
Joined
Jul 27, 2023
Messages
2
Office Version
  1. 365
Platform
  1. Windows
Just started learning the ropes with excel.

I have some data that I pull from an SQL database and it looks like the following:

Dlog1.PNG


I'd like to use that data in a seperate sheet in a table with the following headers:

Date and TimeRFID #Product MasterDescriptionWaste Trim Height

As you can possibly see, I'd like the use the Date/Time as an identifier that groups the information, but I'm not sure where to go with this, what functions to use.

The 'Product Master' and 'Description' columns I will be using a VLOOKUP to another sheet, they can be ignored for this case.

I'm not looking for anyone to write me a full answer, just a point in the right direction will be greatly appreciated!
 

Excel Facts

How can you automate Excel?
Press Alt+F11 from Windows Excel to open the Visual Basic for Applications (VBA) editor.
Power query
1690530010397.png


Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type datetime}, {"Tag", type text}, {"Val", Int64.Type}}),
    #"Pivoted Column" = Table.Pivot(#"Changed Type", List.Distinct(#"Changed Type"[Tag]), "Tag", "Val", List.Sum)
in
    #"Pivoted Column"


Book1
ABCDEFG
1DateTagValDateRFID#WTH
228/07/2023 03:17RFID#45128/07/2023 03:034232456
328/07/2023 03:17WTH245528/07/2023 03:174512455
428/07/2023 03:03RFID#42328/07/2023 04:154272466
528/07/2023 03:03WTH2456
628/07/2023 04:15RFID#427
728/07/2023 04:15WTH2466
Sheet1
 
Upvote 0
Solution
Power query
View attachment 96130

Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type datetime}, {"Tag", type text}, {"Val", Int64.Type}}),
    #"Pivoted Column" = Table.Pivot(#"Changed Type", List.Distinct(#"Changed Type"[Tag]), "Tag", "Val", List.Sum)
in
    #"Pivoted Column"


Book1
ABCDEFG
1DateTagValDateRFID#WTH
228/07/2023 03:17RFID#45128/07/2023 03:034232456
328/07/2023 03:17WTH245528/07/2023 03:174512455
428/07/2023 03:03RFID#42328/07/2023 04:154272466
528/07/2023 03:03WTH2456
628/07/2023 04:15RFID#427
728/07/2023 04:15WTH2466
Sheet1
This looks spot on! I'll give it a whirl Monday, many thanks.
 
Upvote 0

Forum statistics

Threads
1,215,069
Messages
6,122,952
Members
449,095
Latest member
nmaske

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top