DECLARE @Dept VARCHAR(2); SET @Dept = '15'; WITH maxmex AS ( SELECT mrmatter ,mrtk ,mrtitle ,MAX(mreffdate) as 'maxdate' FROM mexrate WHERE mrccode ='!' GROUP BY mrmatter,mrtk,mrtitle ), rates AS ( SELECT b.tkinit AS tkrinit ,b.tkeffdate AS tkrdate1 ,MIN(CASE WHEN e.tkeffdate IS NULL THEN '1/1/2026' ELSE e.tkeffdate END)-1 AS tkrdate2 ,b.tkrt01 AS tkrt01 ,b.tkrtcur AS tkrtcur FROM timerate b LEFT OUTER JOIN timerate e ON b.tkinit=e.tkinit AND e.tkeffdate > b.tkeffdate AND b.tkrtcur=e.tkrtcur GROUP BY b.tkinit,b.tkeffdate,b.tkrt01,b.tkrtcur ) SELECT client.clnum AS 'Client #' ,client.clname1 AS 'Client Name' ,mexrate.mrmatter AS 'Matter #' , matter.mdesc1 AS 'Matter Desc' , deptlab.head1 AS 'Matter Dept' , CASE WHEN mexrate.mrtitle='!' THEN mexrate.mrtk ELSE mexrate.mrtitle END AS 'Exception' , CASE WHEN mexrate.mrtitle='!' THEN tk2.tklast+', '+tk2.tkfirst ELSE 'ALL' END AS 'Exception Name' , CASE WHEN mexrate.mrtitle='!' THEN tk2.tktitle ELSE mexrate.mrtitle END AS 'Exception Title' , CASE WHEN mexrate.mrtitle='!' THEN dept2.head1 ELSE 'ALL' END AS 'Exception Dept' , CASE WHEN mexrate.mrtitle='!' THEN ldesc ELSE 'ALL' END AS 'Exception Loc' , mexrate.mreffdate , mexrate.mrrate , mexrate.mrdevper , mexrate.mrdevdol , mexrate.mrrtnum , rates.tkrt01 , rates.tkrtcur --, matter.mbillaty --, deptlab_billatty.head1 --, matter.mclosedt FROM mexrate mexrate INNER JOIN matter matter ON mexrate.mrmatter=matter.mmatter INNER JOIN deptlab deptlab ON matter.mdept=deptlab.delcode INNER JOIN maxmex maxmex ON mexrate.mrmatter=maxmex.mrmatter AND mexrate.mrtk=maxmex.mrtk AND mexrate.mrtitle=maxmex.mrtitle AND mexrate.mreffdate=maxmex.maxdate INNER JOIN timekeep timekeep ON matter.mbillaty=timekeep.tkinit LEFT OUTER JOIN timekeep tk2 ON maxmex.mrtk=tk2.tkinit LEFT OUTER JOIN deptlab dept2 ON tk2.tkdept=dept2.delcode LEFT OUTER JOIN location ON tk2.tkloc=locode INNER JOIN deptlab deptlab_billatty ON timekeep.tkdept=deptlab_billatty.delcode INNER JOIN client ON mclient=clnum LEFT OUTER JOIN rates ON mexrate.mrtk=rates.tkrinit AND rates.tkrdate2='12/31/2025' WHERE matter.mclosedt IS NULL AND (mexrate.mrtk='!' OR mexrate.mrtk IN (SELECT tkinit FROM timekeep WHERE tktmdate IS NULL)) AND (mrdevper<>0 OR mrdevper IS NULL) AND (mrdevdol<>0 OR mrdevdol IS NULL) AND matter.mdept=@Dept UNION ALL ------------------------------------------------------------------------------------------- -- Client Exceptions ------------------------------------------------------------------------------------------- SELECT cexrate.crclient AS 'Client #' , client.clname1 AS 'Client Name' , 'All' AS 'Matter #' , 'All' AS 'Matter Desc' , 'All' AS 'Matter Dept' , CASE WHEN cexrate.crtitle='!' THEN cexrate.crtk ELSE cexrate.crtitle END AS 'Exception' , CASE WHEN cexrate.crtitle='!' THEN tk2.tklast+', '+tk2.tkfirst ELSE 'ALL' END AS 'Exception Name' , CASE WHEN cexrate.crtitle='!' THEN tk2.tktitle ELSE cexrate.crtitle END AS 'Exception Title' , CASE WHEN cexrate.crtitle='!' THEN dept2.head1 ELSE 'ALL' END AS 'Exception Dept' , CASE WHEN cexrate.crtitle='!' THEN ldesc ELSE 'ALL' END AS 'Exception Loc' , cexrate.creffdate , cexrate.crrate , cexrate.crdevper , cexrate.crdevdol , cexrate.crrtnum , rates.tkrt01 , rates.tkrtcur FROM cexrate INNER JOIN (SELECT crclient ,crtk ,crtitle ,MAX(creffdate) as 'maxdate' FROM cexrate WHERE crccode ='!' GROUP BY crclient,crtk,crtitle) AS maxcex ON cexrate.crclient=maxcex.crclient AND cexrate.crtk=maxcex.crtk AND cexrate.crtitle=maxcex.crtitle AND cexrate.creffdate=maxcex.maxdate LEFT OUTER JOIN timekeep tk2 ON maxcex.crtk=tk2.tkinit LEFT OUTER JOIN deptlab dept2 ON tk2.tkdept=dept2.delcode LEFT OUTER JOIN location ON tk2.tkloc=locode INNER JOIN client ON cexrate.crclient=client.clnum LEFT OUTER JOIN ( SELECT b.tkinit AS tkrinit ,b.tkeffdate AS tkrdate1 ,MIN(CASE WHEN e.tkeffdate IS NULL THEN '1/1/2026' ELSE e.tkeffdate END)-1 AS tkrdate2 ,b.tkrt01 AS tkrt01 ,b.tkrtcur AS tkrtcur FROM timerate b LEFT OUTER JOIN timerate e ON b.tkinit=e.tkinit AND e.tkeffdate > b.tkeffdate AND b.tkrtcur=e.tkrtcur GROUP BY b.tkinit,b.tkeffdate,b.tkrt01,b.tkrtcur ) AS rates ON cexrate.crtk=rates.tkrinit AND rates.tkrdate2='12/31/2025' WHERE (cexrate.crtk='!' OR cexrate.crtk IN (SELECT tkinit FROM timekeep WHERE tktmdate IS NULL)) AND (crdevper IS NULL OR crdevper <> 0) AND (crdevdol IS NULL OR crdevdol <> 0) AND EXISTS (SELECT * FROM matter WHERE mclient=clnum AND mdept=@Dept AND mclosedt IS NULL)
Wednesday, September 17, 2014
Client and Matter Exception Rates
Client and matter exception rates are one of the more difficult areas to manage in Enterprise. This can be complicated by the fact in versions prior to 3.10, there is no end date on the records. In order to end an exception, you had to enter a new line with a zero percent or dollar deviation. Thankfully this has been corrected in 3.10. For those still on prior versions, this bit of code gives you a full view of exceptions for clients and matters. In an effort to make the data a bit more manageable, there is a department variable that limits the results of the query to a single department.
This is probably as good a time as any to point out the merits (and limitations) of common table expressions (CTE) as opposed to sub-queries. You can see in the top portion of the query below that there is a "WITH" expression. Using a WITH expression creates a common table expression from a query and gives it a name, in this case maxmex. You can then call this CTE later in your query as if it were a table. However, note in the client section that I've used subqueries instead of a CTE. WITH expressions can only be used at the beginning of a query, and a previous query/statement must be ended with a semicolon before a WITH expression can be used. Since the UNION ALL is a continuation of the query, we can't use a WITH at that point. However, in my opinion, CTEs are much easier to read and understand than sub-queries, so I highly recommend their use.
Subscribe to:
Post Comments (Atom)
No comments:
Post a Comment