SELECT Invoices.InvMatter ,clname1 AS 'Client Name' ,mdesc1 AS 'Matter Description' ,tkinit AS 'BA #' ,tklast+', '+tkfirst AS 'BillAty' ,ldesc AS 'BA Location' ,Invoices.invInvoice ,Invoices.invDate ,Invoices.invFeeAmt ,Invoices.invCostAmt ,Invoices.invAmount ,Credits.pmtToday ,Credits.woffToday ,Invoices.invAmount-Credits.pmtAmount-Credits.woffAmount AS Balance FROM ( SELECT linvoice AS invInvoice ,lmatter AS invMatter ,ltradat AS invDate ,SUM(CASE WHEN lcfco='F' THEN lamount ELSE 0 END) AS invFeeAmt ,SUM(CASE WHEN lcfco='C' THEN lamount ELSE 0 END) AS invCostAmt ,SUM(lamount) AS invAmount FROM ledger INNER JOIN ledcode ON llcode=lccode WHERE lcfco IS NOT NULL GROUP BY linvoice,lmatter,ltradat ) AS Invoices INNER JOIN ( SELECT inv.linvoice AS invInvoice ,inv.lmatter AS invMatter ,inv.ltradat AS invDate ,SUM(CASE WHEN ccode.lccollhs='Y' AND cred.ltradat >= GETDATE()-1 THEN cred.lamount ELSE 0 END) AS pmtToday ,SUM(CASE WHEN ccode.lccollhs='N' AND cred.ltradat >= GETDATE()-1 THEN cred.lamount ELSE 0 END) AS woffToday ,SUM(CASE WHEN ccode.lccollhs='Y' THEN cred.lamount ELSE 0 END) AS pmtAmount ,SUM(CASE WHEN ccode.lccollhs='N' THEN cred.lamount ELSE 0 END) AS woffAmount FROM ledger cred INNER JOIN ledcode ccode ON cred.llcode=ccode.lccode INNER JOIN ledger inv ON cred.laptoin=inv.lindex INNER JOIN ledcode icode ON inv.llcode=icode.lccode WHERE ccode.lcfco IS NULL AND icode.lcfco IS NOT NULL AND cred.lzero <> 'R' AND EXISTS (SELECT * FROM ledger p INNER JOIN ledcode pc ON p.llcode=pc.lccode WHERE pc.lcfco IS NULL AND p.ltradat >= GETDATE()-1 AND p.linvoice=cred.linvoice AND p.lmatter=cred.lmatter AND p.lzero<> 'R') GROUP BY inv.linvoice,inv.lmatter,inv.ltradat ) AS Credits ON Invoices.invInvoice=Credits.invInvoice AND Invoices.invMatter=Credits.invMatter AND Invoices.invDate=Credits.invDate INNER JOIN matter ON Invoices.invMatter=mmatter INNER JOIN timekeep ON mbillaty=tkinit INNER JOIN client ON mclient=clnum INNER JOIN location ON tkloc=locode WHERE Invoices.invAmount-Credits.pmtAmount-Credits.woffAmount <> 0
Friday, September 19, 2014
Short Paid Invoices
Invoices that are partially paid are a recurring issue at many law firms. The following query will return current day short paid invoices, their original value, the current day payment and the balance left on the invoice. You'll notice that I did not use common table expressions in this query. The reason for this is that this query was developed for an Extend event, and in Extend the final line must always start with SELECT, so starting with WITH won't work!
Thursday, September 18, 2014
1099 Review Data
At my firm, we have not used Elite's native 1099 reporting app within Enterprise for several years. Instead, we opt to export information from Enterprise and import into a third party 1099 application, which in our case is Convey. As such, we use a SQL based report to review all our transactions for correct flagging. This is done in two parts: 1) a summary by vendor where the vendor, voucher or address 1099 flag is not "N", and 2) a listing of all new vendors.
Part 1
WITH trust AS ( SELECT trvendor ,trvendoraddr ,tr1099flag ,SUM(-tramount/cdrate) AS 'tramt' FROM trcheck INNER JOIN trsttran ON trcheck.trindex=trsttran.trindex INNER JOIN tracct ON trsttran.tracct=tracct.tracct INNER JOIN matter ON trmatter=mmatter INNER JOIN currates ON trcurcd=curcode AND trdate bETWEEN cddate1 AND cddate2 AND currates.trtype='A' WHERE YEAR(trdate)='2014' AND tr1099flag IS NOT NULL AND tr1099flag <> 'N' AND trsttran.trflag IS NULL GROUP BY trvendor,trvendoraddr,tr1099flag ), apamt AS ( SELECT csddt.apnum ,csddt.apaddid ,csddt.ap1099 ,SUM(csddt.amt/currates.cdrate) AS 'apamt' FROM csddt INNER JOIN csd ON csddt.cknum = csd.cknum AND csddt.baid = csd.baid INNER JOIN currates ON csddt.currency=currates.curcode AND csddt.ckdate BETWEEN cddate1 AND cddate2 AND currates.trtype='A' WHERE YEAR(csddt.ckdate)='2014' AND csddt.ap1099 <> 'N' GROUP BY csddt.apnum,csddt.apaddid,csddt.ap1099 ) SELECT apaddr.apnum ,apaddr.apaddid ,CASE WHEN apaddr.apfed IS NULL THEN 'zNoTIN'+ap.apnum ELSE apaddr.apfed END AS 'TIN' ,ap.apname AS 'Vendor Name' ,apaddr.appynm AS 'Payee' ,apaddr.appya1 AS 'Address 1' ,apaddr.appya2 AS 'Address 2' ,apaddr.appyct AS 'City' ,apaddr.appyst AS 'State' ,apaddr.appyzp AS 'Zip Code' ,ap.apct1 AS 'Vendor Type' ,ap.ap1099 AS 'Vendor 1099' ,apaddr.ap1099 AS 'Addr 1099' ,CASE WHEN apamt.ap1099 IS NULL THEN tr1099flag ELSE apamt.ap1099 END AS 'Tran 1099' ,ISNULL(apamt,0)+ISNULL(tramt,0) AS 'amt' FROM apaddr INNER JOIN ap ON apaddr.apnum=ap.apnum LEFT OUTER JOIN apamt ON apaddr.apnum=apamt.apnum AND apaddr.apaddid=apamt.apaddid LEFT OUTER JOIN trust ON apaddr.apnum=trvendor AND apaddr.apaddid=trvendoraddr WHERE (ISNULL(apamt,0)+ISNULL(tramt,0))<>0 ORDER BY CASE WHEN apaddr.apfed IS NULL THEN 'zNoTIN'+ap.apnum ELSE apaddr.apfed END ,apaddr.apnum ,apaddr.apaddid
Part 2
WITH trust AS ( SELECT trvendor ,trvendoraddr ,tr1099flag ,SUM(-tramount/cdrate) AS 'tramt' FROM trcheck INNER JOIN trsttran ON trcheck.trindex=trsttran.trindex INNER JOIN tracct ON trsttran.tracct=tracct.tracct INNER JOIN matter ON trmatter=mmatter INNER JOIN currates ON trcurcd=curcode AND trdate bETWEEN cddate1 AND cddate2 AND currates.trtype='A' WHERE YEAR(trdate)='2014' --AND tr1099flag IS NOT NULL --AND tr1099flag <> 'N' AND trsttran.trflag IS NULL GROUP BY trvendor,trvendoraddr,tr1099flag ), apamt AS ( SELECT csddt.apnum ,csddt.apaddid ,csddt.ap1099 ,SUM(csddt.amt/currates.cdrate) AS 'apamt' FROM csddt INNER JOIN csd ON csddt.cknum = csd.cknum AND csddt.baid = csd.baid INNER JOIN currates ON csddt.currency=currates.curcode AND csddt.ckdate BETWEEN cddate1 AND cddate2 AND currates.trtype='A' WHERE YEAR(csddt.ckdate)='2014' AND csddt.trtype<>'CA' --AND csddt.ap1099 <> 'N' GROUP BY csddt.apnum,csddt.apaddid,csddt.ap1099 ) SELECT apaddr.apnum ,apaddr.apaddid ,CASE WHEN apaddr.apfed IS NULL THEN 'zNoTIN'+ap.apnum ELSE apaddr.apfed END AS 'TIN' ,ap.apname AS 'Vendor Name' ,apaddr.appynm AS 'Payee' ,apaddr.appya1 AS 'Address 1' ,apaddr.appya2 AS 'Address 2' ,apaddr.appyct AS 'City' ,apaddr.appyst AS 'State' ,apaddr.appyzp AS 'Zip Code' ,ap.apopendt AS 'Open Date' ,ap.apct1 AS 'Vendor Type' ,ap.ap1099 AS 'Vendor 1099' ,apaddr.ap1099 AS 'Addr 1099' ,CASE WHEN apamt.ap1099 IS NULL THEN tr1099flag ELSE apamt.ap1099 END AS 'Tran 1099' ,ISNULL(apamt,0)+ISNULL(tramt,0) AS 'amt' FROM apaddr INNER JOIN ap ON apaddr.apnum=ap.apnum LEFT OUTER JOIN apamt ON apaddr.apnum=apamt.apnum AND apaddr.apaddid=apamt.apaddid LEFT OUTER JOIN trust ON apaddr.apnum=trvendor AND apaddr.apaddid=trvendoraddr WHERE (ISNULL(apamt,0)+ISNULL(tramt,0))<>0 AND YEAR(ap.apopendt)='2014' ORDER BY CASE WHEN apaddr.apfed IS NULL THEN 'zNoTIN'+ap.apnum ELSE apaddr.apfed END ,apaddr.apnum ,apaddr.apaddid
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.
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)
Tuesday, September 16, 2014
Billing Volumes by Biller
The following query summarizes the quantity and value of non-reversed of invoices billed by user (biller). This particular query assumes billers are set up as timekeepers. If they are not, replace the tklast + tkfirst with ufullname from the usmaster table (joined to the uaccess table). We also use a UDF to define whether a matter is eBilled (udf index 73 shown below), and results are divided between eBilled and non-eBilled. Also, we define hourly and contigent matters as the presence or absence of a value in the Projected Fees field in master matter (mffee field in the matter table). Results are also split based on this field.
SELECT tklast+', '+tkfirst AS 'User' ,COUNT(DISTINCT CASE WHEN (udvalue<>'Y' OR udvalue IS NULL) AND mffee IS NULL THEN linvoice ELSE NULL END) AS 'Hourly Non-eBill #' ,SUM(CASE WHEN (udvalue<>'Y' OR udvalue IS NULL) AND mffee IS NULL THEN lamount/cdrate ELSE 0 END) AS 'Hourly Non-eBill $' ,COUNT(DISTINCT CASE WHEN udvalue='Y' AND mffee IS NULL THEN linvoice ELSE NULL END) AS 'Hourly eBill #' ,SUM(CASE WHEN udvalue='Y' AND mffee IS NULL THEN lamount/cdrate ELSE 0 END) AS 'Hourly eBill $' ,COUNT(DISTINCT CASE WHEN mffee IS NULL THEN linvoice ELSE NULL END) AS 'Hourly Total #' ,SUM(CASE WHEN mffee IS NULL THEN lamount/cdrate ELSE 0 END) AS 'Hourly Total $' ,COUNT(DISTINCT CASE WHEN (udvalue<>'Y' OR udvalue IS NULL) AND mffee IS NOT NULL THEN linvoice ELSE NULL END) AS 'Cont Non-eBill #' ,SUM(CASE WHEN (udvalue<>'Y' OR udvalue IS NULL) AND mffee IS NOT NULL THEN lamount/cdrate ELSE 0 END) AS 'Cont Non-eBill $' ,COUNT(DISTINCT CASE WHEN udvalue='Y' AND mffee IS NOT NULL THEN linvoice ELSE NULL END) AS 'Cont eBill #' ,SUM(CASE WHEN udvalue='Y' AND mffee IS NOT NULL THEN lamount/cdrate ELSE 0 END) AS 'Cont eBill $' ,COUNT(DISTINCT CASE WHEN mffee IS NOT NULL THEN linvoice ELSE NULL END) AS 'Cont Total #' ,SUM(CASE WHEN mffee IS NOT NULL THEN lamount/cdrate ELSE 0 END) AS 'Cont Total $' ,COUNT(DISTINCT linvoice) AS 'Total #' ,SUM(lamount/cdrate) AS 'Total $' FROM ledger INNER JOIN ledcode ON llcode=lccode INNER JOIN batch ON bbatch=lbatch INNER JOIN uaccess ON bop=uname INNER JOIN timekeep ON wvtkinit=tkinit INNER JOIN periodt ON lperiod=pe INNER JOIN matter ON mmatter=lmatter INNER JOIN location ON mloc=locode INNER JOIN client ON mclient=client.clnum INNER JOIN client cr ON client.crelated=cr.clnum INNER JOIN currates ON mcurrency=curcode AND trtype='A' AND pebedt BETWEEN cddate1 AND cddate2 LEFT OUTER JOIN udf ON lmatter=udjoin AND udfindex=73 WHERE pebedt BETWEEN '1/1/2013' AND '12/31/2013' AND lcfco IS NOT NULL AND lzero <> 'R' GROUP BY tklast,tkfirst ORDER BY COUNT(DISTINCT linvoice) DESCI've also included a slightly different query below, which measures total invoice output by biller for the current month.
SELECT tklast+', '+tkfirst AS 'Biller' ,peendt ,COUNT(DISTINCT linvoice) AS 'NumInvs' ,SUM(CASE WHEN lcfco='F' THEN lamount/cdrate ELSE 0 END) AS 'Fees' ,SUM(CASE WHEN lcfco='C' THEN lamount/cdrate ELSE 0 END) AS 'Costs' ,SUM(CASE WHEN lcfco NOT IN ('F','C') THEN lamount/cdrate ELSE 0 END) AS 'Other' ,SUM(lamount/cdrate) AS 'Total' ,SUM(lamount/cdrate)/COUNT(DISTINCT linvoice) AS 'AvgInv' FROM ledger INNER JOIN batch ON lbatch=bbatch INNER JOIN ledcode ON llcode=lccode INNER JOIN uaccess ON bop=uname INNER JOIN timekeep ON wvtkinit=tkinit INNER JOIN periodt ON lperiod=pe INNER JOIN matter ON lmatter=mmatter INNER JOIN currates ON mcurrency=curcode AND currates.trtype='A' AND periodt.pebedt BETWEEN currates.cddate1 AND currates.cddate2 WHERE lcfco IS NOT NULL AND peendt = DATEADD(MONTH,DATEDIFF(MONTH,0,GETDATE())+1,0)-1 GROUP BY tklast,tkfirst,peendt
Monday, September 15, 2014
Accounts Payable Annual Activity and Balance
Here's a quick and dirty little query that you can run at the beginning of the year to see a summary of the prior year's accounts payable activity and current balances by vendor. Transactions are converted to firm currency using the average method for the month of the transaction, and balance is converted to firm currency using the daily rate as of the end of the year. Note that the balance table is outer joined, so not all balances will be returned, just ones with prior payment activity. If you want both, you would need to do some fancy footwork with a full outer join and some coalescing, which is beyond the scope of this post =).
SELECT ap.apnum ,ap.apname ,SUM(CASE WHEN (apyr=2013) THEN apntpr/trancur.cdrate ELSE 0 END) AS '2013' ,SUM(CASE WHEN (apyr=2012) THEN apntpr/trancur.cdrate ELSE 0 END) AS '2012' ,ISNULL(apbal.apbal/balcur.cdrate,0) AS 'Balance' ,apamt.currency AS 'Currency' FROM ap INNER JOIN apamt ON ap.apnum=apamt.apnum INNER JOIN currates trancur ON DATEADD(mm,apper-1,DATEADD(yy,apyr-1900,0)) BETWEEN trancur.cddate1 AND trancur.cddate2 AND trancur.trtype='A' AND trancur.curcode=apamt.currency LEFT OUTER JOIN apbal ON ap.apnum=apbal.apnum AND apbal.currency=apamt.currency LEFT OUTER JOIN currates balcur ON '12/31/2013' BETWEEN balcur.cddate1 AND balcur.cddate2 AND balcur.trtype='D' AND balcur.curcode=apbal.currency GROUP BY ap.apnum,ap.apname,apbal.apbal,apamt.currency,balcur.cdrate ORDER BY SUM(CASE WHEN (apyr=2013) THEN apntpr ELSE 0 END) DESC
Subscribe to:
Posts (Atom)