• mcmu4256 - Friday, February 9, 2018 1:15 PM

    Please help!  I have the query below.  The output is as follows:
    ProcessDate--------------AccountNumber--------------CloseDate-----------Mem_years--------------credit_loan----chk_acct
    20180208-----------------------323314------------------------NULL--------------------23------------------------500------------------X
    20180208-----------------------323314------------------------NULL--------------------23-----------------------NULL----------------X

    But I just want it to return:
    ProcessDate--------------AccountNumber--------------CloseDate-----------Mem_years--------------credit_loan-------chk_acct
    20180208-----------------------323314------------------------NULL--------------------23------------------------500------------------X

    So some accounts have a 'Null' credit_loan, and that is fine, but if an account does have an amount in there, I only want to see that amount, I don't need to see both the 'Null' and '500' records.

    Here is my query:
    SELECT DISTINCT
             TOP (100) PERCENT dbo.ACCOUNT.ProcessDate
                             , dbo.ACCOUNT.ACCOUNTNUMBER
                             , dbo.ACCOUNT.CLOSEDATE
                             , DATEDIFF(year, dbo.ACCOUNT.OPENDATE
                             , GETDATE() - 1080) AS Mem_Years
                             , CASE WHEN loan.TYPE = 77 AND LOAN.CLOSEDATE IS NULL
                                    AND LOAN.CHARGEOFFDATE IS NULL
                                    THEN loan.originalbalance END AS credit_loan
                             , CASE WHEN SAVINGS.SHARECODE = 1 AND SAVINGS.CLOSEDATE IS NULL THEN 'x' ELSE NULL
                                        END AS chk_acct
    FROM    dbo.LOAN RIGHT OUTER JOIN
             dbo.SAVINGS ON dbo.LOAN.PARENTACCOUNT = dbo.SAVINGS.PARENTACCOUNT
                             AND dbo.LOAN.ProcessDate = dbo.SAVINGS.ProcessDate
                             LEFT OUTER JOIN
             dbo.ACCOUNT ON dbo.SAVINGS.ProcessDate = dbo.ACCOUNT.ProcessDate
                             AND dbo.SAVINGS.PARENTACCOUNT = dbo.ACCOUNT.ACCOUNTNUMBER
    WHERE       (dbo.ACCOUNT.ProcessDate = CAST(CONVERT(VARCHAR(8), GETDATE() - 1, 112) AS INT))
                             AND (dbo.ACCOUNT.CLOSEDATE IS NULL) AND
             (dbo.ACCOUNT.OPENDATE < GETDATE() - 1080)
                             AND (dbo.LOAN.ORIGINALBALANCE IS NOT NULL)
                             AND (dbo.SAVINGS.SHARECODE = 1)
                            

    ORDER BY
                dbo.ACCOUNT.ACCOUNTNUMBER

    Any help would be greatly appreciated!

    Thanks.

    The query you are using seems to be doing an outer join which results in duplicating rows and eventually getting rid of the duplicates by using a DISTINCT top 100 percent?. Follow the principle of "Filter Early, Join Late".

    Since you are only interested in getting the results of loan.type=77 and loan.closedate is null and loan.chargeoffdate is null
    why not filter out those records from the dbo.LOAN table first followed by the the rest of the join conditions

    Another point is that you have a condition which does an outer join between savings and loan table.
    Therefore any non matching records from that result set would contain NULLS for dbo.LOAN

     
    However the below condition negates the RIGHT OUTER JOIN whereby you are asserting to get you records where the fields in dbo.loan is NOT NULL

    Use SQL Formatting for readability.
    Haven't tested this since you havent supplied the create scripts and DML but guessing this should work


    SELECT DISTINCT TOP (100) PERCENT
         dbo.ACCOUNT.ProcessDate,
         dbo.ACCOUNT.ACCOUNTNUMBER,
         dbo.ACCOUNT.CLOSEDATE,
         DATEDIFF(YEAR, dbo.ACCOUNT.OPENDATE, GETDATE() - 1080) AS Mem_Years,
         /*CASE
              WHEN loan.TYPE = 77
                  AND LOAN.CLOSEDATE IS NULL
                  AND LOAN.CHARGEOFFDATE IS NULL THEN loan.originalbalance
         END AS credit_loan,*/
         loan_1.originalbalance as credit_loan
         CASE
              WHEN SAVINGS.SHARECODE = 1
                  AND SAVINGS.CLOSEDATE IS NULL THEN 'x'
              ELSE NULL
         END AS chk_acct
    FROM (SELECT *
        FROM dbo.LOAN
             WHERE loan.TYPE = 77 /* Added this condition as you are only interested in those records from LOAN with a NOT NULL credit_loan*/
              AND LOAN.CLOSEDATE IS NULL
              AND LOAN.CHARGEOFFDATE IS NULL
            ) as loan_1
    RIGHT OUTER JOIN dbo.SAVINGS
      ON loan_1.PARENTACCOUNT = dbo.SAVINGS.PARENTACCOUNT
     AND loan_1.ProcessDate = dbo.SAVINGS.ProcessDate
    LEFT OUTER JOIN dbo.ACCOUNT
      ON dbo.SAVINGS.ProcessDate = dbo.ACCOUNT.ProcessDate
     AND dbo.SAVINGS.PARENTACCOUNT = dbo.ACCOUNT.ACCOUNTNUMBER
    WHERE (dbo.ACCOUNT.ProcessDate = CAST(CONVERT(VARCHAR(8), GETDATE() - 1, 112) AS INT))
     AND (dbo.ACCOUNT.CLOSEDATE IS NULL)
     AND (dbo.ACCOUNT.OPENDATE < GETDATE() - 1080)
     AND (loan_1.ORIGINALBALANCE IS NOT NULL) /* This condition negates the RIGHT OUTER JOIN as outer joined records would be NULL and the condition says get only not NULL values*/
     AND (dbo.SAVINGS.SHARECODE = 1)
    ORDER BY dbo.ACCOUNT.ACCOUNTNUMBER