Click here to Skip to main content
15,915,336 members
Home / Discussions / Database
   

Database

 
GeneralSQL Server fills event log Pin
Hesham Amin4-Feb-05 20:00
Hesham Amin4-Feb-05 20:00 
GeneralRe: SQL Server fills event log Pin
Hesham Amin4-Feb-05 23:48
Hesham Amin4-Feb-05 23:48 
GeneralDifficult JOIN Pin
Luis Alonso Ramos4-Feb-05 15:24
Luis Alonso Ramos4-Feb-05 15:24 
GeneralRe: Difficult JOIN Pin
Yulianto.4-Feb-05 16:05
Yulianto.4-Feb-05 16:05 
GeneralRe: Difficult JOIN Pin
Luis Alonso Ramos4-Feb-05 19:18
Luis Alonso Ramos4-Feb-05 19:18 
GeneralRe: Difficult JOIN Pin
Mike Dimmick5-Feb-05 1:52
Mike Dimmick5-Feb-05 1:52 
GeneralRe: Difficult JOIN Pin
Luis Alonso Ramos5-Feb-05 6:41
Luis Alonso Ramos5-Feb-05 6:41 
GeneralRe: Difficult JOIN Pin
Mike Dimmick5-Feb-05 7:32
Mike Dimmick5-Feb-05 7:32 
Luis Alonso Ramos wrote:
I tried it and it works, but it doesn't return records for those customers that don't have yet an address (in the process of being captured, not that it should happen often.)

Well, you could change the first INNER JOIN to a LEFT JOIN. You'll then get a NULL City back for anything you've not yet added the address to. You'll probably need to turn the whole Address<->Address<->City join into a subquery so that the INNER JOINs there don't eliminate rows from the Customers table. Example:
SELECT C.ID_customer, C.Name, AC.City
FROM
    Customers C
LEFT JOIN
(
    SELECT
        A.ID_customer, Cities.Name AS City
    FROM     
        Addresses A
    INNER JOIN
    (
        SELECT ID_customer, MAX(LivesHereSince) AS LastMove
        FROM Addresses
        GROUP BY ID_customer
    ) A2
        ON A.ID_customer = A2.ID_customer AND A.LivesHereSince = A2.LastMove
    INNER JOIN
        Cities ON A.City = Cities.ID_city
) AC ON C.ID_customer = AC.ID_customer


Luis Alonso Ramos wrote:
That might be a problem. I need to perform searches based on first or last name, and so I should get several results.

When I said 'search column', I meant duplicates in the column you're using to find a single row in the historical table (in this case, LivesHereSince in the Addresses table). If you have two rows where ID_customer = 1 and LivesHereSince = 1/1/2002, you'll get two rows from the Addresses<->Addresses join, because they both match LastMoved. I seem to recall finding some disambiguating mechanism last time I needed to do this - I think I added another condition that selected the maximum ID. Unfortunately this ends up adding another join to the query. My problem was trying to extract the most recent event from a transaction log where things actually could happen within the timer period and so were recorded with the same timestamp - however, you couldn't guarantee that the IDs were necessarily in the right order.

As for the trigger, you probably want to add something like:
CREATE  TRIGGER trigUpdateCustomersCurrentAddress
ON Addresses
AFTER INSERT AS
    UPDATE Customers
    SET CurrentAddress = inserted.ID_address
    FROM inserted
    WHERE Customers.ID_customer = inserted.ID_customer
inserted is a virtual table that exists in the trigger. It contains the new versions of rows inserted or updated (you can create a trigger FOR UPDATE too - you can even use the same trigger for both insert and update). The trigger executes in the context of the statement that performs the update. You might ask, why use this form of UPDATE? Remember that you can perform batch updates from client code and that you can use an INSERT/SELECT statement to insert multiple rows in one operation, so you might actually be operating on multiple rows inside the trigger. If you're writing a trigger FOR UPDATE or FOR DELETE, the deleted table contains the old versions of rows that were updated and the rows that were deleted.

