ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Discussion (Misc queries) (https://www.excelbanter.com/excel-discussion-misc-queries/)
-   -   Analysing data through pivot (https://www.excelbanter.com/excel-discussion-misc-queries/63946-analysing-data-through-pivot.html)

Chris

Analysing data through pivot
 
Hi,

I am trying to convert the payroll data I receive from my clients into a csv
file that I import in to my payroll program. Ideally I would like it to be
all automatic (marco).

The problem lies in the variable nature of the information I receive.


Here is the basic layout:

NAME | ID | Basic pay | Commission | Overtime

Bob 2 500 300 50
James 3 400 20
Sarah 4 500
And so forth

THe layout I am trying to achieve is the following:

Bob 2 Basic pay 500
Bob 2 Commission 300
Bob 2 Overtime 50
James 3 Basic pay 400
James 3 Overtime 40
sarah 4 basic pay 500
....
I can transpose the detail & amount easily but how can I get excel to
automatically match the name and ID number for each field. As you can see Bob
has 3 entries ,James has 2 and sarah only one. The number of employees varies
every month and their payroll details also.

Any help would be great.

Thank You

ERR229

Analysing data through pivot
 
Hi Chris,

It looks as though you're trying to use Excel as a relational database and
it's not designed for that. Do you have Access by any chance? That would
really be the way to go.
--
ERR229


"Chris" wrote:

Hi,

I am trying to convert the payroll data I receive from my clients into a csv
file that I import in to my payroll program. Ideally I would like it to be
all automatic (marco).

The problem lies in the variable nature of the information I receive.


Here is the basic layout:

NAME | ID | Basic pay | Commission | Overtime

Bob 2 500 300 50
James 3 400 20
Sarah 4 500
And so forth

THe layout I am trying to achieve is the following:

Bob 2 Basic pay 500
Bob 2 Commission 300
Bob 2 Overtime 50
James 3 Basic pay 400
James 3 Overtime 40
sarah 4 basic pay 500
...
I can transpose the detail & amount easily but how can I get excel to
automatically match the name and ID number for each field. As you can see Bob
has 3 entries ,James has 2 and sarah only one. The number of employees varies
every month and their payroll details also.

Any help would be great.

Thank You


Chris

Analysing data through pivot
 
Yes I was afraid of that.

The client doesn't use access so I was trying to keep everything on excel.

However, can I set an automated process like a macro to perform this task
through access and still end up with a csv file?

I use access & excel but always seperatly so I don't know if they can
interact with each other in a suitable way for this task.

"ERR229" wrote:

Hi Chris,

It looks as though you're trying to use Excel as a relational database and
it's not designed for that. Do you have Access by any chance? That would
really be the way to go.
--
ERR229


"Chris" wrote:

Hi,

I am trying to convert the payroll data I receive from my clients into a csv
file that I import in to my payroll program. Ideally I would like it to be
all automatic (marco).

The problem lies in the variable nature of the information I receive.


Here is the basic layout:

NAME | ID | Basic pay | Commission | Overtime

Bob 2 500 300 50
James 3 400 20
Sarah 4 500
And so forth

THe layout I am trying to achieve is the following:

Bob 2 Basic pay 500
Bob 2 Commission 300
Bob 2 Overtime 50
James 3 Basic pay 400
James 3 Overtime 40
sarah 4 basic pay 500
...
I can transpose the detail & amount easily but how can I get excel to
automatically match the name and ID number for each field. As you can see Bob
has 3 entries ,James has 2 and sarah only one. The number of employees varies
every month and their payroll details also.

Any help would be great.

Thank You


Roger Govier

Analysing data through pivot
 
Hi Chris

Mark your data range
DataPivot TableMultiple Consolidation rangesNextI will create page
FieldsNextRange enter your range of dataNextFinish

On the new page created with the Pivot Table, select the bottom right
cell Grand Total of Columns and Grand Total of Rows.
Double Click
A new page will be created with data set out as follows
Row Column Value
Bob Basic Pay 500
Bob Commission 300
Bob ID 2
Bob Overtime 50
James Basic Pay 400
James Commission
James ID 3
James Overtime 20
Sarah Basic Pay 500
Sarah Commission
Sarah ID 4
Sarah Overtime


Change Heading Row to Name, Column to Type
If you do need the ID numbers in a column, next to Name, then insert a
new column A and enter the following array formula in A2.
To enter an array formula (or modify it) commit with Ctrl+Shift+Enter
and Excel will insert the curly braces { } for you. Do not type them
yourself.
{=INDEX($B$2:$D$13,MATCH(B2&"ID",$B$2:$B$13&$C$2:$ C$13,0),3)}
copy down through B3:B13.
Copy B2:B13, Paste SpecialValues back over the formulae in B2:B13

If you don't then need the rows containing the ID, then,
DataFilterAutofilteruse dropdown on Type to Select ID.
Mark the range of visible rows by selecting their row numbersRight
clickDelete.

Obviously you will have a lot more data, hence your ranges as above will
be expanded.
--
Regards

Roger Govier


"Chris" wrote in message
...
Hi,

I am trying to convert the payroll data I receive from my clients into
a csv
file that I import in to my payroll program. Ideally I would like it
to be
all automatic (marco).

The problem lies in the variable nature of the information I receive.


Here is the basic layout:

NAME | ID | Basic pay | Commission | Overtime

Bob 2 500 300 50
James 3 400 20
Sarah 4 500
And so forth

THe layout I am trying to achieve is the following:

Bob 2 Basic pay 500
Bob 2 Commission 300
Bob 2 Overtime 50
James 3 Basic pay 400
James 3 Overtime 40
sarah 4 basic pay 500
...
I can transpose the detail & amount easily but how can I get excel to
automatically match the name and ID number for each field. As you can
see Bob
has 3 entries ,James has 2 and sarah only one. The number of employees
varies
every month and their payroll details also.

Any help would be great.

Thank You





All times are GMT +1. The time now is 08:35 AM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
ExcelBanter.com