Solved

Update table A from TOP in table B

Posted on 2012-04-06
16
330 Views
Last Modified: 2012-04-11
Given table A as follows:

pk_a   expiration_date
1        1/15/2012
2        1/15/2012
3        2/12/2012

and table B as follows:

pk_b   fk_a            date_expires
1        1                1/15/2012
2        1                1/15/2013
3        2                1/15/2012
4        2                1/15/2013
5        3                2/12/2011
6        3                2/12/2012
7        3                2/12/2013

How can I write an update query in Access 2003 SQL that will update A.expiration_date with B.date_expires from the highest B.pk_b for the join between A.pk_a and B.fk_a?

Thanks in advance,

Pete
0
Comment
Question by:petekipe
  • 6
  • 5
  • 3
  • +1
16 Comments
 
LVL 17

Expert Comment

by:Anuroopsundd
ID: 37815267
http://www.techonthenet.com/access/queries/update2_2007.php

use the max functionfor getting highest value
0
 

Author Comment

by:petekipe
ID: 37815278
Max function is my problem -- I don't know how to incorporate it.  Can you provide an example?
0
 
LVL 17

Expert Comment

by:Anuroopsundd
ID: 37815289
0
 
LVL 17

Expert Comment

by:Anuroopsundd
ID: 37815292
0
 
LVL 77

Expert Comment

by:peter57r
ID: 37815308
Update A set A.expiration_date = Dmax("expiration_date", "B", "fk_a=" & pk_a)

The above assumes pk_a is numeric.

If it is text then you would need..

Update A set A.expiration_date = Dmax("expiration_date", "B", "fk_a='" & pk_a "'")

You cannot run an update query in Access if it includes any simple aggregate function (max(), min() , avg() etc) anywher in its structure.
You CAN use the domain aggregates DMax() DMin() etc as in the solution above.
0
 

Author Comment

by:petekipe
ID: 37815323
Neither of the solutions in the stackoverflow link work in Access 2003, nor does the solution in access-programmers.co.uk.  The following looks logically like what I want -- I've changed the code to the real table and column names:

UPDATE     Station A
SET             expiration_date =
                      (SELECT   MAX([date_expires])
                       FROM      License B
                       WHERE   A.pk_station = B.fk_station)

But I'm getting the error, "Operation must use an updateable query."  Any ideas?
0
 
LVL 77

Expert Comment

by:peter57r
ID: 37815326
See my post immediately before yours.
0
 

Author Comment

by:petekipe
ID: 37815355
peter57r, you're really close -- but the code sets Station.expiration_date to the maximum expiration date of any of its joined rows from License.  Referring to the tables given in my original post, I need to set A.expiration_date to the B.date_expires of the highest B.pk_b for the join of A.pk_a = B.fk_a.  i.e, the date I want isn't necessarily the maximum date in B for the join, it should be the last-entered date (having the highest B.pk_b for the join).  Does that make sense?
0
What Is Threat Intelligence?

Threat intelligence is often discussed, but rarely understood. Starting with a precise definition, along with clear business goals, is essential.

 
LVL 77

Expert Comment

by:peter57r
ID: 37815389
The code I posted does what you are asking.
Post the sql you are using.
0
 

Author Comment

by:petekipe
ID: 37816322
UPDATE Station
SET    Station.expiration_date = Dmax("date_expires", "License", "fk_station=" & pk_station)

What in the code causes date_expires to be chosen from the highest License pk related by foreign key to a particular Station pk?
0
 
LVL 77

Expert Comment

by:peter57r
ID: 37816851
This bit of the DMax does the matching...

 "fk_station=" & pk_station)

This Update command definitely updates table Station with the max date_expires for the matching keys.

Can you confirm that both Station.expiration_date and date_expires are defined as datetime fields.
0
 
LVL 9

Expert Comment

by:keyu
ID: 37822505
Your Query:

UPDATE     Station A
SET             expiration_date =
                      (SELECT   MAX([date_expires])
                       FROM      License B
                       WHERE   A.pk_station = B.fk_station)


First option: Run the sub query individually and check whether its giving records or not.

SELECT   MAX([date_expires])  FROM      License B   WHERE   A.pk_station = B.fk_station

if you still face the error check there might be null values inside "date_expires" field

if it contains null or blank values filter null value records by using

SELECT   MAX([date_expires])  FROM      License B   WHERE   A.pk_station = B.fk_station and isnull([date_expires],'') <>''
0
 

Author Comment

by:petekipe
ID: 37827808
keyu:  Access 2003 does not allow an update query to contain a subquery containing a MAX or TOP function.

peter57r:  Both fields are defined as datetime fields.  I don't think I made the point clear in my ID: 37815355 post:  I don't want the maximum date value -- I want the date value from the most recent License row, which is the row having the highest pk_license among the joined rows.
0
 
LVL 77

Accepted Solution

by:
peter57r earned 100 total points
ID: 37831518
I see.

Then it gets more complicated.  I think this is what you want (subject to my typos!)

Update A set A.expiration_date = DLookup("expiration_date", "B", "pk-b =" & Dmax("pk-B", "B", "fk_a= " & pk_a))
0
 
LVL 9

Expert Comment

by:keyu
ID: 37831896
UPDATE     Station A
SET             expiration_date =
                      (SELECT   top 1 date_expires
                       FROM      License B
                       WHERE   A.pk_station = B.fk_station order by date_expires desc)
0
 

Author Closing Comment

by:petekipe
ID: 37833065
peter57r:  Bingo!  For the record, following is my final query:

Update Station
SET       Station.expiration_date = DLookup("date_expires", "License", "pk_license =" & Dmax("pk_license", "License", "fk_station= " & pk_station))

Note:  Out of roughly 18000 Station rows, only about 1000 had corresponding License rows. According to MS's docs on DLookup/Dmax, if the conditions are not met, null is returned, which caused 17000 rows not to be updated because of type conversion errors.  Ideally, the update could have been accomplished via a right join, to eliminate unlicensed stations from even being considered, but as was pointed out early in this thread, Access doesn't allow an aggregation function in an update query.

Thank you VERY much for your insightful help, peter57r!

Pete
0

Featured Post

What Is Threat Intelligence?

Threat intelligence is often discussed, but rarely understood. Starting with a precise definition, along with clear business goals, is essential.

Join & Write a Comment

Composite queries are used to retrieve the results from joining multiple queries after applying any filters. UNION, INTERSECT, MINUS, and UNION ALL are some of the operators used to get certain desired results.​
A simple tool to export all objects of two Access files as text and compare it with Meld, a free diff tool.
As developers, we are not limited to the functions provided by the VBA language. In addition, we can call the functions that are part of the Windows operating system. These functions are part of the Windows API (Application Programming Interface). U…
Familiarize people with the process of utilizing SQL Server stored procedures from within Microsoft Access. Microsoft Access is a very powerful client/server development tool. One of the SQL Server objects that you can interact with from within Micr…

744 members asked questions and received personalized solutions in the past 7 days.

Join the community of 500,000 technology professionals and ask your questions.

Join & Ask a Question

Need Help in Real-Time?

Connect with top rated Experts

12 Experts available now in Live!

Get 1:1 Help Now