That's the simplistic version. If you might need to insert a customer's old addresses at a later time, you'll need to check what's already in the addresses table:
CREATE TRIGGER trigUpdateCustomersCurrentAddress
ON Addresses
AFTER INSERT AS
    UPDATE Customers
    SET CurrentAddress = inserted.ID_address
    FROM inserted
    INNER JOIN Addresses
        ON inserted.ID_customer = Addresses.ID_Customer AND
           inserted.LivesHereSince > Addresses.LivesHereSince
    WHERE Customers.ID_customer = inserted.ID_customer
It's surprising how few people actually 'get' the set-based concepts of SQL and its ability to work on multiple rows simultaneously, and fall back on cursors way too early. INSERT/SELECT and UPDATE FROM are extremely powerful tools.

I can't recall how exactly I first found out about the power of triggers. It was probably somewhere in Inside SQL Server 2000 by Kalen Delaney.

Once you've created the trigger, you'll need to update the existing rows:
UPDATE Customers
SET CurrentAddress = A.ID_address
FROM
    Addresses A
INNER JOIN
(
    SELECT ID_customer, MAX(LivesHereSince) AS LastMove
    FROM Addresses
    GROUP BY ID_customer
) A2
    ON A.ID_customer = A2.ID_customer AND A.LivesHereSince = A2.LastMove    
WHERE
    Customers.ID_customer = A.ID_customer


Stability. What an interesting concept. -- Chris Maunder
GeneralRe: Difficult JOIN Pin
Luis Alonso Ramos5-Feb-05 8:13
Luis Alonso Ramos5-Feb-05 8:13 
Generali can't to insert a new row Pin
Sasuko4-Feb-05 6:38
Sasuko4-Feb-05 6:38 
GeneralRe: i can't to insert a new row Pin
tojamismis4-Feb-05 6:52
tojamismis4-Feb-05 6:52 
GeneralRe: i can't to insert a new row Pin
Sasuko4-Feb-05 11:00
Sasuko4-Feb-05 11:00 
GeneralRe: i can't to insert a new row Pin
tojamismis4-Feb-05 11:23
tojamismis4-Feb-05 11:23 
GeneralRe: i can't to insert a new row Pin
Sasuko4-Feb-05 11:30
Sasuko4-Feb-05 11:30 
GeneralRe: i can't to insert a new row Pin
tojamismis4-Feb-05 14:11
tojamismis4-Feb-05 14:11 
GeneralRe: i can't to insert a new row Pin
Sasuko4-Feb-05 22:29
Sasuko4-Feb-05 22:29 
GeneralRe: i can't to insert a new row Pin
Sasuko4-Feb-05 23:58
Sasuko4-Feb-05 23:58 
GeneralRe: i can't to insert a new row Pin
tojamismis5-Feb-05 4:49
tojamismis5-Feb-05 4:49 
GeneralRe: i can't to insert a new row Pin
Sasuko5-Feb-05 12:22
Sasuko5-Feb-05 12:22 
GeneralRe: i can't to insert a new row Pin
tojamismis5-Feb-05 4:47
tojamismis5-Feb-05 4:47 
GeneralRe: i can't to insert a new row Pin
tojamismis5-Feb-05 4:58
tojamismis5-Feb-05 4:58 
GeneralEnterprise manger Pin
Tom Wright4-Feb-05 5:50
Tom Wright4-Feb-05 5:50 
GeneralRe: Enterprise manger Pin
David Salter4-Feb-05 6:15
David Salter4-Feb-05 6:15 
GeneralRe: Enterprise manger Pin
Tom Wright4-Feb-05 6:43
Tom Wright4-Feb-05 6:43 
GeneralRe: Enterprise manger Pin
tojamismis4-Feb-05 6:43
tojamismis4-Feb-05 6:43 

General General    News News    Suggestion Suggestion    Question Question    Bug Bug    Answer Answer    Joke Joke    Praise Praise    Rant Rant    Admin Admin   

Use Ctrl+Left/Right to switch messages, Ctrl+Up/Down to switch threads, Ctrl+Shift+Left/Right to switch pages.