+ Reply to Thread
Results 1 to 17 of 17

create a top 10 list of sales figures

  1. #1
    cmart02
    Guest

    RE: create a top 10 list of sales figures

    Dave,

    Use a PivotalTable to summarize the data em create your top 10 lists.

    --
    Regards
    Robert
    Find me at www.juliobattisti.com.br/forum/

  2. #2
    Davidy
    Guest

    RE: create a top 10 list of sales figures

    Sorry. I should have pointed out that I was trying to achieve this without
    having to create pivot tables.....but thanks for the suggestion.

  3. #3
    cmart02
    Guest

    RE: create a top 10 list of sales figures

    Davidy,

    That will be, in my opinion, your best bet. You can easily summarize the
    data and once that it is done, simply right-click on the row field and select
    the option Field Setting and the click on Advanced. There you will have the
    option to list the top 10, top 15, top 20, top 5, or literally anything
    really.

    And all that wil only a few clicks and now messy formulas.

  4. #4
    macropod
    Guest

    Re: create a top 10 list of sales figures

    hi Dave,

    Suppose your data start in row 2 (row 1 is for headings) and you want an
    ordered list of the 10 items from Column B that correspond to the 10 highest
    values in column I. And suppose too that the output is also to start on row
    2. In that case, the formula:
    =INDEX(B:B,MATCH(LARGE(I:I,ROW()-2),I:I,0))
    input in any available column on row 2 and copied down to row 11 would work,
    PROVIDED, the values in column I are unique. If any values are repeated, the
    formula will return duplicates from column B for the column I matches. If
    there is the risk that values in column I are repeated, you could use the
    above for the first row and, for the third row (copied down to row 11):
    =IF(LARGE(I:I,ROW()-2)=LARGE(I:I,ROW()-3),INDEX(B:B,MATCH(LARGE(I:I,ROW()-2)
    ,OFFSET(I,MATCH(K3,B:B,0),0,ROW(I)-MATCH(K3,B:B,0),1),0)+MATCH(K3,B:B,0)),IN
    DEX(B:B,MATCH(LARGE(I:I,ROW()-2),I:I,0)))

    If your output table starts on any row other than row 2, simply change the
    '-2' references in the above formulae to match the starting row counts.

    Cheers



    "Davidy" <[email protected]> wrote in message
    news:[email protected]...
    > Help required to solve a pain of an issue (and save what little hair I

    have
    > left)
    >
    > I have a very large worksheet containing monthly sales data for 600+
    > products sorted by product group. I want to create a series of "top 10's"
    > for the data.
    >
    > The data is set out a bit like this:
    >
    > Item code Name Price Unit Sales(1 column per month)
    >
    > There are columns in between some of these but they aren't really relevant
    > to what I want to achieve.
    >
    > I need to create a conditional formula that will examine the sales figures
    > by month and product group and pull out the highest sellers for each
    > group/month (complete with all the indentifying data). I also need to

    look
    > at sales figures over the entire range and pull out overall top sellers.
    >
    > All the functions I have looked at will give me the overall position of a
    > sales figure but won't tie it to the name or item code and they will not
    > break the data down by group.
    >
    > Any suggestions gratefully received......the boss is starting to get
    > impatient!!!!
    >
    > ---
    >
    > Dave




  5. #5
    macropod
    Guest

    Re: create a top 10 list of sales figures

    hi Dave,

    Suppose your data start in row 2 (row 1 is for headings) and you want an
    ordered list of the 10 items from Column B that correspond to the 10 highest
    values in column I. And suppose too that the output is also to start on row
    2. In that case, the formula:
    =INDEX(B:B,MATCH(LARGE(I:I,ROW()-2),I:I,0))
    input in any available column on row 2 and copied down to row 11 would work,
    PROVIDED, the values in column I are unique. If any values are repeated, the
    formula will return duplicates from column B for the column I matches. If
    there is the risk that values in column I are repeated, you could use the
    above for the first row and, for the third row (copied down to row 11):
    =IF(LARGE(I:I,ROW()-2)=LARGE(I:I,ROW()-3),INDEX(B:B,MATCH(LARGE(I:I,ROW()-2)
    ,OFFSET(I,MATCH(K3,B:B,0),0,ROW(I)-MATCH(K3,B:B,0),1),0)+MATCH(K3,B:B,0)),IN
    DEX(B:B,MATCH(LARGE(I:I,ROW()-2),I:I,0)))

    If your output table starts on any row other than row 2, simply change the
    '-2' references in the above formulae to match the starting row counts.

    Cheers



    "Davidy" <[email protected]> wrote in message
    news:[email protected]...
    > Help required to solve a pain of an issue (and save what little hair I

    have
    > left)
    >
    > I have a very large worksheet containing monthly sales data for 600+
    > products sorted by product group. I want to create a series of "top 10's"
    > for the data.
    >
    > The data is set out a bit like this:
    >
    > Item code Name Price Unit Sales(1 column per month)
    >
    > There are columns in between some of these but they aren't really relevant
    > to what I want to achieve.
    >
    > I need to create a conditional formula that will examine the sales figures
    > by month and product group and pull out the highest sellers for each
    > group/month (complete with all the indentifying data). I also need to

    look
    > at sales figures over the entire range and pull out overall top sellers.
    >
    > All the functions I have looked at will give me the overall position of a
    > sales figure but won't tie it to the name or item code and they will not
    > break the data down by group.
    >
    > Any suggestions gratefully received......the boss is starting to get
    > impatient!!!!
    >
    > ---
    >
    > Dave




  6. #6
    cmart02
    Guest

    RE: create a top 10 list of sales figures

    Dave,

    Use a PivotalTable to summarize the data em create your top 10 lists.

    --
    Regards
    Robert
    Find me at www.juliobattisti.com.br/forum/

  7. #7
    Davidy
    Guest

    RE: create a top 10 list of sales figures

    Sorry. I should have pointed out that I was trying to achieve this without
    having to create pivot tables.....but thanks for the suggestion.

  8. #8
    cmart02
    Guest

    RE: create a top 10 list of sales figures

    Davidy,

    That will be, in my opinion, your best bet. You can easily summarize the
    data and once that it is done, simply right-click on the row field and select
    the option Field Setting and the click on Advanced. There you will have the
    option to list the top 10, top 15, top 20, top 5, or literally anything
    really.

    And all that wil only a few clicks and now messy formulas.

  9. #9
    macropod
    Guest

    Re: create a top 10 list of sales figures

    hi Dave,

    Suppose your data start in row 2 (row 1 is for headings) and you want an
    ordered list of the 10 items from Column B that correspond to the 10 highest
    values in column I. And suppose too that the output is also to start on row
    2. In that case, the formula:
    =INDEX(B:B,MATCH(LARGE(I:I,ROW()-2),I:I,0))
    input in any available column on row 2 and copied down to row 11 would work,
    PROVIDED, the values in column I are unique. If any values are repeated, the
    formula will return duplicates from column B for the column I matches. If
    there is the risk that values in column I are repeated, you could use the
    above for the first row and, for the third row (copied down to row 11):
    =IF(LARGE(I:I,ROW()-2)=LARGE(I:I,ROW()-3),INDEX(B:B,MATCH(LARGE(I:I,ROW()-2)
    ,OFFSET(I,MATCH(K3,B:B,0),0,ROW(I)-MATCH(K3,B:B,0),1),0)+MATCH(K3,B:B,0)),IN
    DEX(B:B,MATCH(LARGE(I:I,ROW()-2),I:I,0)))

    If your output table starts on any row other than row 2, simply change the
    '-2' references in the above formulae to match the starting row counts.

    Cheers



    "Davidy" <[email protected]> wrote in message
    news:[email protected]...
    > Help required to solve a pain of an issue (and save what little hair I

    have
    > left)
    >
    > I have a very large worksheet containing monthly sales data for 600+
    > products sorted by product group. I want to create a series of "top 10's"
    > for the data.
    >
    > The data is set out a bit like this:
    >
    > Item code Name Price Unit Sales(1 column per month)
    >
    > There are columns in between some of these but they aren't really relevant
    > to what I want to achieve.
    >
    > I need to create a conditional formula that will examine the sales figures
    > by month and product group and pull out the highest sellers for each
    > group/month (complete with all the indentifying data). I also need to

    look
    > at sales figures over the entire range and pull out overall top sellers.
    >
    > All the functions I have looked at will give me the overall position of a
    > sales figure but won't tie it to the name or item code and they will not
    > break the data down by group.
    >
    > Any suggestions gratefully received......the boss is starting to get
    > impatient!!!!
    >
    > ---
    >
    > Dave




  10. #10
    cmart02
    Guest

    RE: create a top 10 list of sales figures

    Davidy,

    That will be, in my opinion, your best bet. You can easily summarize the
    data and once that it is done, simply right-click on the row field and select
    the option Field Setting and the click on Advanced. There you will have the
    option to list the top 10, top 15, top 20, top 5, or literally anything
    really.

    And all that wil only a few clicks and now messy formulas.

  11. #11
    Davidy
    Guest

    RE: create a top 10 list of sales figures

    Sorry. I should have pointed out that I was trying to achieve this without
    having to create pivot tables.....but thanks for the suggestion.

  12. #12
    cmart02
    Guest

    RE: create a top 10 list of sales figures

    Dave,

    Use a PivotalTable to summarize the data em create your top 10 lists.

    --
    Regards
    Robert
    Find me at www.juliobattisti.com.br/forum/

  13. #13
    macropod
    Guest

    Re: create a top 10 list of sales figures

    hi Dave,

    Suppose your data start in row 2 (row 1 is for headings) and you want an
    ordered list of the 10 items from Column B that correspond to the 10 highest
    values in column I. And suppose too that the output is also to start on row
    2. In that case, the formula:
    =INDEX(B:B,MATCH(LARGE(I:I,ROW()-2),I:I,0))
    input in any available column on row 2 and copied down to row 11 would work,
    PROVIDED, the values in column I are unique. If any values are repeated, the
    formula will return duplicates from column B for the column I matches. If
    there is the risk that values in column I are repeated, you could use the
    above for the first row and, for the third row (copied down to row 11):
    =IF(LARGE(I:I,ROW()-2)=LARGE(I:I,ROW()-3),INDEX(B:B,MATCH(LARGE(I:I,ROW()-2)
    ,OFFSET(I,MATCH(K3,B:B,0),0,ROW(I)-MATCH(K3,B:B,0),1),0)+MATCH(K3,B:B,0)),IN
    DEX(B:B,MATCH(LARGE(I:I,ROW()-2),I:I,0)))

    If your output table starts on any row other than row 2, simply change the
    '-2' references in the above formulae to match the starting row counts.

    Cheers



    "Davidy" <[email protected]> wrote in message
    news:[email protected]...
    > Help required to solve a pain of an issue (and save what little hair I

    have
    > left)
    >
    > I have a very large worksheet containing monthly sales data for 600+
    > products sorted by product group. I want to create a series of "top 10's"
    > for the data.
    >
    > The data is set out a bit like this:
    >
    > Item code Name Price Unit Sales(1 column per month)
    >
    > There are columns in between some of these but they aren't really relevant
    > to what I want to achieve.
    >
    > I need to create a conditional formula that will examine the sales figures
    > by month and product group and pull out the highest sellers for each
    > group/month (complete with all the indentifying data). I also need to

    look
    > at sales figures over the entire range and pull out overall top sellers.
    >
    > All the functions I have looked at will give me the overall position of a
    > sales figure but won't tie it to the name or item code and they will not
    > break the data down by group.
    >
    > Any suggestions gratefully received......the boss is starting to get
    > impatient!!!!
    >
    > ---
    >
    > Dave




  14. #14
    cmart02
    Guest

    RE: create a top 10 list of sales figures

    Davidy,

    That will be, in my opinion, your best bet. You can easily summarize the
    data and once that it is done, simply right-click on the row field and select
    the option Field Setting and the click on Advanced. There you will have the
    option to list the top 10, top 15, top 20, top 5, or literally anything
    really.

    And all that wil only a few clicks and now messy formulas.

  15. #15
    Davidy
    Guest

    RE: create a top 10 list of sales figures

    Sorry. I should have pointed out that I was trying to achieve this without
    having to create pivot tables.....but thanks for the suggestion.

  16. #16
    cmart02
    Guest

    RE: create a top 10 list of sales figures

    Dave,

    Use a PivotalTable to summarize the data em create your top 10 lists.

    --
    Regards
    Robert
    Find me at www.juliobattisti.com.br/forum/

  17. #17
    Davidy
    Guest

    create a top 10 list of sales figures

    Help required to solve a pain of an issue (and save what little hair I have
    left)

    I have a very large worksheet containing monthly sales data for 600+
    products sorted by product group. I want to create a series of "top 10's"
    for the data.

    The data is set out a bit like this:

    Item code Name Price Unit Sales(1 column per month)

    There are columns in between some of these but they aren't really relevant
    to what I want to achieve.

    I need to create a conditional formula that will examine the sales figures
    by month and product group and pull out the highest sellers for each
    group/month (complete with all the indentifying data). I also need to look
    at sales figures over the entire range and pull out overall top sellers.

    All the functions I have looked at will give me the overall position of a
    sales figure but won't tie it to the name or item code and they will not
    break the data down by group.

    Any suggestions gratefully received......the boss is starting to get
    impatient!!!!

    ---

    Dave

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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