+ Reply to Thread
Results 1 to 7 of 7

Create excel table using formulas

  1. #1
    Registered User
    Join Date
    07-25-2014
    Location
    Oftringen, Switzerland
    MS-Off Ver
    Professional Plus 2010
    Posts
    16

    Post Create excel table using formulas

    Hi all

    I have an excel sheet that indicates the timecard date of different employees and I would like to create a table using formulas as opposed to the in-built manual excel function.
    My data is unsorted as shown in columns A:D in the attached excel file. The employees can work more than once in day (maximum 3 shifts per day) and more than one employee can work per day.
    Column A shows the day.
    Column B the employee.
    Column C the start of the shift.
    Column D the end of the shift.

    The goal is to have the date sorted (using formulas) by employee and date, as shown in columns I:N in the attached excel file
    Attached Files Attached Files

  2. #2
    Forum Expert
    Join Date
    03-20-2015
    Location
    Primarily UK, sometimes NL
    MS-Off Ver
    Work: Office 365 / Home: Office 2010
    Posts
    2,405

    Re: Create excel table using formulas

    Your file doesn't have anything in columns I:N.
    Is there a reason why you don't want to use the built-in Sort function?
    1. Select your whole range (A2:D25 in your sample file);
    2. On the Data tab, click Sort to open up the Sort dialogue box;
    3. Because you want to sort by two variables, click Add Level;
    4. Against Sort by, select Arbeitsort from the drop-down list;
    5. Against Then by, select Date;
    6. Click OK.
    Regards,
    Aardigspook

    I recently started a new job so am a bit busy and may not reply quickly. Sorry - it's not personal - I will reply eventually.
    If your problem is solved, please go to 'Thread Tools' above your first post and 'Mark this Thread as Solved'.
    If you use commas as your decimal separator (1,23 instead of 1.23) then please replace commas with semi-colons in your formulae.
    You don't need to give me rep if I helped, but a thank-you is nice.

  3. #3
    Registered User
    Join Date
    07-25-2014
    Location
    Oftringen, Switzerland
    MS-Off Ver
    Professional Plus 2010
    Posts
    16

    Re: Create excel table using formulas

    Hi Aardigspook

    Thank you very much for your reply.

    I would prefer not to use the in-built sort function, since I want to automate generation of the excel table, whereby my users (the employees) only have to input their names and workdates and shifts, and using formulas, sort the input.

    Best regards,

  4. #4
    Banned User!
    Join Date
    02-05-2015
    Location
    San Escobar
    MS-Off Ver
    any on PC except 365
    Posts
    12,168

    Re: Create excel table using formulas

    Ctrl+T and sort/filter as you wish

  5. #5
    Forum Expert
    Join Date
    03-20-2015
    Location
    Primarily UK, sometimes NL
    MS-Off Ver
    Work: Office 365 / Home: Office 2010
    Posts
    2,405

    Re: Create excel table using formulas

    Okay, I've got a solution for you to dynamically sort the data. It uses helper columns, which you can hide later.

    Helper column 1.
    This assigns numbers to each Arbeitsort, with lowest number (0) for the first alphabetically. For example, 'Papito' in B6 is assigned the number 6 because there are six entries in column B which are before 'Papito' alphabetically (3 x Bruppbacher and 3 x Endreinigung). The formula (in F3, dragged down) is:
    Formula: copy to clipboard
    Please Login or Register  to view this content.

    Note the quotation marks around the < and the & sign.

    Helper column 2
    This does the same as above, for each Date which has the same Arbeitsort. For example, row 6 gets the value of 2 because there are four dates against 'Papito', 2 of which are less than the one in A6 (A6 is 15.01.2018, the two 'lower' dates are 02.01.2018 and 04.01.2018 in A8 and A14). The formula (in G3, dragged down) is:
    Formula: copy to clipboard
    Please Login or Register  to view this content.

    Note that your dates are currently stored as text, but even if you convert them to proper dates, this formula will still work.

    Helper column 3
    This uses a newly-inserted column H and simply adds the two previous helpers. This is the formula (in H3, dragged down):
    Formula: copy to clipboard
    Please Login or Register  to view this content.

    Of course, you could skip the two previous columns and just combine them in this one, using this formula:
    Formula: copy to clipboard
    Please Login or Register  to view this content.


    Ideally, this column would contain only unique numbers, but if you have two rows with the same Date and Arbeitsort then you will get non-unique numbers (for example, both rows 16 and 17 have 17.01.2018 and Schaub).

    Helper column 4
    To fix the possibility of non-unique numbers in the previous column, we now Rank those numbers. Again, this is a new column - column I.
    If we used one the Rank functions on its own, we would still get non-unique numbers. For example, H13 and H22 both contain the number 4, so would both be ranked the same. We want unique increasing numbers, so we combine Rank with a CountIf of each number. Here's the formula (in I3, dragged down):
    Formula: copy to clipboard
    Please Login or Register  to view this content.


    Output Data
    Each row has now been assigned a unique number, from 1 for the first alphabetical Arbeitsort & Date combination, increasing (up to 23, with the sample data you gave). We can now refer to these numbers in an Index-Match to sort the original data. The new Target Data columns are: K (Date), L (Arbeitsort), M (Start) and N (End). Put the formula below in K3 and drag across to N3, then down as far as needed:
    Formula: copy to clipboard
    Please Login or Register  to view this content.

    What the formula does is this:
    • Rows provides a number, increasing from 1;
    • Match then looks for this number in the list of numbers in column I (the Ranked helper column) and returns the row that match is in;
    • Index then returns the data found in that row of the appropriate column (col A in the formula above, but this changes to B, C, D as you drag it across).

    When there is no data to find, you will get #N/A errors. You can remove these by using IfError:
    Formula: copy to clipboard
    Please Login or Register  to view this content.

    Replace "no data" with any error message you want, or with just "" for a blank.

    Note
    For all the formulae above, you should ensure that the range is amended to show the actual range you need. For example, if you think you may have up to 1000 entries, then replace each $25 with $1000 (only the $25 - not every 25 on its own).

    Translation
    I note that Arbeitsort is German. If you need the formulae in German too, here they are:
    Formula: copy to clipboard
    Please Login or Register  to view this content.

    The translation was done using this website: https://en.excel-translator.de/translator/



    I hope that does what you need. I've attached a file showing it working with your sample data.

  6. #6
    Registered User
    Join Date
    07-25-2014
    Location
    Oftringen, Switzerland
    MS-Off Ver
    Professional Plus 2010
    Posts
    16

    Re: Create excel table using formulas

    Dear Aardigspook

    You are a life-saver, kudos for the solution, it helped me to solve the task at hand.

    Thank you very much.

  7. #7
    Forum Expert
    Join Date
    03-20-2015
    Location
    Primarily UK, sometimes NL
    MS-Off Ver
    Work: Office 365 / Home: Office 2010
    Posts
    2,405

    Re: Create excel table using formulas

    You're welcome, thanks for the feedback and for marking the thread as Solved.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Replies: 1
    Last Post: 05-31-2017, 04:20 PM
  2. Using indirect (?) within table to create dynamic formulas
    By cotoews in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 08-29-2013, 07:01 PM
  3. [SOLVED] Looking to Simplify Pivot Table and Formulas Used to Create Chart
    By mo4391 in forum Excel Charting & Pivots
    Replies: 3
    Last Post: 01-29-2013, 11:44 PM
  4. Replies: 0
    Last Post: 11-07-2012, 01:16 PM
  5. Create New row in a table and copy/update formulas VBA
    By whitenoise22 in forum Excel Programming / VBA / Macros
    Replies: 14
    Last Post: 07-25-2012, 03:07 AM
  6. How do you create formulas in pivot table eg simple division?
    By Belinda_Tim in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 01-05-2006, 11:10 AM

Tags for this Thread

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1