Query Help

  • Hello Everyone

    I Have one task, in that there are two tables,

    one has student testing dates

    and other has student enrollment dates.

    CREATE TABLE #TestDates

    (

    iSchoolYearCode int NOT NULL,

    dtStartDate DATETIME NOT NULL

    )

    insert into #TestDates values (2011,'2011-08-22 00:00:00.000')

    insert into #TestDates values (2011,'2011-12-14 00:00:00.000')

    insert into #TestDates values (2011,'2012-05-01 00:00:00.000')

    insert into #TestDates values (2012,'2012-08-30 00:00:00.000')

    This tables has students Test Dates.

    CREATE TABLE #EnrollmentDates

    (

    iSchoolYearCode int NOT NULL,

    dtRunDate DATETIME NOT NULL

    )

    insert into #EnrollmentDates values (2011,'2011-06-16 06:00:06.780')

    insert into #EnrollmentDates values (2011,'2011-10-14 11:43:48.840')

    insert into #EnrollmentDates values (2011,'2011-11-01 06:00:05.353')

    insert into #EnrollmentDates values (2011,'2011-12-03 06:00:06.980')

    insert into #EnrollmentDates values (2011,'2012-01-11 06:00:06.947')

    insert into #EnrollmentDates values (2011,'2012-01-28 06:00:06.733')

    insert into #EnrollmentDates values (2011,'2012-02-11 06:00:07.130')

    insert into #EnrollmentDates values (2011,'2012-03-10 06:00:09.083')

    insert into #EnrollmentDates values (2011,'2012-04-14 06:00:08.330')

    insert into #EnrollmentDates values (2011,'2012-05-12 06:00:11.163')

    insert into #EnrollmentDates values (2011,'2012-06-14 06:00:07.893')

    insert into #EnrollmentDates values (2012,'2012-10-08 23:47:43.897')

    This tables has students Enrollment Dates.

    I need to display most nearest Enrollment Dates with respect to Test dates

    something link this

    dtStartDatedtRunDate

    2011-08-22 00:00:00.0002011-06-16 06:00:06.780

    2011-12-14 00:00:00.0002011-12-03 06:00:06.980

    2012-05-01 00:00:00.0002012-04-14 06:00:08.330

    2012-08-30 00:00:00.0002012-06-14 06:00:07.893

    Please help me to build the logic for this

    Thanks

  • This looks a lot like homework. We don't typically provide answers for homework because we want you to learn.

    However, it seems you want the most recent date prior to the test date for each value in the test table?

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Sean Lange (10/10/2012)


    This looks a lot like homework. We don't typically provide answers for homework because we want you to learn.

    However, it seems you want the most recent date prior to the test date for each value in the test table?

    This is not Homework. I have task in that i need to use this logic.

    and You correct I need most recent date prior to the test date.

    I am thinking to do with cursor, what you say?

  • yogi123 (10/10/2012)


    Sean Lange (10/10/2012)


    This looks a lot like homework. We don't typically provide answers for homework because we want you to learn.

    However, it seems you want the most recent date prior to the test date for each value in the test table?

    This is not Homework. I have task in that i need to use this logic.

    and You correct I need most recent date prior to the test date.

    I am thinking to do with cursor, what you say?

    No you certainly don't need a cursor for this. Cursors are very rarely required for data manipulation. They are very resource intensive and can be huge issue for performance.

    I can think of two ways to do this immediately without a cursor. I am sure there are other ways to do this.

    The first is an inline subquery.

    select *, (select top 1 dtRunDate from #EnrollmentDates where dtRunDate <= #TestDates.dtStartDate order by dtRunDate desc) as dtRunDate

    from #TestDates

    The second uses Apply as a correlated subquery.

    select *

    from #TestDates

    outer apply (select top 1 dtRunDate from #EnrollmentDates where dtRunDate <= #TestDates.dtStartDate order by dtRunDate desc) x

    The second approach will produce a slightly simpler execution plan. You need to make sure you understand the logic of either approach.

    BTW, excellent job posting ddl and sample data. I wish more people would post things so nicely. It really makes it easy for us to help. 😀

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Sean Lange (10/10/2012)


    yogi123 (10/10/2012)


    Sean Lange (10/10/2012)


    This looks a lot like homework. We don't typically provide answers for homework because we want you to learn.

    However, it seems you want the most recent date prior to the test date for each value in the test table?

    This is not Homework. I have task in that i need to use this logic.

    and You correct I need most recent date prior to the test date.

    I am thinking to do with cursor, what you say?

    No you certainly don't need a cursor for this. Cursors are very rarely required for data manipulation. They are very resource intensive and can be huge issue for performance.

    I can think of two ways to do this immediately without a cursor. I am sure there are other ways to do this.

    The first is an inline subquery.

    select *, (select top 1 dtRunDate from #EnrollmentDates where dtRunDate <= #TestDates.dtStartDate order by dtRunDate desc) as dtRunDate

    from #TestDates

    The second uses Apply as a correlated subquery.

    select *

    from #TestDates

    outer apply (select top 1 dtRunDate from #EnrollmentDates where dtRunDate <= #TestDates.dtStartDate order by dtRunDate desc) x

    The second approach will produce a slightly simpler execution plan. You need to make sure you understand the logic of either approach.

    BTW, excellent job posting ddl and sample data. I wish more people would post things so nicely. It really makes it easy for us to help. 😀

    Thank You so much

  • yogi123 (10/10/2012)


    Hello Everyone

    I Have one task, in that there are two tables,

    one has student testing dates

    and other has student enrollment dates.

    CREATE TABLE #TestDates

    (

    iSchoolYearCode int NOT NULL,

    dtStartDate DATETIME NOT NULL

    )

    insert into #TestDates values (2011,'2011-08-22 00:00:00.000')

    insert into #TestDates values (2011,'2011-12-14 00:00:00.000')

    insert into #TestDates values (2011,'2012-05-01 00:00:00.000')

    insert into #TestDates values (2012,'2012-08-30 00:00:00.000')

    This tables has students Test Dates.

    CREATE TABLE #EnrollmentDates

    (

    iSchoolYearCode int NOT NULL,

    dtRunDate DATETIME NOT NULL

    )

    insert into #EnrollmentDates values (2011,'2011-06-16 06:00:06.780')

    insert into #EnrollmentDates values (2011,'2011-10-14 11:43:48.840')

    insert into #EnrollmentDates values (2011,'2011-11-01 06:00:05.353')

    insert into #EnrollmentDates values (2011,'2011-12-03 06:00:06.980')

    insert into #EnrollmentDates values (2011,'2012-01-11 06:00:06.947')

    insert into #EnrollmentDates values (2011,'2012-01-28 06:00:06.733')

    insert into #EnrollmentDates values (2011,'2012-02-11 06:00:07.130')

    insert into #EnrollmentDates values (2011,'2012-03-10 06:00:09.083')

    insert into #EnrollmentDates values (2011,'2012-04-14 06:00:08.330')

    insert into #EnrollmentDates values (2011,'2012-05-12 06:00:11.163')

    insert into #EnrollmentDates values (2011,'2012-06-14 06:00:07.893')

    insert into #EnrollmentDates values (2012,'2012-10-08 23:47:43.897')

    This tables has students Enrollment Dates.

    I need to display most nearest Enrollment Dates with respect to Test dates

    something link this

    dtStartDatedtRunDate

    2011-08-22 00:00:00.0002011-06-16 06:00:06.780

    2011-12-14 00:00:00.0002011-12-03 06:00:06.980

    2012-05-01 00:00:00.0002012-04-14 06:00:08.330

    2012-08-30 00:00:00.0002012-06-14 06:00:07.893

    Please help me to build the logic for this

    Thanks

    This is what I came up with...

    WITH dt AS

    (

    SELECTDENSE_RANK() OVER (ORDER BY tdt.dtStartDate) x,

    tdt.dtStartDate,

    edt.dtRunDate

    FROM #TestDates tdt

    CROSS JOIN #EnrollmentDates edt

    WHERE tdt.dtStartDate > edt.dtRunDate

    ),

    maxSDt AS

    (

    SELECT DISTINCT x,

    MAX(dtStartDate) OVER (PARTITION BY x) y

    FROM dt

    ),

    maxRDt AS

    (

    SELECT DISTINCT x,

    MAX(dtRunDate) OVER (PARTITION BY x) y

    FROM dt

    )

    SELECTSDt.y dtStartDate,

    RDt.y dtRunDate

    FROM maxRDt RDt

    JOIN maxSDt SDt ON Rdt.x = SDt.x

    It should still be optimized but this should do.

    Update... what Sean Lange posted is much better and will produce a much simpler query plan. I had not seen his last post when I posted this. Both of our approaches are better than a cursor or loop.

    "I cant stress enough the importance of switching from a sequential files mindset to set-based thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code."

    -- Itzik Ben-Gan 2001

  • This query would give the best performance from all the queries posted above 🙂

    SELECT dtStartDate,

    (SELECT Max(dtRunDate)

    FROM #EnrollmentDates

    WHERE dtRunDate <= #TestDates.dtStartDate)

    FROM #TestDates

    I am certainly not trying to compete with experts like Sean here. But just came up with my own better version 😀

    ~ Lokesh Vij


    Guidelines for quicker answers on T-SQL question[/url]
    Guidelines for answers on Performance questions

    Link to my Blog Post --> www.SQLPathy.com[/url]

    Follow me @Twitter

  • Hi Sean

    There is slight difference in requirement

    so the table and data as follows

    CREATE TABLE #TestDates

    (

    iSchoolYearCode int NOT NULL,

    dtStartDate DATETIME NOT NULL

    )

    insert into #TestDates values (2011,'2011-08-22 00:00:00.000')

    insert into #TestDates values (2011,'2011-12-14 00:00:00.000')

    insert into #TestDates values (2011,'2012-05-01 00:00:00.000')

    insert into #TestDates values (2012,'2012-08-30 00:00:00.000')

    CREATE TABLE #EnrollmentDates

    (

    iSchoolYearCode int NOT NULL,

    dtRunDate DATETIME NOT NULL

    )

    insert into #EnrollmentDates values (2010,'2011-06-16 06:00:06.780')

    insert into #EnrollmentDates values (2011,'2011-10-14 11:43:48.840')

    insert into #EnrollmentDates values (2011,'2011-11-01 06:00:05.353')

    insert into #EnrollmentDates values (2011,'2011-12-03 06:00:06.980')

    insert into #EnrollmentDates values (2011,'2012-01-11 06:00:06.947')

    insert into #EnrollmentDates values (2011,'2012-01-28 06:00:06.733')

    insert into #EnrollmentDates values (2011,'2012-02-11 06:00:07.130')

    insert into #EnrollmentDates values (2011,'2012-03-10 06:00:09.083')

    insert into #EnrollmentDates values (2011,'2012-04-14 06:00:08.330')

    insert into #EnrollmentDates values (2011,'2012-05-12 06:00:11.163')

    insert into #EnrollmentDates values (2011,'2012-06-14 06:00:07.893')

    insert into #EnrollmentDates values (2012,'2012-10-08 23:47:43.897')

    now, if the TestDate is first date of Year, then need to update first enroll date from #EnrollmentDates

    so now desired output looks like

    dtStartDatedtRunDate

    2011-08-22 00:00:00.0002011-10-14 11:43:48.840

    2011-12-14 00:00:00.0002011-12-03 06:00:06.980

    2012-05-01 00:00:00.0002012-04-14 06:00:08.330

    2012-08-30 00:00:00.0002012-10-08 23:47:43.897

    That means we need to display first Enrollment date for first test date for particular Year.

    Please help me one more time to build this.

  • Lokesh Vij (10/10/2012)


    This query would give the best performance from all the queries posted above 🙂

    SELECT dtStartDate,

    (SELECT Max(dtRunDate)

    FROM #EnrollmentDates

    WHERE dtRunDate <= #TestDates.dtStartDate)

    FROM #TestDates

    I am certainly not trying to compete with experts like Sean here. But just came up with my own better version 😀

    I am certainly no expert and this is by no means a competition. This is definitely a better version than mine. Not sure why I used top instead of max. 😉

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Lokesh Vij (10/10/2012)


    This query would give the best performance from all the queries posted above 🙂

    SELECT dtStartDate,

    (SELECT Max(dtRunDate)

    FROM #EnrollmentDates

    WHERE dtRunDate <= #TestDates.dtStartDate)

    FROM #TestDates

    I am certainly not trying to compete with experts like Sean here. But just came up with my own better version 😀

    I cleaned my original up which runs much faster but can't compete with Lokesh Vij's example above.

    ;WITH dt AS

    (

    SELECTDENSE_RANK() OVER (ORDER BY tdt.dtStartDate) x,

    tdt.dtStartDate,

    edt.dtRunDate

    FROM #TestDates tdt

    JOIN #EnrollmentDates edt

    ON tdt.dtStartDate > edt.dtRunDate

    ),

    maxSDt AS

    (

    SELECT DISTINCT x,

    MAX(dtStartDate) OVER (PARTITION BY x) dtStartDate,

    MAX(dtRunDate) OVER (PARTITION BY x) dtRunDate

    FROM dt

    )

    SELECTdtStartDate,

    dtRunDate

    FROM maxSDt

    "I cant stress enough the importance of switching from a sequential files mindset to set-based thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code."

    -- Itzik Ben-Gan 2001

  • That may win a bit:

    SELECT td.dtStartDate

    ,Max(dtRunDate)

    FROM #TestDates td

    LEFT JOIN #EnrollmentDates ed

    ON ed.dtRunDate <= td.dtStartDate

    group by td.dtStartDate

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • I'm a bit confused with OP last requirements. Looks like expected outcome doesn't corresponds to:

    That means we need to display first Enrollment date for first test date for particular Year.

    May be something like that:

    ;with CTE1

    AS

    (

    SELECT td.dtStartDate

    ,MAX(ed.dtRunDate) dtRunDate

    ,YEAR(td.dtStartDate) sdYear

    FROM #TestDates td

    LEFT JOIN #EnrollmentDates ed

    ON ed.dtRunDate <= td.dtStartDate

    group by td.dtStartDate

    )

    , CTE2

    AS

    (

    SELECT sdYear, MIN(dtRunDate) dtRunDate

    FROM CTE1

    GROUP BY sdYear

    )

    SELECT c1.dtStartDate, c2.dtRunDate

    FROM CTE1 c1

    JOIN CTE2 c2

    ON c2.sdYear = c1.sdYear

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • select dtStartDate,dtRunDate from #TestDates

    cross apply (select top 1 * from #EnrollmentDates

    where dtRunDate<=#TestDates.dtStartDate order by dtRunDate desc ) b

  • cooljagadeesh (10/11/2012)


    select dtStartDate,dtRunDate from #TestDates

    cross apply (select top 1 * from #EnrollmentDates

    where dtRunDate<=#TestDates.dtStartDate order by dtRunDate desc ) b

    This looks strikingly similar to the one I posted yesterday. The version using MAX that Lokesh posted will beat this on performance.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

Viewing 14 posts - 1 through 13 (of 13 total)

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