Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Update Top 1


Update Top 1

Author
Message
Ben Wilson-179630
Ben Wilson-179630
SSC Veteran
SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)

Group: General Forum Members
Points: 204 Visits: 192

Hi All,

I have a table with the following fields: TransactionId, AssetType, AssetDetails, Order. Primary key is TransactionId, AssetType and Order.

One of the current assetTypes is 'House'. A Transaction can have many houses (Hence order is part of the key). I am trying to update the AssetType of the first house for each transaction to 'Home' (ie where AssetType is currently = 'House' and Order is the min 'Order' where for assetType House).

What i tried to do (that didnt work) was:

UPDATE TOP 1 tbl_ApplicantAsset
SET AssetType = 'Home'
FROM Asset

WHERE (tbl_Asset.AssetType = N'House')
GROUP BY Asset.TransactionId

It seems Update Top 1 is not a valid statement...any suggestions for ways to go about this that will work ???

Thanks

Ben


GilaMonster
GilaMonster
SSC-Forever
SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)

Group: General Forum Members
Points: 47343 Visits: 44392
I'm not sure I completely understood what you're trying to do, but the below code should be fairly close to what you're trying.

If I've missed the mark by a few miles, please post the table definitions.

Update tbl_ApplicantAsset SET tbl_ApplicantAsset = 'Home' FROM tbl_ApplicantAsset INNER JOIN
(select TransactionID, min([Order]) as minOrder from tbl_ApplicantAsset where AssetType = N'House') Filtered
On tbl_ApplicantAsset.TransactionID = Filtered.TransactionID AND tbl_ApplicantAsset.[Order] = Filtered.minOrder


Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


Kenneth Wilhelmsson
Kenneth Wilhelmsson
SSCommitted
SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)

Group: General Forum Members
Points: 1579 Visits: 699

You are aware that by updating 'House' to 'Home' you are in fact also changing the Primary Key for that record? Have you carefully analyzed what the consequences of such an update would be for the integrity of your data?

/Kenneth





Ben Wilson-179630
Ben Wilson-179630
SSC Veteran
SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)

Group: General Forum Members
Points: 204 Visits: 192

Thanks for the help guys...yu were right on the mark with the suggested code I didnt know i could do a join like that!!

I hadnt considered that I was changing the primary key, but have had a good look, and in this case, it wont have any adverse affects on the data

Thanks again!

Ben


Kenneth Wilhelmsson
Kenneth Wilhelmsson
SSCommitted
SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)

Group: General Forum Members
Points: 1579 Visits: 699

Of course I don't know your data as you do, but.... I must stress my point here.

I just want to make sure that you do realize that by doing this update, you will create a new instance (eg row) of the entity (in table) that previously didn't exist, and also by doing so, you will delete an existing instance of the entity, thereby changing the fact that it has ever existed, along with it being the 'parent' of several rows that I suppose have some relation to each other (the order differs only).

The point I'm trying to make is that you want to change the PK for some, but not for all of the registered and currently related asset records. This seems a little strange to me, that's why I'm, asking. I want you to be sure that you're not doing anything you'd later regret..

/Kenneth





Ben Wilson-179630
Ben Wilson-179630
SSC Veteran
SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)

Group: General Forum Members
Points: 204 Visits: 192
Thanks again Kenneth...the asset table does not have any child tables, and the reason for the update is to introduce a new asset type 'Home' for all home owners (as we now wish to distinguish investment properties from homes). AS long as the new home asset is still realted to the same TransactionId, all will be well!
Richard Berman
Richard Berman
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 2
BTW, "UPDATE TOP" will work in SQL Server 2005.
Ben Wilson-179630
Ben Wilson-179630
SSC Veteran
SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)SSC Veteran (204 reputation)

Group: General Forum Members
Points: 204 Visits: 192
Cool! will be great to see what 2005 can do! Sounds like there is gonna be lots of new and useful commands...which will be good, but even more to learn!
discotech
discotech
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 1

Here's an alternative that should also work.

Update ta
SET ta.tbl_ApplicantAsset = 'Home'
FROM tbl_ApplicantAsset ta
where ta.tbl_ApplicantAsset = 'House'
and ta.[Order] = ( select min([t2.Order])
from tbl_ApplicantAsset t2
where t2.TransactionID = ta.TransactionID
and t2.AssetType = N'House')





Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search