Results 1 to 5 of 5
  1. #1
    adnancanada is offline Competent Performer
    Windows XP Access 2007
    Join Date
    May 2010
    Posts
    122

    Case statement

    I have rate table that contains effective and expiry date and rates for example

    effective_date expiry_date Rate
    4/28/2024 8/31/2024 50.39
    9/1/2024 12/28/2024 70.56

    I have anther table where I need to calculate revenue based on rates. It has also has PO_date

    I have to incorporate this rate if it falls between effective and expiry date pickup above rates if it out this range pickup latest rate , in this it should pickup 70.56 from 1/1/2024 to 4/27/2024

    I need to build SQL query

    case
    when PO_date between effective_date and expiry_date then rate *wg/100
    End

    how can I setup second condition if it is out of range then it should pickup last latest rate.

    Kindly help me out.

  2. #2
    Minty is online now VIP
    Windows 10 Office 365
    Join Date
    Sep 2017
    Location
    UK - Wiltshire
    Posts
    3,145
    Simply add an Else :
    Code:
    CASE WHEN PO_date between effective_date and expiry_date then rate *wg/100
    
    ELSE (SELECT TOP 1 RATE FROM RateTable Order By ExpiryDate Desc) * wg/100
    
    End as YourCalc
    
    DLookup Syntax and others http://access.mvps.org/access/general/gen0018.htm
    Please use the star below the post to say thanks if we have helped !
    ↓↓ It's down here ↓↓

  3. #3
    pbaldy's Avatar
    pbaldy is offline Who is John Galt?
    Windows XP Access 2007
    Join Date
    Feb 2010
    Location
    Nevada, USA
    Posts
    22,643
    I'd consider a non-equi join. Off the top of my head:

    Code:
    SELECT M.Field1, M.Field2, R.Rate
    FROM MainTable M
      LEFT JOIN RateTable R ON M.PO_date >= R.effective_date and M.PO_date <= R.expiry_date
    Paul (wino moderator)
    MS Access MVP 2007-2019
    www.BaldyWeb.com

  4. #4
    CJ_London is online now VIP
    Windows 10 Access 2010 32bit
    Join Date
    Mar 2015
    Posts
    11,845
    or use a cartesian query -adapting Pauls sql

    Code:
    SELECT M.Field1, M.Field2, R.Rate
    FROM MainTable M, RateTable R
    WHERE  M.PO_date >= R.effective_date and M.PO_date <= R.expiry_date
    and if you need the current rate where an expirydate is unknown (and therefore null)

    Code:
    SELECT M.Field1, M.Field2, R.Rate
    FROM MainTable M, RateTable R
    WHERE  M.PO_date >= R.effective_date and M.PO_date <= nz(R.expiry_date, date)
    this assumes a PO date can't be later than today. If it can, substitute date for some future date such as #2100-01-01# or ensure the expiry date field has a default value of a future date

  5. #5
    Join Date
    Jun 2010
    Location
    Belgium
    Posts
    1,175
    one issue: SQL server probably won't like the cartesian query, just compare the query plans. You can use the sql from reply #3 and create a view with it. Then link it to Access as a table.


Please reply to this thread with any new information or opinions.

Similar Threads

  1. Replies: 4
    Last Post: 04-28-2019, 07:19 PM
  2. Change text case from upper to proper case
    By s.nolan in forum Access
    Replies: 1
    Last Post: 12-02-2015, 10:56 AM
  3. Replies: 3
    Last Post: 10-27-2014, 07:37 AM
  4. Case for in case field corrupt
    By Ruegen in forum Forms
    Replies: 9
    Last Post: 08-03-2014, 07:56 PM
  5. Replies: 5
    Last Post: 10-23-2012, 03:55 PM

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •  
Other Forums: Microsoft Office Forums