Cumulative variance

Collapse
This topic is closed.
X
X
 
  • Time
  • Show
Clear All
new posts
  • Matt Larkin

    Cumulative variance

    I am pulling my hair out trying to solve this one (presumably because
    I am not particularly trained or skilled at access!)

    I have a query which summarises the variances that each of my sales
    guys have created from their targets. This summarises by week, and
    works fine. I then re-use this into a cross-tab which presents a nice
    orderly table.

    My boss would like to see these variances accumulate, so that we could
    make a nice graph in Excel of who is doing well against the baseline
    target, and who isn't.

    I can't seem to find a way of creating a running total of the
    variances that are being created.

    e.g

    Rep_ID Week No Variance Cumulative
    1 1 0.01 0.01
    1 2 -0.03 -0.02
    1 3 0.01 -0.01
    etc etc

    I've seen some discussion of Dsum as the tool for this, but I think I
    may be missing something......

    Any pointers gratefully received!

    Matt
    UK
  • MGFoster

    #2
    Re: Cumulative variance

    -----BEGIN PGP SIGNED MESSAGE-----
    Hash: SHA1

    You've got a problem. Usually, a running (cumulative) total can be
    calculated in a query this way:

    SELECT Rep_ID, WeekNo, SUM(RepSales) As SalesSum,

    (SELECT SUM(RepSales)
    FROM Sales
    WHERE Rep_ID = S.Rep_ID AND WeekNo <= S.WeekNO ) As Cumulative

    FROM Sales As S
    WHERE ... < your criteria > ...
    ORDER BY Rep_ID, WeekNo

    The subquery in the SELECT clause will calc the running total for the
    column RepSales for the query's "current" Rep_ID and WeekNo.

    The trouble is you want something like this:

    SELECT Rep_ID, WeekNo, VAR(RepSales) As Variance,

    (SELECT SUM(VAR(RepSale s))
    FROM Sales
    WHERE Rep_ID = S.Rep_ID AND WeekNo <= S.WeekNO ) As Cumulative

    FROM Sales As S
    .... etc. ...

    Which can't be done, because SQL doesn't allow an aggregate function
    to have another aggregate function as part of it's expression (what's
    inside the parentheses). So, you'll probably have to run 2 queries to
    get the results:

    qryVariance:

    SELECT Rep_ID, WeekNo, VAR(RepSales) As Variance,
    FROM Sales As S
    WHERE ... < your criteria > ...
    GROUP BY Rep_ID, WeekNo


    qryVarianceRunn ingSum:

    SELECT Rep_ID, WeekNo, Variance,

    (SELECT SUM(Variance)
    FROM qryVariance
    WHERE Rep_ID = V.Rep_ID AND WeekNo <= V.WeekNO ) As Cumulative

    FROM qryVariance AS V
    ORDER BY Rep_ID, WeekNo

    You can also substitute the DSum() function for the subquery:

    DSum("Variance" , "qryVarianc e",
    "Rep_ID=V.Rep_I D AND WeekNo <= V.WeekNO")

    Not sure if this will work ('cuz of summing a variance column in
    another query). If it doesn't you may want to save the results of
    qryVariance to a temp. table and then change qryVarianceRunn ingSum to
    this:

    SELECT Rep_ID, WeekNo, Variance, SUM(Variance) As Cumulative
    FROM tblVariance_tmp AS V
    GROUP BY Rep_ID, WeekNo, Variance

    I've found that using a subquery in the SELECT statement of a query
    causes Access report's to reject the query, even though the query runs
    from query design view! That's when using a domain aggregate function
    (e.g.: DSum()) is needed.

    - --
    MGFoster:::mgf
    Oakland, CA (USA)

    -----BEGIN PGP SIGNATURE-----
    Version: PGP for Personal Privacy 5.0
    Charset: noconv

    iQA/AwUBP6qwioechKq OuFEgEQJtRwCfV1 e1/ubXicEAWetPXZVB KwiQDLYAn1Ct
    gstDlvVS8OF9AAp 7i9Y1+l9I
    =ZftM
    -----END PGP SIGNATURE-----


    Matt Larkin wrote:[color=blue]
    > I am pulling my hair out trying to solve this one (presumably because
    > I am not particularly trained or skilled at access!)
    >
    > I have a query which summarises the variances that each of my sales
    > guys have created from their targets. This summarises by week, and
    > works fine. I then re-use this into a cross-tab which presents a nice
    > orderly table.
    >
    > My boss would like to see these variances accumulate, so that we could
    > make a nice graph in Excel of who is doing well against the baseline
    > target, and who isn't.
    >
    > I can't seem to find a way of creating a running total of the
    > variances that are being created.
    >
    > e.g
    >
    > Rep_ID Week No Variance Cumulative
    > 1 1 0.01 0.01
    > 1 2 -0.03 -0.02
    > 1 3 0.01 -0.01
    > etc etc
    >
    > I've seen some discussion of Dsum as the tool for this, but I think I
    > may be missing something......
    >
    > Any pointers gratefully received!
    >
    > Matt
    > UK[/color]

    Comment

    • Iago Gallego

      #3
      Re: Cumulative variance

      Matt,
      if your query was called qryVariances, and had columns called
      Rep_ID, Week_Number and Variance then the following query will give a
      running sum of the variance for each Rep:

      SELECT T1.Rep_ID, T2.Week_Number, Sum(T1.Variance ) AS SumOfVariance
      FROM qryVariances AS T1 INNER JOIN qryVariances AS T2 ON T1.Rep_ID =
      T2.Rep_ID
      WHERE (((T2.Week_Numb er)>=[T1].[Week_Number]))
      GROUP BY T1.Rep_ID, T2.Week_Number
      ORDER BY T1.Rep_ID, T2.Week_Number;

      You could use the results of this query as the input for your crosstab
      table. I recommend Celko's "SQL for Smarties" - where I got this
      query type.

      Good luck,
      Martin

      google.matthew@ mattandsarah.or g.uk (Matt Larkin) wrote in message news:<91291f7.0 311060816.ee34d 85@posting.goog le.com>...[color=blue]
      > I am pulling my hair out trying to solve this one (presumably because
      > I am not particularly trained or skilled at access!)
      >
      > I have a query which summarises the variances that each of my sales
      > guys have created from their targets. This summarises by week, and
      > works fine. I then re-use this into a cross-tab which presents a nice
      > orderly table.
      >
      > My boss would like to see these variances accumulate, so that we could
      > make a nice graph in Excel of who is doing well against the baseline
      > target, and who isn't.
      >
      > I can't seem to find a way of creating a running total of the
      > variances that are being created.
      >
      > e.g
      >
      > Rep_ID Week No Variance Cumulative
      > 1 1 0.01 0.01
      > 1 2 -0.03 -0.02
      > 1 3 0.01 -0.01
      > etc etc
      >
      > I've seen some discussion of Dsum as the tool for this, but I think I
      > may be missing something......
      >
      > Any pointers gratefully received!
      >
      > Matt
      > UK[/color]

      Comment

      • Matt Larkin

        #4
        Re: Cumulative variance

        Martin.Hungerfo rd@dsto.defence .gov.au (Iago Gallego) wrote in message news:<a56d6c97. 0311061844.48d0 9a96@posting.go ogle.com>...[color=blue]
        > Matt,
        > if your query was called qryVariances, and had columns called
        > Rep_ID, Week_Number and Variance then the following query will give a
        > running sum of the variance for each Rep:
        >
        > SELECT T1.Rep_ID, T2.Week_Number, Sum(T1.Variance ) AS SumOfVariance
        > FROM qryVariances AS T1 INNER JOIN qryVariances AS T2 ON T1.Rep_ID =
        > T2.Rep_ID
        > WHERE (((T2.Week_Numb er)>=[T1].[Week_Number]))
        > GROUP BY T1.Rep_ID, T2.Week_Number
        > ORDER BY T1.Rep_ID, T2.Week_Number;
        >
        > You could use the results of this query as the input for your crosstab
        > table. I recommend Celko's "SQL for Smarties" - where I got this
        > query type.
        >
        > Good luck,
        > Martin
        >[/color]
        Not sure if I understood this correctly - the references to T1 and T2
        in particular.

        The source for the qryVariances is a single table of Rep_ID,
        Week_Number etc.

        Do I need further reference tables (in the example above, T1, T2)
        containing week and rep details?

        TIA, much appreciated!

        Matt

        Comment

        • Iago Gallego

          #5
          Re: Cumulative variance

          Matt,
          it is confusing, yes. :)

          The query I gave works with two copies of the same table/query. To
          tell them apart, the FROM clause has the same table twice and gives
          each instance an alias (T1 and T2 in this case). If you were to use
          the QBE window, it would have the two tables joined on the Rep_Id
          column, but no other joins.

          If you want to add week and rep details, I would be tempted to add
          them afterwards (in a query using the results of this one - but then I
          tend to chain my queries. Its may not be efficient, but it fits my
          "top-down" programming approach.

          Best of luck,
          Martin


          google.matthew@ mattandsarah.or g.uk (Matt Larkin) wrote in message news:<91291f7.0 311070125.6a1b0 93@posting.goog le.com>...[color=blue]
          > Martin.Hungerfo rd@dsto.defence .gov.au (Iago Gallego) wrote in message news:<a56d6c97. 0311061844.48d0 9a96@posting.go ogle.com>...[color=green]
          > > Matt,
          > > if your query was called qryVariances, and had columns called
          > > Rep_ID, Week_Number and Variance then the following query will give a
          > > running sum of the variance for each Rep:
          > >
          > > SELECT T1.Rep_ID, T2.Week_Number, Sum(T1.Variance ) AS SumOfVariance
          > > FROM qryVariances AS T1 INNER JOIN qryVariances AS T2 ON T1.Rep_ID =
          > > T2.Rep_ID
          > > WHERE (((T2.Week_Numb er)>=[T1].[Week_Number]))
          > > GROUP BY T1.Rep_ID, T2.Week_Number
          > > ORDER BY T1.Rep_ID, T2.Week_Number;
          > >
          > > You could use the results of this query as the input for your crosstab
          > > table. I recommend Celko's "SQL for Smarties" - where I got this
          > > query type.
          > >
          > > Good luck,
          > > Martin
          > >[/color]
          > Not sure if I understood this correctly - the references to T1 and T2
          > in particular.
          >
          > The source for the qryVariances is a single table of Rep_ID,
          > Week_Number etc.
          >
          > Do I need further reference tables (in the example above, T1, T2)
          > containing week and rep details?
          >
          > TIA, much appreciated!
          >
          > Matt[/color]

          Comment

          Working...