Consulting

Results 1 to 6 of 6

Thread: How to consolidate and return extensions

  1. #1
    Microsoft Word MVP 2003-2009 VBAX Guru gmaxey's Avatar
    Joined
    Sep 2005
    Posts
    3,376
    Location

    How to consolidate and return extensions

    The answer to this question may not involve VBA but I'm hoping someone can steer me in the right direction. For simplicity in explaining the issue, I am going to use a simplified example.

    I have a table of Projects "tblProjects". With "ProjectID" as the primary key and fields "Base_Due_Date" and "Total_Days_Extended" . During the course of the project execution, the Project Manager may request one or more (probably not more than three but just out of interest, lets say unlimited). When an extension is granted, the due date is revised (pushed forward by the approved number of days).

    So in a query I can have Due_Date = DateAdd("d, "Base_Due_Date", "Total_Days_Extended")

    My table might look like this

    ProjID Base_Due_Date Total_Days_Extended
    1 1/1/2024 ??
    2 2/1/2024 ??
    3 3/1/2024 ??

    My problem (question) is how to go about resolving "Total_Days_Extended).

    I am just one step above being a complete novice but I believe the approach would be to have another table of extensions tblExtensions that has a relationship with tblProjects. Each approved extension is entered into that table. So it might look like this:

    ExtID, ProjectID NumDay
    1 1 10
    2 2 15
    3 1 30

    ... and with the proper relationship have a result in my tblProjects like this:

    ProjID Base_Due_Date Total_Days_Extended
    1 1/1/2024 40
    2 2/1/2024 15
    3 3/1/2024 0

    Then if an extension of ProjID is approved:
    ExtID, ProjectID NumDay
    1 1 10
    2 2 15
    3 1 30
    4 3 20

    I get:

    ProjID Base_Due_Date Total_Days_Extended
    1 1/1/2024 40
    2 2/1/2024 15
    3 3/1/2024 20

    If this is even possible, how would one go about setting up the relationship and between the tables and how would one define the "Total_Days_Extended" field expression to sum or add up all the extensions related to that record.

    Thank you!!
    Greg

    Visit my website: http://gregmaxey.com

  2. #2
    VBAX Regular xps350's Avatar
    Joined
    Jul 2022
    Posts
    11
    Location
    First of all: you should not STORE Total_Days_Extended in the project table. It is a derived value, that you should calculate and SHOW whenever needed. For that you use a query like:
    SELECT tblProjects.ProjID, tblProjects.Base_Due_Date, Sum(Nz(tblExtensions.NumDay)) AS Total_Days_Extended
    FROM tblProjects LEFT JOIN tblExtensions ON tblProjects.ProjID = tblExtensions.ProjID
    GROUP BY tblProjects.ProjID;
    Groeten,

    Peter

  3. #3
    Moderator VBAX Wizard Aussiebear's Avatar
    Joined
    Dec 2005
    Location
    Queensland
    Posts
    5,153
    Location
    hmmm.... not bad advice at all Peter.
    Remember To Do the Following....
    Use [Code].... [/Code] tags when posting code to the thread.
    Mark your thread as Solved if satisfied by using the Thread Tools options.
    If posting the same issue to another forum please show the link

  4. #4
    Microsoft Word MVP 2003-2009 VBAX Guru gmaxey's Avatar
    Joined
    Sep 2005
    Posts
    3,376
    Location
    Peter,

    Thank you very much. So I created a new query and pasted your SQL string into the SQL view. When I first ran it, I got an error
    Your query does not include the specified expression "Base_Due_Date" as part of an aggregate function.

    Having no idea what that meant or what exactly to do to fix it, I started fiddling around. First I removed "tblProjects.Base_Due_Date" from the first line. When I ran the query I got no error and the query returned the ProjID and the sum of the extensions!!! I then went to design view and added "Base_Due_Date" and this time when I ran the query again I got exactly what I was looking for:

    ProjID Base_Due_Date Total_Days_Extended
    1 1/1/2024 40
    2 2/1/2024 15
    3 3/1/2024 20

    When I went back and looked at the resulting SQL I noticed tblProjects.Base_Due_Date was added to the GROUP BY line.

    SELECT tblProjects.pkProjID, tblProjects.Base_Due_Date, Sum(Nz(tblExtensions.NumDays)) AS Total_Days_Extended
    FROM tblProjects LEFT JOIN tblExtensions ON tblProjects.pkProjID = tblExtensions.fkProjID
    GROUP BY tblProjects.pkProjID, tblProjects.Base_Due_Date;

    Why is the GROUP BY line necessary? What does Nz mean and what does it do?

    Again thank you. Hopefully I will be able to apply what you have shown me here to a practical project that is much more complicated.
    Greg

    Visit my website: http://gregmaxey.com

  5. #5
    VBAX Regular xps350's Avatar
    Joined
    Jul 2022
    Posts
    11
    Location
    Quote Originally Posted by gmaxey View Post
    Why is the GROUP BY line necessary? What does Nz mean and what does it do?
    The GROUP BY is necessary because you want to add (group) the extensions of a project together. So group and add per ProjID.

    For some projects there are no extensions. So NumDay and the sum of that will return blank values (Null). The Nz (NullToZero) function will convert the nulls to zeroes, so that you can also calculate with it.
    Groeten,

    Peter

  6. #6
    Microsoft Word MVP 2003-2009 VBAX Guru gmaxey's Avatar
    Joined
    Sep 2005
    Posts
    3,376
    Location
    I understand. Not fully, but well enough. Thank you so much. My next objective was to filter the value returned on a specific extension type. I knuckled that part out myself:

    SELECT tblProjects.pkProjID, tblProjects.Base_Due_Date, Sum(Nz(tblExtensions.NumDays)) AS Total_Days_Extended
    FROM tblProjects LEFT JOIN tblExtensions ON tblProjects.pkProjID = tblExtensions.fkProjID
    WHERE (((tblExtensions.ExtType)="A"))
    GROUP BY tblProjects.pkProjID, tblProjects.Base_Due_Date
    Last edited by Aussiebear; 06-25-2024 at 04:09 PM.
    Greg

    Visit my website: http://gregmaxey.com

Posting Permissions

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