How to solve this?

  • I have this query

    select distinct p.first_name

    ,p.last_name

    ,'class level' = case when a.credits + t.earned_credits between 1 and 32 and a.program ='ft'then 'F1'

    when a.credits + t.earned_credits between 33 and 61 and a.program ='ft' then 'F2'

    when a.credits + t.earned_credits >= 62 and a.program ='ft'then 'F3'

    when a.credits + t.earned_credits between 1 and 25 and a.program ='pt'then 'P1'

    when a.credits + t.earned_credits between 26 and 47 and a.program ='pt'then 'P2'

    when a.credits + t.earned_credits between 48 and 70 and a.program ='pt'then 'P3'

    when a.credits + t.earned_credits >= 71 and a.program ='pt'then 'P4'

    end

    from people as p

    inner join academic as a

    on p.people_code_id=a.people_code_id

    inner join transcriptgpa as t

    on p.people_code_id=t.people_code_id

    where t.record_type='O'

    and a.academic_term='Spring'

    and a.academic_year='2008'

    and t.academic_term='Fall'

    and t.academic_year='2007'

    and a.enroll_separation ='enrl'

    and a.academic_session='main'

    and (a.program ='ft' or a.program='pt')

    order by 'class level', p.first_name

    Which is correct, BUT, not everyone has data in the transcriptgpa table, for fall 2007 but, i still need to pull them based on their a.credits. if they dont have anything in the transcriptgpa table for fall 2007. How can i do this?

  • LEFT join transcriptgpa

    And move

    t.record_type='O'

    and t.academic_term='Fall'

    and t.academic_year='2007'

    from "WHERE" to "ON"

    _____________
    Code for TallyGenerator

  • Can you clarify? Im not sure how to move them to the on line. The joins confuses me? Can you write an example?

  • [Code]...

    left join transcriptgpa as t on

    p.people_code_id=t.people_code_id

    and t.record_type='O'

    and t.academic_term='Fall'

    and t.academic_year='2007'

    where a.academic_term='Spring'

    and a.academic_year='2008'

    and a.enroll_separation ='enrl'

    and a.academic_session='main'

    and (a.program ='ft' or a.program='pt')

    [/Code]

    _____________
    Code for TallyGenerator

  • Thanks!! It worked. Now i see the people who were previosuly missing. Ive never seen a join created like this, can you explain how exactly this is working? Im looking at it, and its just not jumping out yet. I really appreciate the help btw.

  • After further review it looks like that by adding those as a left outer join by using

    on p.people_code_id=t.people_code_id

    and t.record_type='O'

    and t.academic_term='Fall'

    and t.academic_year='2007'

    its pulling IF they have a fall 2007 "o" record. If not, its just pulling their people record and using the data contained in the academic table for my case calulations, using the rest of the where clause? So my Case statement is seeing nothing in the transcriptgpa table, then using the rest of the where clause for definition. Am i close?

    *edit*

    I also notice now the people who are appearing are showing a class level of "null". Probably because they dont have any data in the transcriptgpa table, is their any way to use only the values in the acadmic table IF, they dont have data in the transcriptgpa table? Does this make sense?

  • Add IsNull() or Coalesce() around the transcription credits, like this:

    select distinct p.first_name

    ,p.last_name

    ,'class level' = case when a.credits + t.earned_credits between 1 and 32 and a.program ='ft'then 'F1'

    when a.credits + isnull(t.earned_credits, 0) between 33 and 61 and a.program ='ft' then 'F2'

    when a.credits + isnull(t.earned_credits, 0) >= 62 and a.program ='ft'then 'F3'

    when a.credits + isnull(t.earned_credits, 0) between 1 and 25 and a.program ='pt'then 'P1'

    when a.credits + isnull(t.earned_credits, 0) between 26 and 47 and a.program ='pt'then 'P2'

    when a.credits + isnull(t.earned_credits, 0) between 48 and 70 and a.program ='pt'then 'P3'

    when a.credits + isnull(t.earned_credits, 0) >= 71 and a.program ='pt'then 'P4'

    end

    ..........etc

  • One more thing i need to add...On their transcript gpa record, when it is pulling t.earned credits, their is also a trans seq number of either 001 or 002. Not everyone has a 002 record, BUT, if they do i need to use that record, if they dont have a trans seq of 002, then i need to use their 001 record. Is it possible to incoporate this into my code? This is what i have thus far, which is pulling everyone correctly, BUT, some people are appearing twice because they have both a trans seq 001 and 002 record, it should only be pulling their 002 record if they have it, if not, then 001.

    select distinct p.first_name

    ,p.last_name

    ,'class level' = case when a.credits + isnull(t.earned_credits,0) between 1 and 32 and a.program ='ft'then 'F1' when a.credits + isnull(t.earned_credits, 0) between 33 and 61 and a.program ='ft' then 'F2'when a.credits + isnull(t.earned_credits, 0) >= 62 and a.program ='ft'then 'F3' when a.credits + isnull(t.earned_credits, 0) between 1 and 25 and a.program ='pt'then 'P1'

    when a.credits + isnull(t.earned_credits, 0) between 26 and 47 and a.program ='pt'then 'P2'

    when a.credits + isnull(t.earned_credits, 0) between 48 and 70 and a.program ='pt'then 'P3'

    when a.credits + isnull(t.earned_credits, 0) >= 71 and a.program ='pt'then 'P4'

    end

    from people as p

    inner join academic as a

    on p.people_code_id=a.people_code_id

    left outer join transcriptgpa as t

    on p.people_code_id=t.people_code_id

    and t.record_type='O'and t.academic_term='Fall'--records in the transcript gpa table

    and t.academic_year='2007'

    where a.academic_term='Spring'

    and a.academic_year='2008'

    and a.enroll_separation ='enrl'

    and a.academic_session='main'

    and (a.program ='ft' or a.program='pt')

    order by 'class level'

  • still looking for an answer to the trans seq question, anyone?

  • -- One way is to join the transcript table twice and switch from isNull() to coalesce().

    select distinct

    p.first_name

    ,p.last_name

    ,'class level' = case

    when a.credits + coalesce(t2.earned_credits, t1.earned_credits, 0) between 1 and 32 and a.program ='ft'then 'F1'

    when a.credits + coalesce(t2.earned_credits, t1.earned_credits, 0) between 33 and 61 and a.program ='ft' then 'F2'

    when a.credits + coalesce(t2.earned_credits, t1.earned_credits, 0) >= 62 and a.program ='ft'then 'F3'

    when a.credits + coalesce(t2.earned_credits, t1.earned_credits, 0) between 1 and 25 and a.program ='pt'then 'P1'

    when a.credits + coalesce(t2.earned_credits, t1.earned_credits, 0) between 26 and 47 and a.program ='pt'then 'P2'

    when a.credits + coalesce(t2.earned_credits, t1.earned_credits, 0) between 48 and 70 and a.program ='pt'then 'P3'

    when a.credits + coalesce(t2.earned_credits, t1.earned_credits, 0) >= 71 and a.program ='pt'then 'P4'

    end

    from people as p

    inner join academic as a

    on p.people_code_id=a.people_code_id

    left outer join transcriptgpa as t2

    on p.people_code_id=t2.people_code_id

    and t2.record_type='O'

    and t2.academic_term='Fall'

    and t2.academic_year='2007'

    and t2.seqno = '002'

    left outer join transcriptgpa as t1

    on p.people_code_id=t1.people_code_id

    and t1.record_type='O'

    and t1.academic_term='Fall'

    and t1.academic_year='2007'

    and t1.seqno = '001'

    where a.academic_term='Spring'

    and a.academic_year='2008'

    and a.enroll_separation ='enrl'

    and a.academic_session='main'

    and (a.program ='ft' or a.program='pt')

    order by 'class level'

  • Im going to do a little research on colesce, as ive never used it. So that code will pull their transcript seq 002 record IF they have one, and if not, use there trans 001 record for the aggregate function?

  • I appreciate the help. I will try your suggested query, and update.

  • You should check BOL for the words LEFT OUTER JOIN and COALESCE.

    If you dont like looking up references (heaven forbid!) then:

    LEFT OUTER JOIN is to return ALL values from the LEFT joined table whether or not there is a matching record in the RIGHT or other joined table. Which is defined by NULL in the return value for that record, for the RIGHT table.field.value.

    COALESCE is equivalent to this CASE function:

    COALESCE(expression1,...n)

    CASE

    WHEN (expression1 IS NOT NULL) THEN expression1

    ...

    WHEN (expressionN IS NOT NULL) THEN expressionN

    ELSE NULL

    That last was taken directly from BOL.

  • When using coalesce, and have something like

    coalesce(t2.earned_credits, t1.earned_credits, 0)

    IF, t2 or t1 do not return any rows, its going to use 0 for the aggregate function instead of a null? Could this potentially be any number?

    Also, The join syntax confuses me still as ive never seen it like this. So the left outer join transcriptgpa as t1

    on p.people_code_id=t1.people_code_id I understand, but using the and t1.record_type='O'

    and t1.academic_term='Fall'

    and t1.academic_year='2007'

    and t1.transcript_seq = '001'

    statements are further limiting the results to only those that match the and statements?

  • When using ...coalesce(t2.earned_credits, t1.earned_credits, 0) ...

    IF, t2 or t1 do not return any rows, its going to use 0 for the aggregate function instead of a null?

    A: Yes. That's what happens. Coalesce returns the first non-null value from the list, reading from left to right.

    Could this potentially be any number?

    A: Yes. The datatypes of the items in the list just have to be the same.

    Also, The join syntax confuses me still as ive never seen it like this. So the left outer join transcriptgpa as t1

    on p.people_code_id=t1.people_code_id I understand, but using the and t1.record_type='O'

    and t1.academic_term='Fall'

    and t1.academic_year='2007'

    and t1.transcript_seq = '001'

    statements are further limiting the results to only those that match the and statements?

    A: Yes, the additional criteria in the ON clause work similar to the way they work in a WHERE clause.

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

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