+ Reply to Thread
Results 1 to 5 of 5

Set Data Range by Variable

  1. #1
    Registered User
    Join Date
    11-05-2004
    Location
    Palm Springs California
    MS-Off Ver
    Office 2011 for Mac
    Posts
    37

    Set Data Range by Variable

    I want to be able to define the number of cells in a column that will be included in a calculation.

    =SUM(A5:A25)/2

    So in the above example I have selected 20 cell in column A. I want to be able to set the number via a slider on the spread sheet to capture any number of cell below the cell with the formula in it. So, and I know this does not work but, =SUM(A5:A(X))/2 where X equals the number of cells that I want included. I want to avoid VBA because this will update a graph and I don't want to run a macro every time the data gets changed to update my graph.

    I have gone through the Excel 2003 Bible, called MS Office support and combed the web. There must be a simple way to accomplish this without a macro.

    Thanks to all. Michael



    [COLOR=DarkRed]

  2. #2
    Forum Expert
    Join Date
    06-18-2004
    Location
    Canada
    MS-Off Ver
    Office 2016
    Posts
    1,474
    Try...

    =SUM(A5:INDEX(A5:A65536,B5))

    ...where B5 contains the number of cells you want included. Then link B5 to your slider.

    Hope this helps!

    Quote Originally Posted by MJSlattery
    I want to be able to define the number of cells in a column that will be included in a calculation.

    =SUM(A5:A25)/2

    So in the above example I have selected 20 cell in column A. I want to be able to set the number via a slider on the spread sheet to capture any number of cell below the cell with the formula in it. So, and I know this does not work but, =SUM(A5:A(X))/2 where X equals the number of cells that I want included. I want to avoid VBA because this will update a graph and I don't want to run a macro every time the data gets changed to update my graph.

    I have gone through the Excel 2003 Bible, called MS Office support and combed the web. There must be a simple way to accomplish this without a macro.

    Thanks to all. Michael



    [COLOR=DarkRed]

  3. #3
    Peo Sjoblom
    Guest

    Re: Set Data Range by Variable

    A couple of ways

    =SUM($A$5:INDEX(A:A,F1))


    =SUM(A5:INDIRECT("A"&F1))

    =SUM(OFFSET($A$5,,,F1-ROW($A$5)+1))

    the first is to prefer since it is not volatile

    F1 holds the X numbers

    --
    Regards,

    Peo Sjoblom

    (No private emails please)


    "MJSlattery" <[email protected]> wrote
    in message news:[email protected]...[color=blue]
    >
    > I want to be able to define the number of cells in a column that will be
    > included in a calculation.
    >
    > =SUM(A5:A25)/2
    >
    > So in the above example I have selected 20 cell in column A. I want to
    > be able to set the number via a slider on the spread sheet to capture
    > any number of cell below the cell with the formula in it. So, and I
    > know this does not work but, =SUM(A5:A(X))/2 where X equals the number
    > of cells that I want included. I want to avoid VBA because this will
    > update a graph and I don't want to run a macro every time the data gets
    > changed to update my graph.
    >
    > I have gone through the Excel 2003 Bible, called MS Office support and
    > combed the web. There must be a simple way to accomplish this without
    > a macro.
    >
    > Thanks to all. Michael
    >
    >
    >
    >
    >
    >
    > --
    > MJSlattery
    > ------------------------------------------------------------------------
    > MJSlattery's Profile:
    > http://www.excelforum.com/member.php...o&userid=16141
    > View this thread: http://www.excelforum.com/showthread...hreadid=377967
    >



  4. #4
    Jim Cone
    Guest

    Re: Set Data Range by Variable

    Michael,

    Piece of cake...
    1. Add a scroll bar from the Forms toolbar to the sheet.
    2. Format the scrollbar so the minimum is 0 and the
    increment is 1. Specify a cell link cell. (say D1)
    3. Move the scroll bar over the top of the linked cell.
    4. In a cell below the scrollbar, enter the formula "= D1 +1"
    5. Add a title above it called "Total Cells"
    6. In a cell further down enter the formula "=SUM(A1:OFFSET(A1,D1,0))"
    7. Add a title above it called "Sum"
    8. Enter values in column A, click the scrollbar.

    Regards,
    Jim Cone
    San Francisco, USA


    "MJSlattery" <[email protected]>
    wrote in message news:[email protected]...

    I want to be able to define the number of cells in a column that will be
    included in a calculation.

    =SUM(A5:A25)/2

    So in the above example I have selected 20 cell in column A. I want to
    be able to set the number via a slider on the spread sheet to capture
    any number of cell below the cell with the formula in it. So, and I
    know this does not work but, =SUM(A5:A(X))/2 where X equals the number
    of cells that I want included. I want to avoid VBA because this will
    update a graph and I don't want to run a macro every time the data gets
    changed to update my graph.

    I have gone through the Excel 2003 Bible, called MS Office support and
    combed the web. There must be a simple way to accomplish this without
    a macro.

    Thanks to all. Michael

    MJSlattery


  5. #5
    Registered User
    Join Date
    11-05-2004
    Location
    Palm Springs California
    MS-Off Ver
    Office 2011 for Mac
    Posts
    37

    Smile Thank you both

    Very helpful and explicit advice.

    Michael

+ 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