Alternate way for SELF JOIN

  • Hi All,

    I have a table like below.

    create table fund(

    fund_id integer primary key not null,

    name varchar(100) not null,

    short_name varchar(30) null,

    val_start_date datetime not null,

    val_end_date datetime null,

    active_version_id integer null,

    version_timestamp datetime not null,

    is_active_version int not null,

    financial_instit_id integer not null

    )

    insert into fund

    select 1,'Test','Test','Nov 8 2012','Nov 8 2012',2,'Nov 8 2012',0,1

    union all

    select 2,'Test','Test','Nov 9 2012','Nov 13 2012',null,'Nov 8 2012',1,1

    union all

    select 3,'Fund','F','Nov 8 2012','Nov 30 2012',null,'Nov 8 2012',1,1

    union all

    select 4,'TST','TST','Nov 9 2012','Nov 9 2012',null,'Nov 9 2012',1,1

    union all

    select 5,'TSTTSTTSTTST','TSTTST','Nov 9 2012','Nov 9 2012',6,'Nov 9 2012',0,1

    union all

    select 6,'TSTTSTTSTTST','TSTTST','Nov 10 2012','Nov 21 2012',null,'Nov 9 2012',1,1

    union all

    select 7,'Check','Nov 13 2012','Nov 13 2012',8,'Nov 13 2012',0,1

    union all

    select 8,'Check','Nov 14 2012','Nov 30 2012',null,'Nov 13 2012',1,1

    My requirement is to update the is_active_version column if the business_date fall between val_start_date & val_end_date

    and also the active_version_id should be update with the active fund id.

    somehow pseduo logic is:

    Fund A V1 - active from 10/11/2012 to 15/11/2012

    Fund A V2 - not yet active from 16/11/2012 to 18/11/2012

    Fund A V3 - not yet active from 19/11/2012 to 21/11/2012

    technical storage will be:

    V1 - is_active_version = 1 / active_version_id = NULL

    V2 - is_active_version = 0 / active_version_id = 1 (tehnical id of V1)

    V3 - is_active_version = 0 / active_version_id = 1 (tehnical id of V1)

    the batch will run on 16/11 morning batch

    result will be

    V1 - is_active_version = 0 / active_version_id = 2

    V2 - is_active_version = 1 / active_version_id = NULL

    V3 - is_active_version = 0 / active_version_id = 2

    karthik

  • What you're looking for is essentially an UPSERT procedure, or a MERGE.

    Here's one way of doing it:

    CREATE TABLE #ActiveRecords

    (

    fund_id INT PRIMARY KEY,

    [name] VARCHAR(100)

    )

    INSERT INTO #ActiveRecords (fund_id, [name])

    SELECT

    fund_id,

    [name]

    FROM Fund

    WHERE GETDATE() BETWEEN val_start_date AND val_end_date

    -- SET INACTIVE ALL RECORDS WHICH DON'T EXIST --

    UPDATE f

    SET f.active_version_id = NULL,

    f.is_active_version = 0

    FROM Fund f

    LEFT JOIN #ActiveRecords a ON f.[name] = a.[name]

    WHERE a.[name] IS NULL

    -- UPDATE RECORDS WHICH DO EXIST --

    UPDATE f

    SET f.active_version_id = (CASE WHEN f.fund_id = a.fund_id THEN NULL ELSE a.fund_id END),

    f.is_active_version = (CASE WHEN f.fund_id = a.fund_id THEN 1 ELSE 0 END)

    FROM Fund f

    JOIN #ActiveRecords a ON f.[name] = a.[name]

    I would recommend that you find a better way of being able to identify common records than by using the name. You should have one table that has the information about the different funds, and another table that has the information about the different instances of the funds.

Viewing 2 posts - 1 through 1 (of 1 total)

You must be logged in to reply to this topic. Login to reply