Clean data with dates as headers and merged cells

Zee996

New Member
Joined
Nov 30, 2021
Messages
36
Office Version
  1. 365
Platform
  1. Windows
Hello Eveyone,

I have been asked to clean 6 months of data in the Tracker to find the total count of activity, sub-activity, total hours in minutes, and hours. But, the problem is the data formatting. The date is used as a header to represent the data for that particular day.

Here an example of how the data looks like:

1730912675281.png


Is there a way to clean this data without manually copying and pasting the date into each column? I need to clean this data for 9 agents, and it includes 6 months of data.

Thank you.
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
Hello, since I am not sure if I understand it correctly how the output should look like would you be so kind and post a sample of the desired output?
 
Upvote 0
Thank you.
I would like summarised this using pivot 3 tables. 1. Pivot table of total count of activities and sub activites.
2. Pivot table of total hours in min of activities and subactivites.
3. Pivot table of total hours in hours
of activities and subactivites.

So, Activities and subactivites in Raws field and date and in dates in column filed and count, mins and hours in 3 different tables respectively.

I hope this makes sense.
 
Upvote 0
Based on the sample you posted, please test whether the following will help you with rearranging the data:

Excel Formula:
=LET(
a,C3:N10,
b,C1:N1,
c,A3:A10,
d,B3:B10,
e,COUNTA(b),
f,TOCOL(IF(SEQUENCE(,e),TOCOL(SCAN("",c,LAMBDA(a,b,IF(b<>"",b,a))),1)),,TRUE),
g,TOCOL(IF(SEQUENCE(,e),TOCOL(d,1)),,TRUE),
h,TOCOL(IF(SEQUENCE(,ROWS(a)),TOCOL(b,1))),
i,DROP(REDUCE("",SEQUENCE(e),LAMBDA(x,y,VSTACK(x,CHOOSECOLS(a,CHOOSEROWS(SEQUENCE(e,3),y))))),1),
HSTACK(f,g,h,i))
 
Upvote 0

Forum statistics

Threads
1,223,723
Messages
6,174,113
Members
452,544
Latest member
aush

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