issue #23241: add triggers, indexes, and api views and functions
authorSteve Hackbarth <stephenhackbarth@gmail.com>
Wed, 9 Apr 2014 02:12:14 +0000 (22:12 -0400)
committerSteve Hackbarth <stephenhackbarth@gmail.com>
Wed, 9 Apr 2014 02:12:14 +0000 (22:12 -0400)
208 files changed:
foundation-database/api/functions/getcustnumberfrominfo.sql [new file with mode: 0644]
foundation-database/api/functions/insertsalesline.sql [new file with mode: 0644]
foundation-database/api/views/account.sql [new file with mode: 0644]
foundation-database/api/views/accountchar.sql [new file with mode: 0644]
foundation-database/api/views/accountcomment.sql [new file with mode: 0644]
foundation-database/api/views/accountfile.sql [new file with mode: 0644]
foundation-database/api/views/accountimage.sql [new file with mode: 0644]
foundation-database/api/views/address.sql [new file with mode: 0644]
foundation-database/api/views/addresschar.sql [new file with mode: 0644]
foundation-database/api/views/addresscomment.sql [new file with mode: 0644]
foundation-database/api/views/apmemo.sql [new file with mode: 0644]
foundation-database/api/views/armemo.sql [new file with mode: 0644]
foundation-database/api/views/bom.sql [new file with mode: 0644]
foundation-database/api/views/bomitem.sql [new file with mode: 0644]
foundation-database/api/views/bomitemcomment.sql [new file with mode: 0644]
foundation-database/api/views/bomitemsubstitute.sql [new file with mode: 0644]
foundation-database/api/views/budget.sql [new file with mode: 0755]
foundation-database/api/views/budgetentry.sql [new file with mode: 0755]
foundation-database/api/views/cashreceipt.sql [new file with mode: 0644]
foundation-database/api/views/cashreceiptapply.sql [new file with mode: 0644]
foundation-database/api/views/cashreceiptapplymisc.sql [new file with mode: 0644]
foundation-database/api/views/contact.sql [new file with mode: 0644]
foundation-database/api/views/contactchar.sql [new file with mode: 0644]
foundation-database/api/views/contactcomment.sql [new file with mode: 0644]
foundation-database/api/views/creditmemo.sql [new file with mode: 0644]
foundation-database/api/views/creditmemoline.sql [new file with mode: 0644]
foundation-database/api/views/custchar.sql [new file with mode: 0644]
foundation-database/api/views/custcomment.sql [new file with mode: 0644]
foundation-database/api/views/custcreditcard.sql [new file with mode: 0644]
foundation-database/api/views/customer.sql [new file with mode: 0644]
foundation-database/api/views/customertaxreg.sql [new file with mode: 0644]
foundation-database/api/views/customertype.sql [new file with mode: 0644]
foundation-database/api/views/customertypechar.sql [new file with mode: 0644]
foundation-database/api/views/custshipto.sql [new file with mode: 0644]
foundation-database/api/views/custtax.sql [new file with mode: 0644]
foundation-database/api/views/employee.sql [new file with mode: 0644]
foundation-database/api/views/employeechar.sql [new file with mode: 0644]
foundation-database/api/views/employeecomment.sql [new file with mode: 0644]
foundation-database/api/views/extshipmaint.sql [new file with mode: 0644]
foundation-database/api/views/freightpricingscheduleitem.sql [new file with mode: 0644]
foundation-database/api/views/glaccount.sql [new file with mode: 0644]
foundation-database/api/views/incident.sql [new file with mode: 0644]
foundation-database/api/views/incidentchar.sql [new file with mode: 0644]
foundation-database/api/views/incidentcomment.sql [new file with mode: 0644]
foundation-database/api/views/incidentfile.sql [new file with mode: 0644]
foundation-database/api/views/incidentimage.sql [new file with mode: 0644]
foundation-database/api/views/invoice.sql [new file with mode: 0644]
foundation-database/api/views/invoiceline.sql [new file with mode: 0644]
foundation-database/api/views/item.sql [new file with mode: 0644]
foundation-database/api/views/itemalias.sql [new file with mode: 0644]
foundation-database/api/views/itemchar.sql [new file with mode: 0644]
foundation-database/api/views/itemcomment.sql [new file with mode: 0644]
foundation-database/api/views/itemcost.sql [new file with mode: 0644]
foundation-database/api/views/itemfile.sql [new file with mode: 0644]
foundation-database/api/views/itemimage.sql [new file with mode: 0644]
foundation-database/api/views/itemsite.sql [new file with mode: 0644]
foundation-database/api/views/itemsitecomment.sql [new file with mode: 0644]
foundation-database/api/views/itemsource.sql [new file with mode: 0644]
foundation-database/api/views/itemsourceprice.sql [new file with mode: 0644]
foundation-database/api/views/itemsubstitute.sql [new file with mode: 0644]
foundation-database/api/views/itemtaxtype.sql [new file with mode: 0644]
foundation-database/api/views/itemuomconversion.sql [new file with mode: 0644]
foundation-database/api/views/journalentry.sql [new file with mode: 0644]
foundation-database/api/views/location.sql [new file with mode: 0644]
foundation-database/api/views/misccounttag.sql [new file with mode: 0644]
foundation-database/api/views/physinvcount.sql [new file with mode: 0644]
foundation-database/api/views/pricingschedule.sql [new file with mode: 0644]
foundation-database/api/views/pricingscheduleassign.sql [new file with mode: 0644]
foundation-database/api/views/pricingscheduleitem.sql [new file with mode: 0644]
foundation-database/api/views/pricingscheduleitemchar.sql [new file with mode: 0644]
foundation-database/api/views/project.sql [new file with mode: 0644]
foundation-database/api/views/projectcomment.sql [new file with mode: 0644]
foundation-database/api/views/prospect.sql [new file with mode: 0644]
foundation-database/api/views/purchaseline.sql [new file with mode: 0644]
foundation-database/api/views/purchaselinechar.sql [new file with mode: 0644]
foundation-database/api/views/purchaselinecomment.sql [new file with mode: 0644]
foundation-database/api/views/purchaseorder.sql [new file with mode: 0644]
foundation-database/api/views/purchaseordercomment.sql [new file with mode: 0644]
foundation-database/api/views/quote.sql [new file with mode: 0644]
foundation-database/api/views/quotecomment.sql [new file with mode: 0644]
foundation-database/api/views/quoteline.sql [new file with mode: 0644]
foundation-database/api/views/quotelinechar.sql [new file with mode: 0644]
foundation-database/api/views/quotelinecomment.sql [new file with mode: 0644]
foundation-database/api/views/salescredit.sql [new file with mode: 0644]
foundation-database/api/views/saleshistory.sql [new file with mode: 0644]
foundation-database/api/views/salesline.sql [new file with mode: 0644]
foundation-database/api/views/saleslinechar.sql [new file with mode: 0644]
foundation-database/api/views/saleslinecomment.sql [new file with mode: 0644]
foundation-database/api/views/salesorder.sql [new file with mode: 0644]
foundation-database/api/views/salesordercomment.sql [new file with mode: 0644]
foundation-database/api/views/salesrep.sql [new file with mode: 0644]
foundation-database/api/views/site.sql [new file with mode: 0644]
foundation-database/api/views/sitezone.sql [new file with mode: 0644]
foundation-database/api/views/task.sql [new file with mode: 0644]
foundation-database/api/views/taskcomment.sql [new file with mode: 0644]
foundation-database/api/views/todo.sql [new file with mode: 0644]
foundation-database/api/views/vendor.sql [new file with mode: 0644]
foundation-database/api/views/vendoraddress.sql [new file with mode: 0644]
foundation-database/api/views/vendortype.sql [new file with mode: 0644]
foundation-database/manifest.js
foundation-database/public/indexes/evntlog.sql [new file with mode: 0644]
foundation-database/public/indexes/invcitemtax.sql [new file with mode: 0644]
foundation-database/public/indexes/shipitem.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/accnt.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/addr.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/alarm.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/apapply.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/apopen.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/arapply.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/aropen.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/bomhead.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/bomitem.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/bomitemsub.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/cashrcpt.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/cashrcptitem.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/cashrcptmisc.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/ccard.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/char.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/charass.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/charopt.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/checkhead.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/cmhead.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/cmitem.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/cntct.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/cntslip.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/cobill.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/cobmisc.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/cohead.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/coitem.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/comment.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/company.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/contrct.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/crmacct.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/curr_rate.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/curr_symbol.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/cust.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/custtype.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/docass.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/emp.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/evntlog.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/gltrans.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/grppriv.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/imageass.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/incdt.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/invchead.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/invcitem.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/invhist.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/ipsass.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/ipshead.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/ipsitemchar.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/ipsiteminfo.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/item.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/itemcost.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/itemsite.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/itemsrc.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/itemsrcp.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/itemsub.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/itemtax.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/itemuomconv.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/location.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/metasql.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/ophead.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/pack.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/period.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/pkgcmd.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/pkgcmdarg.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/pkghead.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/pkgimage.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/pkgitem.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/pkgmetasql.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/pkgpriv.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/pkgreport.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/pkgscript.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/pkguiform.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/pohead.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/poitem.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/pr.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/prj.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/prjtask.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/prospect.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/quhead.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/quitem.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/recur.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/report.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/salesrep.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/saletype.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/shipdata.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/shipdatasum.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/shipform.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/shiphead.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/shiptoinfo.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/shipvia.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/sltrans.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/taxauth.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/terms.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/todoitem.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/uomconv.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/usrpref.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/usrpriv.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/vend.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/vendaddr.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/vodist.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/vohead.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/voitem.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/whsezone.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/whsinfo.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/wo.sql [new file with mode: 0644]
foundation-database/public/trigger_functions/womatl.sql [new file with mode: 0644]

diff --git a/foundation-database/api/functions/getcustnumberfrominfo.sql b/foundation-database/api/functions/getcustnumberfrominfo.sql
new file mode 100644 (file)
index 0000000..f5c34e9
--- /dev/null
@@ -0,0 +1,128 @@
+CREATE OR REPLACE FUNCTION api.getCustNumberFromInfo(TEXT, TEXT, TEXT, TEXT, TEXT, BOOLEAN) RETURNS TEXT AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _email       TEXT    := COALESCE(UPPER($1), '');
+  _company     TEXT    := COALESCE(UPPER($2), '');
+  _first       TEXT    := COALESCE(UPPER($3), '');
+  _last                TEXT    := COALESCE(UPPER($4), '');
+  _fullname    TEXT    := COALESCE(UPPER($5), TRIM(_first || ' ' || _last));
+  _generate    BOOLEAN := COALESCE($6, FALSE);
+  _counter     INTEGER;
+  _custcount   INTEGER := 0;
+  _custnumber  TEXT;
+  _candidate   TEXT    := '';
+  _loopmax     INTEGER := 0;
+  _minlength   INTEGER := 5;
+  _maxlength   INTEGER := 8;
+  _numformat   TEXT    := '';
+  _testme      TEXT;
+BEGIN
+  IF (_email != '') THEN
+    SELECT count(*), cust_number INTO _custcount, _custnumber
+    FROM custinfo LEFT OUTER JOIN cntct ON (cust_cntct_id=cntct_id)
+    WHERE (UPPER(cntct_email)=_email)
+    GROUP BY cust_number;
+    IF (NOT FOUND) THEN
+      _custcount := 0;
+    ELSIF(_custcount = 1) THEN
+      RETURN _custnumber;
+    END IF;
+  END IF;
+
+  IF (_company != '') THEN
+    SELECT count(*), cust_number INTO _custcount, _custnumber
+    FROM custinfo
+    WHERE (UPPER(cust_name)=_company)
+    GROUP BY cust_number;
+    IF (NOT FOUND) THEN
+      _custcount := 0;
+    ELSIF(_custcount = 1) THEN
+      RETURN _custnumber;
+    END IF;
+  END IF;
+
+  IF (_fullname = '' AND (_first != '' OR _last != '')) THEN
+    _fullname := TRIM(_first || ' ' || _last);
+  END IF;
+
+  IF (_custcount <= 0 AND _fullname != '') THEN
+    SELECT count(*), cust_number INTO _custcount, _custnumber
+    FROM custinfo
+    WHERE (UPPER(cust_name)=_fullname)
+    GROUP BY cust_number;
+    IF (NOT FOUND) THEN
+      _custcount := 0;
+    ELSIF(_custcount = 1) THEN
+      RETURN _custnumber;
+    END IF;
+  END IF;
+
+  IF (_custcount > 1) THEN
+    RAISE EXCEPTION 'Found % possible Customers for % and % and %',
+                   _custcount, _email, _company, _fullname;
+  END IF;
+
+  IF (_custcount <= 0 AND _generate) THEN
+    IF (_maxlength < _minlength) THEN
+      RAISE EXCEPTION 'Fix getCustNumberFromInfo: max length < min length';
+    END IF;
+
+    IF (_company != '') THEN
+      _candidate := _company;
+    ELSIF (_email != '') THEN
+      _candidate := SUBSTRING(_email FOR POSITION('@' IN _email) - 1);
+    ELSIF (_last != '') THEN
+      _candidate := _last;
+      IF (_first != '') THEN
+       _candidate := _candidate || _first;
+      END IF;
+    ELSIF (_fullname != '' AND (POSITION(' ' IN _fullname) > 0)) THEN
+      _candidate := SUBSTRING(_fullname FROM POSITION(' ' IN _fullname) + 1) ||
+                   SUBSTRING(_fullname FOR  POSITION(' ' IN _fullname) - 1);
+    END IF;
+    WHILE (POSITION(' ' IN _candidate) > 0) LOOP
+      _candidate := SUBSTRING(_candidate FOR  POSITION(' ' IN _candidate) - 1) ||
+                   SUBSTRING(_candidate FROM POSITION(' ' IN _candidate) + 1);
+    END LOOP;
+    FOR _counter IN _minlength.._maxlength LOOP
+      _testme := SUBSTRING(_candidate FOR _counter);
+      IF (NOT EXISTS(SELECT cust_number
+                    FROM custinfo
+                    WHERE (cust_number=_testme))) THEN
+       _custnumber := _testme;
+       EXIT;
+      END IF;
+    END LOOP;
+    IF (_custnumber IS NULL OR _custnumber = '') THEN
+      IF (LENGTH(_candidate) < _minlength) THEN
+       _minlength := LENGTH(_candidate);
+      END IF;
+      FOR _counter IN _minlength.._maxlength LOOP
+       _loopmax := _loopmax * 10 + 9;
+       _numformat := _numformat || '0';
+      END LOOP;
+      FOR _counter IN 1.._loopmax LOOP
+       _testme := SUBSTRING(_candidate FOR _minlength) ||
+                  TRIM(TO_CHAR(_counter, _numformat));
+       IF (NOT EXISTS(SELECT cust_number
+                      FROM custinfo
+                      WHERE (cust_number=_testme))) THEN
+         _custnumber := _testme;
+         EXIT;
+       END IF;
+      END LOOP;
+    END IF;
+    IF (_custnumber IS NULL OR _custnumber = '') THEN
+      RAISE EXCEPTION 'Could not generate a new Customer Number';
+    END IF;
+  END IF;
+
+  IF (_custnumber IS NULL OR _custnumber = '') THEN
+    RAISE EXCEPTION 'Could not find Customer Number for % and % and %',
+                   _email, _company, _fullname;
+  END IF;
+
+  RETURN _custnumber;
+END;
+$$ LANGUAGE 'plpgsql';
diff --git a/foundation-database/api/functions/insertsalesline.sql b/foundation-database/api/functions/insertsalesline.sql
new file mode 100644 (file)
index 0000000..5ac4fa7
--- /dev/null
@@ -0,0 +1,109 @@
+CREATE OR REPLACE FUNCTION api.insertSalesLine(api.salesline) RETURNS boolean AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  pNEW ALIAS FOR $1;
+  _r RECORD;
+
+BEGIN
+
+  IF (NOT EXISTS (SELECT cohead_id FROM cohead WHERE cohead_number=pNEW.order_number)) THEN
+    RAISE EXCEPTION 'Function insertSalesLine failed because Sales Order % not found', pNEW.order_number;
+  END IF;
+
+  IF (NOT EXISTS (SELECT item_id FROM item WHERE item_number=pNEW.item_number)) THEN
+    RAISE EXCEPTION 'Function insertSalesLine failed because Item Number % not found', pNEW.item_number;
+  END IF;
+
+  SELECT * INTO _r
+  FROM cohead, itemsite, item, whsinfo
+  WHERE ((cohead_number=pNEW.order_number)
+  AND (itemsite_warehous_id=warehous_id
+  AND (itemsite_item_id=item_id)
+  AND (itemsite_active)
+  AND (item_number=pNEW.item_number)
+  AND (warehous_active)
+  AND (warehous_id=COALESCE(getWarehousId(pNEW.sold_from_site,'ALL'),cohead_warehous_id,fetchprefwarehousid()))));
+
+  IF (NOT FOUND) THEN
+    RAISE EXCEPTION 'Function insertSalesLine failed with unknown failure to retrieve Sales Order';
+  END IF;
+
+  INSERT INTO coitem (
+    coitem_cohead_id,
+    coitem_linenumber,
+    coitem_itemsite_id,
+    coitem_status,
+    coitem_scheddate,
+    coitem_promdate,
+    coitem_qtyord,
+    coitem_qty_uom_id,
+    coitem_qty_invuomratio,
+    coitem_qtyshipped,
+    coitem_unitcost,
+    coitem_price,
+    coitem_price_uom_id,
+    coitem_price_invuomratio,
+    coitem_custprice,
+    coitem_order_id,
+    coitem_memo,
+    coitem_imported,
+    coitem_qtyreturned,
+    coitem_custpn,
+    coitem_order_type,
+    coitem_substitute_item_id,
+    coitem_prcost,
+    coitem_taxtype_id,
+    coitem_warranty,
+    coitem_cos_accnt_id,
+    coitem_rev_accnt_id)
+  VALUES (
+    _r.cohead_id,
+    pNEW.line_number::INTEGER,
+    _r.itemsite_id,
+    pNEW.status,
+    pNEW.scheduled_date,
+    pNEW.promise_date,
+    pNEW.qty_ordered,
+    COALESCE(getUomId(pNEW.qty_uom),_r.item_inv_uom_id),
+    itemuomtouomratio(_r.item_id,COALESCE(getUomId(pNEW.qty_uom),_r.item_inv_uom_id),_r.item_inv_uom_id),
+    0,
+    stdCost(_r.item_id),
+    COALESCE(pNEW.net_unit_price,itemPrice(_r.item_id,_r.cohead_cust_id,
+             _r.cohead_shipto_id,pNEW.qty_ordered,_r.cohead_curr_id,_r.cohead_orderdate)),
+    COALESCE(getUomId(pNEW.price_uom),_r.item_price_uom_id),
+    itemuomtouomratio(_r.item_id,COALESCE(getUomId(pNEW.price_uom),_r.item_price_uom_id),_r.item_price_uom_id),
+    itemPrice(_r.item_id, _r.cohead_cust_id, _r.cohead_shipto_id,
+              pNEW.qty_ordered, _r.item_inv_uom_id, _r.item_price_uom_id,
+              _r.cohead_curr_id,_r.cohead_orderdate,
+              CASE WHEN (fetchMetricText('soPriceEffective') = 'ScheduleDate') THEN pNEW.scheduled_date
+                   WHEN (fetchMetricText('soPriceEffective') = 'OrderDate') THEN _r.cohead_orderdate
+                   ELSE CURRENT_DATE END,
+              NULL)
+    -1,
+    pNEW.notes,
+    true,
+    0,
+    pNEW.customer_pn,
+    CASE
+      WHEN ((pNEW.create_order  AND (_r.item_type = 'M')) OR 
+           ((pNEW.create_order IS NULL) AND _r.itemsite_createwo)) THEN
+        'W'
+      WHEN ((pNEW.create_order AND (_r.item_type = 'P')) OR 
+           ((pNEW.create_order IS NULL) AND _r.itemsite_createsopr)) THEN
+        'R'
+      WHEN ((pNEW.create_order AND (_r.item_type = 'P') AND (_r.itemsite_createsopo)) OR 
+           ((pNEW.create_order IS NULL) AND _r.itemsite_createsopo)) THEN
+        'P'
+    END,
+    getitemid(pNEW.substitute_for),
+    pNEW.overwrite_po_price,
+    COALESCE(getTaxTypeId(pNEW.tax_type), getItemTaxType(_r.itemsite_item_id, _r.cohead_taxzone_id)),
+    pNEW.warranty,
+    getGlAccntId(pNEW.alternate_cos_account),
+    getGlAccntId(pNEW.alternate_rev_account)
+    );
+
+  RETURN TRUE;
+END;
+$$ LANGUAGE 'plpgsql';
diff --git a/foundation-database/api/views/account.sql b/foundation-database/api/views/account.sql
new file mode 100644 (file)
index 0000000..8fd3169
--- /dev/null
@@ -0,0 +1,166 @@
+
+  --Account View
+
+SELECT dropIfExists('VIEW', 'account', 'api');
+  CREATE OR REPLACE VIEW api.account AS
+  SELECT 
+    c.crmacct_number::varchar AS account_number,
+    p.crmacct_number AS parent_account,
+    c.crmacct_name AS account_name,
+    c.crmacct_active AS active,
+    CASE WHEN (c.crmacct_type='O') THEN
+      'Organization'
+    ELSE 'Individual'
+    END AS type,
+    pc.cntct_number AS primary_contact_number,
+    pc.cntct_honorific AS primary_contact_honorific,
+    pc.cntct_first_name AS primary_contact_first,
+    pc.cntct_middle AS primary_contact_middle,
+    pc.cntct_last_name AS primary_contact_last,
+    pc.cntct_suffix AS primary_contact_suffix,
+    pc.cntct_title AS primary_contact_job_title,
+    pc.cntct_phone AS primary_contact_voice,
+    pc.cntct_fax AS primary_contact_fax,
+    pc.cntct_email AS primary_contact_email,
+    (''::TEXT) AS primary_contact_change,
+    m.addr_number AS primary_contact_address_number,
+    m.addr_line1 AS primary_contact_address1,
+    m.addr_line2 AS primary_contact_address2,
+    m.addr_line3 AS primary_contact_address3,
+    m.addr_city AS primary_contact_city,
+    m.addr_state AS primary_contact_state,
+    m.addr_postalcode AS primary_contact_postalcode,
+    m.addr_country AS primary_contact_country,
+    (''::TEXT) AS primary_contact_address_change,
+    sc.cntct_number AS secondary_contact_number,
+    sc.cntct_honorific AS secondary_contact_honorific,
+    sc.cntct_first_name AS secondary_contact_first,
+    sc.cntct_middle AS secondary_contact_middle,
+    sc.cntct_last_name AS secondary_contact_last,
+    sc.cntct_suffix AS secondary_contact_suffix,
+    sc.cntct_title AS secondary_contact_job_title,
+    sc.cntct_phone AS secondary_contact_voice,
+    sc.cntct_fax AS secondary_contact_fax,
+    sc.cntct_email AS secondary_contact_email,
+    sc.cntct_webaddr AS secondary_contact_web,
+    (''::TEXT) AS secondary_contact_change,
+    s.addr_number AS secondary_contact_address_number,
+    s.addr_line1 AS secondary_contact_address1,
+    s.addr_line2 AS secondary_contact_address2,
+    s.addr_line3 AS secondary_contact_address3,
+    s.addr_city AS secondary_contact_city,
+    s.addr_state AS secondary_contact_state,
+    s.addr_postalcode AS secondary_contact_postalcode,
+    s.addr_country AS secondary_contact_country,
+    (''::TEXT) AS secondary_contact_address_change,
+    c.crmacct_notes AS notes
+  FROM
+    crmacct c
+      LEFT OUTER JOIN crmacct p ON (c.crmacct_parent_id=p.crmacct_id)
+      LEFT OUTER JOIN cntct pc ON (c.crmacct_cntct_id_1=pc.cntct_id)
+      LEFT OUTER JOIN addr m ON (pc.cntct_addr_id=m.addr_id)
+      LEFT OUTER JOIN cntct sc ON (c.crmacct_cntct_id_2=sc.cntct_id)
+      LEFT OUTER JOIN addr s ON (sc.cntct_addr_id=s.addr_id);
+
+GRANT ALL ON TABLE api.account TO xtrole;
+COMMENT ON VIEW api.account IS 'Account';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.account DO INSTEAD
+
+INSERT INTO crmacct
+       (crmacct_number,
+         crmacct_parent_id,
+         crmacct_name,
+         crmacct_active,
+         crmacct_type,
+         crmacct_cntct_id_1,
+         crmacct_cntct_id_2,
+         crmacct_notes )
+        VALUES
+        (COALESCE(NEW.account_number,CAST(fetchCRMAccountNumber() AS text)),
+         getCrmAcctId(NEW.parent_account),
+         NEW.account_name,
+         COALESCE(NEW.active,TRUE),
+         CASE WHEN (NEW.type = 'Individual') THEN
+           'I'
+         ELSE 'O' END,
+         saveCntct(
+          getCntctId(NEW.primary_contact_number),
+          NEW.primary_contact_number,
+          saveAddr(
+            getAddrId(NEW.primary_contact_address_number),
+            NEW.primary_contact_address_number,
+            NEW.primary_contact_address1,
+            NEW.primary_contact_address2,
+            NEW.primary_contact_address3,
+            NEW.primary_contact_city,
+            NEW.primary_contact_state,
+            NEW.primary_contact_postalcode,
+            NEW.primary_contact_country,
+            NEW.primary_contact_address_change),
+          NEW.primary_contact_honorific,
+          NEW.primary_contact_first,
+          NEW.primary_contact_middle,
+          NEW.primary_contact_last,
+          NEW.primary_contact_suffix,
+          NEW.primary_contact_voice,
+          NULL,
+          NEW.primary_contact_fax,
+          NEW.primary_contact_email,
+          NULL,
+          NEW.primary_contact_job_title,
+          NEW.primary_contact_change
+          ),
+          saveCntct(
+          getCntctId(NEW.secondary_contact_number),
+          NEW.secondary_contact_number,
+            saveAddr(
+            getAddrId(NEW.secondary_contact_address_number),
+            NEW.secondary_contact_address_number,
+            NEW.secondary_contact_address1,
+            NEW.secondary_contact_address2,
+            NEW.secondary_contact_address3,
+            NEW.secondary_contact_city,
+            NEW.secondary_contact_state,
+            NEW.secondary_contact_postalcode,
+            NEW.secondary_contact_country,
+            NEW.secondary_contact_address_change),
+          NEW.secondary_contact_honorific,
+          NEW.secondary_contact_first,
+          NEW.secondary_contact_middle,
+          NEW.secondary_contact_last,
+          NEW.secondary_contact_suffix,
+          NEW.secondary_contact_voice,
+          NULL,
+          NEW.secondary_contact_fax,
+          NEW.secondary_contact_email,
+          NULL,
+          NEW.secondary_contact_job_title,
+          NEW.secondary_contact_change),
+          NEW.notes);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.account DO INSTEAD
+
+UPDATE crmacct SET
+    crmacct_number=NEW.account_number,
+    crmacct_parent_id=getCrmAcctId(NEW.parent_account),
+    crmacct_name=NEW.account_name,
+    crmacct_active=NEW.active,
+    crmacct_type=(
+    CASE WHEN (NEW.type = 'Individual') THEN
+           'I'
+    ELSE 'O' END),
+    crmacct_cntct_id_1=getCntctId(NEW.primary_contact_number),
+    crmacct_cntct_id_2=getCntctId(NEW.secondary_contact_number),
+    crmacct_notes=NEW.notes
+  WHERE (crmacct_number=OLD.account_number);
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.account DO INSTEAD
+  DELETE FROM crmacct WHERE crmacct_number = OLD.account_number;
+
diff --git a/foundation-database/api/views/accountchar.sql b/foundation-database/api/views/accountchar.sql
new file mode 100644 (file)
index 0000000..fbc825e
--- /dev/null
@@ -0,0 +1,52 @@
+-- Account Characteristic
+
+SELECT dropIfExists('VIEW', 'accountchar', 'api');
+CREATE VIEW api.accountchar
+AS 
+   SELECT 
+     crmacct_number::varchar AS account_number,
+     char_name::varchar AS characteristic,
+     charass_value AS value
+   FROM crmacct, char, charass
+   WHERE (('CRMACCT'=charass_target_type)
+   AND (crmacct_id=charass_target_id)
+   AND (charass_char_id=char_id));
+
+GRANT ALL ON TABLE api.accountchar TO xtrole;
+COMMENT ON VIEW api.accountchar IS 'Account Characteristics';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.accountchar DO INSTEAD
+
+  INSERT INTO charass (
+    charass_target_type,
+    charass_target_id,
+    charass_char_id,
+    charass_value,
+    charass_default
+    )
+  VALUES (
+    'CRMACCT',
+    getCrmAcctId(NEW.account_number),
+    getCharId(NEW.characteristic,'CRMACCT'),
+    NEW.value,
+    false);
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.accountchar DO INSTEAD
+
+  UPDATE charass SET
+    charass_value=NEW.value
+  WHERE ((charass_target_type='CRMACCT')
+  AND (charass_target_id=getCrmAcctId(OLD.account_number))
+  AND (charass_char_id=getCharId(OLD.characteristic,'CRMACCT')));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.accountchar DO INSTEAD
+
+  DELETE FROM charass
+  WHERE ((charass_target_type='CRMACCT')
+  AND (charass_target_id=getCrmAcctId(OLD.account_number))
+  AND (charass_char_id=getCharId(OLD.characteristic,'CRMACCT')));
diff --git a/foundation-database/api/views/accountcomment.sql b/foundation-database/api/views/accountcomment.sql
new file mode 100644 (file)
index 0000000..548b42a
--- /dev/null
@@ -0,0 +1,45 @@
+-- Account Comment
+
+DROP VIEW api.accountcomment;
+CREATE VIEW api.accountcomment
+AS 
+   SELECT 
+     crmacct_number::varchar AS account_number,
+     cmnttype_name AS type,
+     comment_date AS date,
+     comment_user AS username,
+     comment_text AS text
+   FROM crmacct, cmnttype, comment
+   WHERE ((comment_source='CRMA')
+   AND (comment_source_id=crmacct_id)
+   AND (comment_cmnttype_id=cmnttype_id));
+
+GRANT ALL ON TABLE api.accountcomment TO xtrole;
+COMMENT ON VIEW api.accountcomment IS 'Account Comment';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.accountcomment DO INSTEAD
+
+  INSERT INTO comment (
+    comment_date,
+    comment_source,
+    comment_source_id,
+    comment_user,
+    comment_cmnttype_id,
+    comment_text
+    )
+  VALUES (
+    COALESCE(NEW.date,now()),
+    'CRMA',
+    getCrmAcctId(NEW.account_number),
+    COALESCE(NEW.username,getEffectiveXtUser()),
+    getCmntTypeId(NEW.type),
+    NEW.text);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.accountcomment DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.accountcomment DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/accountfile.sql b/foundation-database/api/views/accountfile.sql
new file mode 100644 (file)
index 0000000..1fd9677
--- /dev/null
@@ -0,0 +1,51 @@
+-- Account File 
+
+SELECT dropifexists('VIEW', 'accountfile','API'); 
+CREATE VIEW api.accountfile
+AS 
+   SELECT 
+     crmacct_number AS account_number,
+     url_title AS title,
+     url_url AS url
+   FROM crmacct, url
+   WHERE ((crmacct_id=url_source_id)
+   AND (url_source='CRMA'));
+
+GRANT ALL ON TABLE api.accountfile TO xtrole;
+COMMENT ON VIEW api.accountfile IS 'Account File';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.accountfile DO INSTEAD
+
+  INSERT INTO url (
+    url_source_id,
+    url_source,
+    url_title,
+    url_url)
+  VALUES (
+    getCrmAcctId(NEW.account_number),
+    'CRMA',
+    NEW.title,
+    NEW.url);
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.accountfile DO INSTEAD
+
+  UPDATE url SET
+    url_title=NEW.title,
+    url_url=NEW.url
+  WHERE  ((url_source_id=getCrmAcctId(OLD.account_number))
+  AND (url_source='CRMA')
+  AND (url_title=OLD.title)
+  AND (url_url=OLD.url));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.accountfile DO INSTEAD
+
+  DELETE FROM url
+  WHERE  ((url_source_id=getCrmAcctId(OLD.account_number))
+  AND (url_source='CRMA')
+  AND (url_title=OLD.title)
+  AND (url_url=OLD.url));
diff --git a/foundation-database/api/views/accountimage.sql b/foundation-database/api/views/accountimage.sql
new file mode 100644 (file)
index 0000000..a64bc75
--- /dev/null
@@ -0,0 +1,43 @@
+-- Account Image
+
+SELECT dropifexists('VIEW', 'accountimage','API');
+CREATE VIEW api.accountimage
+AS 
+   SELECT 
+     crmacct_number AS account_number,
+     image_name AS image_name
+   FROM crmacct, imageass, image
+   WHERE ((crmacct_id=imageass_source_id)
+   AND (imageass_source='CRMA')
+   AND (imageass_image_id=image_id));
+
+GRANT ALL ON TABLE api.accountimage TO xtrole;
+COMMENT ON VIEW api.accountimage IS 'Account Image';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.accountimage DO INSTEAD
+
+  SELECT saveImageAss(
+    'CRMA',
+    getCrmAcctId(NEW.account_number),
+    'M',
+    getImageId(NEW.image_name));
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.accountimage DO INSTEAD
+
+  UPDATE imageass
+  SET imageass_image_id=getImageId(NEW.image_name)
+  WHERE ((imageass_source_id=getCrmAcctId(OLD.account_number))
+  AND (imageass_source='CRMA')
+  AND (imageass_image_id=getImageId(OLD.image_name)));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.accountimage DO INSTEAD
+
+  DELETE FROM imageass
+  WHERE ((imageass_source_id=getCrmAcctId(OLD.account_number))
+  AND (imageass_source='CRMA')
+  AND (imageass_image_id=getImageId(OLD.image_name)));
diff --git a/foundation-database/api/views/address.sql b/foundation-database/api/views/address.sql
new file mode 100644 (file)
index 0000000..bef6549
--- /dev/null
@@ -0,0 +1,63 @@
+  --Address View
+
+SELECT dropIfExists('VIEW', 'address', 'api');
+  CREATE OR REPLACE VIEW api.address AS
+  SELECT 
+    addr_number::varchar AS address_number,
+    addr_line1 AS address1,
+    addr_line2 AS address2,
+    addr_line3 AS address3,
+    addr_city AS city,
+    addr_state AS state,
+    addr_postalcode AS postal_code,
+    addr_country AS country,
+    addr_active AS active,
+    addr_notes AS notes,
+    ''::TEXT AS change       
+  FROM
+    addr;
+
+GRANT ALL ON TABLE api.address TO xtrole;
+COMMENT ON VIEW api.address IS 'Address';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.address DO INSTEAD
+
+SELECT    saveAddr(
+           NULL,
+            NEW.address_number,
+            NEW.address1,
+            NEW.address2,
+            NEW.address3,
+            NEW.city,
+            NEW.state,
+            NEW.postal_code,
+            NEW.country,
+            COALESCE(NEW.active,TRUE),
+            NEW.notes,
+            NULL);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.address DO INSTEAD
+
+SELECT saveAddr(
+            getAddrId(NEW.address_number),
+            NEW.address_number,
+            NEW.address1,
+            NEW.address2,
+            NEW.address3,
+            NEW.city,
+            NEW.state,
+            NEW.postal_code,
+            NEW.country,
+            NEW.active,
+            NEW.notes,
+            NEW.change);
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.address DO INSTEAD
+
+SELECT deleteAddress(getAddrId(OLD.address_number));
diff --git a/foundation-database/api/views/addresschar.sql b/foundation-database/api/views/addresschar.sql
new file mode 100644 (file)
index 0000000..436a413
--- /dev/null
@@ -0,0 +1,52 @@
+-- Address Characteristic
+
+SELECT dropIfExists('VIEW', 'addresschar', 'api');
+CREATE VIEW api.addresschar
+AS 
+   SELECT 
+     addr_number::varchar AS address_number,
+     char_name::varchar AS characteristic,
+     charass_value AS value
+   FROM addr, char, charass
+   WHERE (('ADDR'=charass_target_type)
+   AND (addr_id=charass_target_id)
+   AND (charass_char_id=char_id));
+
+GRANT ALL ON TABLE api.addresschar TO xtrole;
+COMMENT ON VIEW api.addresschar IS 'Address Characteristics';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.addresschar DO INSTEAD
+
+  INSERT INTO charass (
+    charass_target_type,
+    charass_target_id,
+    charass_char_id,
+    charass_value,
+    charass_default
+    )
+  VALUES (
+    'ADDR',
+    getAddrId(NEW.address_number),
+    getCharId(NEW.characteristic,'ADDR'),
+    NEW.value,
+    false);
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.addresschar DO INSTEAD
+
+  UPDATE charass SET
+    charass_value=NEW.value
+  WHERE ((charass_target_type='ADDR')
+  AND (charass_target_id=getAddrId(OLD.address_number))
+  AND (charass_char_id=getCharId(OLD.characteristic,'ADDR')));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.addresschar DO INSTEAD
+
+  DELETE FROM charass
+  WHERE ((charass_target_type='ADDR')
+  AND (charass_target_id=getAddrId(OLD.address_number))
+  AND (charass_char_id=getCharId(OLD.characteristic,'ADDR')));
diff --git a/foundation-database/api/views/addresscomment.sql b/foundation-database/api/views/addresscomment.sql
new file mode 100644 (file)
index 0000000..f54d612
--- /dev/null
@@ -0,0 +1,45 @@
+-- Address Comment
+
+SELECT dropIfExists('VIEW', 'addresscomment', 'api');
+CREATE VIEW api.addresscomment
+AS 
+   SELECT 
+     addr_number::varchar AS Address_number,
+     cmnttype_name AS type,
+     comment_date AS date,
+     comment_user AS username,
+     comment_text AS text
+   FROM addr, cmnttype, comment
+   WHERE ((comment_source='ADDR')
+   AND (comment_source_id=addr_id)
+   AND (comment_cmnttype_id=cmnttype_id));
+
+GRANT ALL ON TABLE api.addresscomment TO xtrole;
+COMMENT ON VIEW api.addresscomment IS 'Address Comment';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.addresscomment DO INSTEAD
+
+  INSERT INTO comment (
+    comment_date,
+    comment_source,
+    comment_source_id,
+    comment_user,
+    comment_cmnttype_id,
+    comment_text
+    )
+  VALUES (
+    COALESCE(NEW.date,now()),
+    'ADDR',
+    getAddrId(NEW.Address_number),
+    COALESCE(NEW.username,getEffectiveXtUser()),
+    getCmntTypeId(NEW.type),
+    NEW.text);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.addresscomment DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.addresscomment DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/apmemo.sql b/foundation-database/api/views/apmemo.sql
new file mode 100644 (file)
index 0000000..e7a220e
--- /dev/null
@@ -0,0 +1,107 @@
+CREATE OR REPLACE VIEW api.apmemo AS 
+ SELECT vendinfo.vend_number AS vendor_number,
+        apopen.apopen_docdate AS document_date,
+        apopen.apopen_duedate AS due_date, 
+        CASE
+            WHEN apopen.apopen_doctype = 'C'::bpchar THEN 'Credit Memo'::text
+            ELSE 'Debit Memo'::text
+        END AS document_type,
+        apopen.apopen_docnumber AS document_number,
+        apopen.apopen_ponumber AS po_number,
+        apopen.apopen_journalnumber AS journal_number,
+        terms.terms_code AS terms,
+        curr.curr_abbr AS currency,
+        apopen.apopen_amount AS amount,
+        apopen.apopen_paid AS paid,
+        apopen.apopen_amount - apopen.apopen_paid AS balance,
+        apopen.apopen_notes AS notes, 
+        CASE
+            WHEN apopen.apopen_accnt_id = (-1) THEN NULL::text
+            ELSE formatglaccount(apopen.apopen_accnt_id)
+        END AS alternate_prepaid_account
+   FROM apopen
+   LEFT JOIN vendinfo ON vendinfo.vend_id = apopen.apopen_vend_id
+   LEFT JOIN curr_symbol curr ON curr.curr_id = apopen.apopen_curr_id
+   LEFT JOIN terms ON terms.terms_id = apopen.apopen_terms_id
+  WHERE apopen.apopen_doctype = ANY (ARRAY['C'::bpchar, 'D'::bpchar]);
+
+GRANT ALL ON TABLE api.apmemo TO xtrole;
+COMMENT ON VIEW api.apmemo IS 'A/P Credit and Debit Memo';
+
+CREATE OR REPLACE FUNCTION insertapmemo(api.apmemo) RETURNS boolean AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  pNew ALIAS FOR $1;
+  _result INTEGER;
+
+BEGIN
+  IF (pNew.document_type = 'Credit Memo') THEN
+    SELECT createAPCreditMemo( getVendId(pNew.vendor_number),
+                               pNew.document_number,
+                               pNew.po_number,
+                               pNew.document_date,
+                               pNew.amount,
+                               pNew.notes,
+                               getGLAccntId(pNew.alternate_prepaid_account),
+                               pNew.due_date,
+                               getTermsId(pNew.terms) ) INTO _result;
+    IF (_result <= 0) THEN
+      RAISE EXCEPTION 'Function createAPCreditMemo failed with result = %', _result;
+    END IF;
+  ELSE
+    IF (pNew.document_type = 'Debit Memo') THEN
+      SELECT createAPDebitMemo( null, getVendId(pNew.vendor_number),
+                                pNew.journal_number,
+                                pNew.document_number,
+                                pNew.po_number,
+                                pNew.document_date,
+                                pNew.amount,
+                                pNew.notes,
+                                getGLAccntId(pNew.alternate_prepaid_account),
+                                pNew.due_date,
+                                getTermsId(pNew.terms),
+                                COALESCE(getCurrId(pNew.currency), baseCurrId()) ) INTO _result;
+      IF (_result <= 0) THEN
+        RAISE EXCEPTION 'Function createAPDebitMemo failed with result = %', _result;
+      END IF;
+    ELSE
+      RAISE EXCEPTION 'Function insertAPMemo failed, invalid Document Type';
+    END IF;
+  END IF;
+
+  RETURN TRUE;
+END;
+$$ LANGUAGE 'plpgsql';
+
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.apmemo DO INSTEAD  SELECT insertapmemo(new.*) AS insertapmemo;
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.apmemo DO INSTEAD  UPDATE apopen SET apopen_duedate = new.due_date, apopen_terms_id = gettermsid(new.terms), apopen_amount = new.amount, apopen_notes = new.notes
+  WHERE apopen.apopen_docnumber = old.document_number AND apopen.apopen_doctype::text = 
+        CASE
+            WHEN old.document_type = 'Credit Memo'::text THEN 'C'::text
+            WHEN old.document_type = 'Debit Memo'::text THEN 'D'::text
+            ELSE ''::text
+        END;
+
+CREATE OR REPLACE RULE "_RETURN" AS
+    ON SELECT TO api.apmemo DO INSTEAD  SELECT vendinfo.vend_number AS vendor_number, apopen.apopen_docdate AS document_date, apopen.apopen_duedate AS due_date, 
+        CASE
+            WHEN apopen.apopen_doctype = 'C'::bpchar THEN 'Credit Memo'::text
+            ELSE 'Debit Memo'::text
+        END AS document_type, apopen.apopen_docnumber AS document_number, apopen.apopen_ponumber AS po_number, apopen.apopen_journalnumber AS journal_number, terms.terms_code AS terms, curr.curr_abbr AS currency, apopen.apopen_amount AS amount, apopen.apopen_paid AS paid, apopen.apopen_amount - apopen.apopen_paid AS balance, apopen.apopen_notes AS notes, 
+        CASE
+            WHEN apopen.apopen_accnt_id = (-1) THEN NULL::text
+            ELSE formatglaccount(apopen.apopen_accnt_id)
+        END AS alternate_prepaid_account
+   FROM apopen
+   LEFT JOIN vendinfo ON vendinfo.vend_id = apopen.apopen_vend_id
+   LEFT JOIN curr_symbol curr ON curr.curr_id = apopen.apopen_curr_id
+   LEFT JOIN terms ON terms.terms_id = apopen.apopen_terms_id
+  WHERE apopen.apopen_doctype = ANY (ARRAY['C'::bpchar, 'D'::bpchar]);
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.apmemo DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/armemo.sql b/foundation-database/api/views/armemo.sql
new file mode 100644 (file)
index 0000000..c71af19
--- /dev/null
@@ -0,0 +1,121 @@
+CREATE OR REPLACE VIEW api.armemo AS
+  SELECT cust_number AS customer_number,
+         aropen_docdate AS document_date,
+         aropen_duedate AS due_date,
+         CASE WHEN (aropen_doctype='C') THEN 'Credit Memo'
+              ELSE 'Debit Memo'
+         END AS document_type,
+         aropen_docnumber AS document_number,
+         aropen_applyto AS order_number,
+         aropen_journalnumber AS journal_number,
+         rsncode_code AS reason_code,
+         terms_code AS terms,
+         salesrep_number AS sales_rep,
+         curr.curr_abbr AS currency,
+         aropen_amount AS amount,
+         aropen_paid AS paid,
+         (aropen_amount - aropen_paid) AS balance,
+         aropen_commission_due AS commission_due,
+         aropen_commission_paid AS commission_paid,
+         aropen_notes AS notes,
+         salescat_name AS alternate_prepaid_sales_category,
+         CASE WHEN (aropen_accnt_id=-1) THEN NULL
+              ELSE formatglaccount(aropen_accnt_id)
+         END AS alternate_prepaid_account
+  FROM aropen
+         LEFT OUTER JOIN custinfo ON (cust_id=aropen_cust_id)
+         LEFT OUTER JOIN curr_symbol AS curr ON (curr.curr_id=aropen_curr_id)
+         LEFT OUTER JOIN salesrep ON (salesrep_id=aropen_salesrep_id)
+         LEFT OUTER JOIN terms ON (terms_id=aropen_terms_id)
+         LEFT OUTER JOIN salescat ON (salescat_id=aropen_salescat_id)
+         LEFT OUTER JOIN rsncode ON (rsncode_id=aropen_rsncode_id)
+  WHERE (aropen_doctype IN ('C', 'D'));
+       
+GRANT ALL ON TABLE api.armemo TO xtrole;
+COMMENT ON VIEW api.armemo IS 'A/R Credit and Debit Memo';
+
+
+CREATE OR REPLACE FUNCTION insertARMemo(api.armemo) RETURNS boolean AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  pNew ALIAS FOR $1;
+  _result INTEGER;
+
+BEGIN
+  IF (pNew.document_type = 'Credit Memo') THEN
+    SELECT createARCreditMemo( NULL,
+                               getCustId(pNew.customer_number),
+                               pNew.document_number,
+                               pNew.order_number,
+                               pNew.document_date,
+                               pNew.amount,
+                               pNew.notes,
+                               getRsnId(pNew.reason_code),
+                               getSalescatId(pNew.alternate_prepaid_sales_category),
+                               getGLAccntId(pNew.alternate_prepaid_account),
+                               pNew.due_date,
+                               getTermsId(pNew.terms),
+                               getSalesrepId(pNew.sales_rep),
+                               pNew.commission_due,
+                               pNew.journal_number,
+                               COALESCE(getCurrId(pNew.currency), baseCurrId()) ) INTO _result;
+    IF (_result <= 0) THEN
+      RAISE EXCEPTION 'Function createARCreditMemo failed with result = %', _result;
+    END IF;
+  ELSE
+    IF (pNew.document_type = 'Debit Memo') THEN
+      SELECT createARDebitMemo( null, getCustId(pNew.customer_number),
+                                pNew.journal_number,
+                                pNew.document_number,
+                                pNew.order_number,
+                                pNew.document_date,
+                                pNew.amount,
+                                pNew.notes,
+                                getRsnId(pNew.reason_code),
+                                getSalescatId(pNew.alternate_prepaid_sales_category),
+                                getGLAccntId(pNew.alternate_prepaid_account),
+                                pNew.due_date,
+                                getTermsId(pNew.terms),
+                                getSalesrepId(pNew.sales_rep),
+                                pNew.commission_due,
+                                COALESCE(getCurrId(pNew.currency), baseCurrId()) ) INTO _result;
+      IF (_result <= 0) THEN
+        RAISE EXCEPTION 'Function createARDebitMemo failed with result = %', _result;
+      END IF;
+    ELSE
+      RAISE EXCEPTION 'Function insertARMemo failed, invalid Document Type';
+    END IF;
+  END IF;
+
+  RETURN TRUE;
+END;
+$$ LANGUAGE 'plpgsql';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+  ON INSERT TO api.armemo DO INSTEAD
+    SELECT insertARMemo(NEW);
+
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+  ON UPDATE TO api.armemo DO INSTEAD
+    UPDATE aropen SET aropen_duedate=NEW.due_date,
+                      aropen_terms_id=getTermsId(NEW.terms),
+                      aropen_salesrep_id=getSalesrepId(NEW.sales_rep),
+                      aropen_amount=NEW.amount,
+                      aropen_commission_due=NEW.commission_due,
+                      aropen_notes=NEW.notes,
+                      aropen_rsncode_id=getRsnId(NEW.reason_code)
+    WHERE ( (aropen_docnumber=OLD.document_number)
+      AND   (aropen_doctype = CASE WHEN (OLD.document_type='Credit Memo') THEN 'C'
+                                   WHEN (OLD.document_type='Debit Memo') THEN 'D'
+                                   ELSE ''
+                              END) );
+
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+  ON DELETE TO api.armemo DO INSTEAD
+
+    NOTHING;
diff --git a/foundation-database/api/views/bom.sql b/foundation-database/api/views/bom.sql
new file mode 100644 (file)
index 0000000..683a2b9
--- /dev/null
@@ -0,0 +1,49 @@
+  --Bill of Material View
+
+SELECT dropIfExists('VIEW', 'bom', 'api');
+  CREATE OR REPLACE VIEW api.bom AS
+
+  SELECT
+    item_number::varchar AS item_number,
+    bomhead_revision::varchar AS revision,
+    bomhead_docnum AS document_number,
+    bomhead_revisiondate AS revision_date,
+    bomhead_batchsize AS batch_size,
+    bomhead_requiredqtyper AS total_qty_per
+  FROM
+    bomhead, item
+  WHERE
+    (bomhead_item_id=item_id);
+
+
+GRANT ALL ON TABLE api.bom TO xtrole;
+COMMENT ON VIEW api.bom IS 'Bill of Material Header';
+
+  --Rules
+
+  CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.bom DO INSTEAD
+
+  SELECT saveBomHead(
+     getItemId(NEW.item_number),
+     NEW.revision,
+     NEW.revision_date,
+     NEW.document_number,
+     COALESCE(NEW.batch_size,0),
+     NEW.total_qty_per);
+    CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.bom DO INSTEAD
+
+  SELECT saveBomHead(
+     getItemId(NEW.item_number),
+     NEW.revision,
+     NEW.revision_date,
+     NEW.document_number,
+     COALESCE(NEW.batch_size,0),
+     NEW.total_qty_per);
+
+    CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.bom DO INSTEAD
+
+    SELECT deletebom(getItemId(OLD.item_number));
diff --git a/foundation-database/api/views/bomitem.sql b/foundation-database/api/views/bomitem.sql
new file mode 100644 (file)
index 0000000..cdd2fb1
--- /dev/null
@@ -0,0 +1,170 @@
+  --Bill of Material Item View
+
+  SELECT dropIfExists('VIEW', 'bomitem', 'api');
+  CREATE OR REPLACE VIEW api.bomitem AS
+
+  SELECT
+    bomitem_id AS id,
+    p.item_number::varchar AS bom_item_number,
+    bomhead_revision::varchar AS bom_revision,
+    bomitem_seqnumber AS sequence_number,
+    i.item_number AS item_number,
+    CASE WHEN
+      bomitem_effective = startoftime() THEN
+        'Always'
+      ELSE
+        formatdate(bomitem_effective)
+    END AS effective,
+    CASE WHEN
+      bomitem_expires = endoftime() THEN
+        'Never'
+      ELSE
+        formatdate(bomitem_expires)
+    END AS expires,
+    bomitem_qtyper AS qty_per,
+    uom_name AS issue_uom,
+    bomitem_scrap AS scrap,
+    bomitem_createwo AS create_child_wo,
+    CASE
+      WHEN bomitem_issuemethod = 'M' THEN
+        'Mixed'
+      WHEN bomitem_issuemethod = 'L' THEN
+        'Pull'
+      WHEN bomitem_issuemethod = 'S' THEN
+        'Push'
+    END AS issue_method,
+    formatBooSeq(p.item_id,bomitem_booitem_seq_id) AS used_at,
+    bomitem_schedatwooper AS schedule_at_wo_operation,
+    bomitem_ecn AS ecn_number,
+    bomitem_notes AS notes,
+    bomitem_ref AS reference,
+    CASE
+      WHEN bomitem_subtype = 'N' THEN
+        'No'
+      WHEN bomitem_subtype = 'I' THEN
+        'Item-Defined'
+      WHEN bomitem_subtype = 'B' THEN
+        'BOM-Defined'
+    END AS substitutions,
+    char_name AS characteristic,
+    bomitem_value AS value
+  FROM
+    bomitem
+      LEFT OUTER JOIN bomhead ON ((bomitem_parent_item_id=bomhead_item_id)
+                              AND (bomitem_rev_id=bomhead_rev_id))
+      LEFT OUTER JOIN char ON (bomitem_char_id=char_id), 
+    item p, item i, uom
+  WHERE ((bomitem_parent_item_id=p.item_id)
+  AND (bomitem_item_id=i.item_id)
+  AND (bomitem_uom_id=uom_id))
+  ORDER BY p.item_number,bomitem_seqnumber;
+
+GRANT ALL ON TABLE api.bomitem TO xtrole;
+COMMENT ON VIEW api.bomitem IS 'Bill of Material Item';
+
+  --Rules
+
+  CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.bomitem DO INSTEAD
+
+    SELECT createBOMItem( COALESCE(NEW.id, NEXTVAL('bomitem_bomitem_id_seq')::integer), 
+                          getItemId(NEW.bom_item_number), 
+                          getItemId(NEW.item_number),
+                          COALESCE(NEW.sequence_number,(
+                            SELECT MAX(bomitem_seqnumber) + 10
+                            FROM bomitem(getItemId(NEW.bom_item_number),COALESCE(
+                                         getRevId('BOM',NEW.bom_item_number,NEW.bom_revision)))),10),
+                          CASE
+                            WHEN NEW.issue_method = 'Mixed' THEN
+                              'M'
+                            WHEN NEW.issue_method = 'Push' THEN
+                              'S'
+                            WHEN NEW.issue_method = 'Pull' THEN
+                              'L'
+                            ELSE
+                              fetchMetricText('DefaultWomatlIssueMethod')
+                          END,
+                          COALESCE(getUomId(NEW.issue_uom),(
+                          SELECT item_inv_uom_id
+                          FROM item
+                          WHERE (item_id=getItemId(NEW.item_number)))), 
+                          NEW.qty_per, 
+                          NEW.scrap,
+                          CASE WHEN (NEW.effective = 'Always') THEN startoftime()
+                               ELSE COALESCE(NEW.effective::date,startoftime())
+                          END, 
+                          CASE WHEN (NEW.expires = 'Never') THEN endoftime()
+                               ELSE COALESCE(NEW.expires::date,endoftime())
+                          END,
+                          COALESCE(NEW.create_child_wo,FALSE),
+                          COALESCE(getBooitemSeqId(NEW.bom_item_number,NEW.used_at),-1),
+                          COALESCE(NEW.schedule_at_wo_operation,FALSE),
+                          NEW.ecn_number,
+                          CASE
+                            WHEN NEW.substitutions = 'No' THEN
+                              'N'
+                            WHEN NEW.substitutions = 'BOM-Defined' THEN
+                              'B'
+                            ELSE
+                              'I'
+                          END,
+                          COALESCE(getRevId('BOM',NEW.bom_item_number,NEW.bom_revision)),
+                          getCharId(NEW.characteristic,'I'),
+                          NEW.value,
+                          NEW.notes,
+                          NEW.reference);
+    CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.bomitem DO INSTEAD
+
+    UPDATE bomitem SET
+      bomitem_issuemethod=
+      CASE
+        WHEN NEW.issue_method = 'Mixed' THEN
+                              'M'
+        WHEN NEW.issue_method = 'Push' THEN
+                              'S'
+        WHEN NEW.issue_method = 'Pull' THEN
+                              'L'
+      END,
+      bomitem_uom_id=getUomId(NEW.issue_uom), 
+      bomitem_qtyper=NEW.qty_per, 
+      bomitem_scrap=NEW.scrap,
+      bomitem_effective=
+        CASE WHEN NEW.effective = 'Always' THEN
+          startoftime()
+        ELSE 
+          NEW.effective::date
+        END, 
+      bomitem_expires=
+        CASE WHEN NEW.expires = 'Never' THEN
+          endoftime()
+        ELSE 
+          NEW.expires::date
+        END,
+      bomitem_createwo=NEW.create_child_wo,
+      bomitem_booitem_seq_id=COALESCE(getBooitemSeqId(NEW.bom_item_number,NEW.used_at),-1),
+      bomitem_schedatwooper=NEW.schedule_at_wo_operation,
+      bomitem_ecn=NEW.ecn_number,
+      bomitem_subtype=
+      CASE
+        WHEN NEW.substitutions = 'No' THEN
+          'N'
+        WHEN NEW.substitutions = 'Item-Defined' THEN
+          'I'
+        WHEN NEW.substitutions = 'BOM-Defined' THEN
+          'B'
+      END,
+      bomitem_rev_id=getRevId('BOM',NEW.bom_item_number,NEW.bom_revision),
+      bomitem_char_id=getCharId(NEW.characteristic,'I'),
+      bomitem_value=NEW.value,
+      bomitem_notes=NEW.notes,
+      bomitem_ref=NEW.reference
+      WHERE (bomitem_id = OLD.id);
+
+    CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.bomitem DO INSTEAD
+
+    DELETE FROM bomitem
+    WHERE ((bomitem_id = OLD.id)
+    AND (fetchMetricBool('AllowBOMItemDelete')));
diff --git a/foundation-database/api/views/bomitemcomment.sql b/foundation-database/api/views/bomitemcomment.sql
new file mode 100644 (file)
index 0000000..19dbefa
--- /dev/null
@@ -0,0 +1,50 @@
+-- Bill of Material Item Comment
+
+SELECT dropIfExists('VIEW', 'bomitemcomment', 'api');
+CREATE VIEW api.bomitemcomment
+AS 
+   SELECT 
+     bomitem_id AS bomitem_id,
+     cmnttype_name AS type,
+     comment_date AS date,
+     comment_user AS username,
+     comment_text AS text
+   FROM bomitem
+     LEFT OUTER JOIN bomhead ON ((bomitem_parent_item_id=bomhead_item_id) 
+                             AND (bomitem_rev_id=bomhead_rev_id)),
+     item, cmnttype, comment
+   WHERE ((comment_source='BMI')
+   AND (comment_source_id=bomitem_id)
+   AND (comment_cmnttype_id=cmnttype_id)
+   AND (bomitem_parent_item_id=item_id))
+   ORDER BY item_number,bomhead_revision,bomitem_seqnumber,comment_date;
+
+GRANT ALL ON TABLE api.bomitemcomment TO xtrole;
+COMMENT ON VIEW api.bomitemcomment IS 'Bill of Material Comment';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.bomitemcomment DO INSTEAD
+
+  INSERT INTO comment (
+    comment_date,
+    comment_source,
+    comment_source_id,
+    comment_user,
+    comment_cmnttype_id,
+    comment_text
+    )
+  VALUES (
+    COALESCE(NEW.date,now()),
+    'BMI',
+    NEW.bomitem_id,
+    COALESCE(NEW.username,getEffectiveXtUser()),
+    getCmntTypeId(NEW.type),
+    NEW.text);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.bomitemcomment DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.bomitemcomment DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/bomitemsubstitute.sql b/foundation-database/api/views/bomitemsubstitute.sql
new file mode 100644 (file)
index 0000000..aec3ae5
--- /dev/null
@@ -0,0 +1,55 @@
+-- Bill of Material Item Substitute
+
+SELECT dropIfExists('VIEW', 'bomitemsubstitute', 'api');
+CREATE VIEW api.bomitemsubstitute
+AS 
+   SELECT 
+     bomitem_id,
+     p.item_number::varchar AS bom_item_number,
+     bomhead_revision::varchar AS bom_revision,
+     bomitem_seqnumber AS sequence_number,
+     s.item_number::varchar AS substitute_item_number,
+     bomitemsub_uomratio AS sub_parent_uom_ratio,
+     bomitemsub_rank AS ranking
+   FROM item p, item s, bomitem
+     LEFT OUTER JOIN bomhead ON ((bomitem_parent_item_id=bomhead_item_id)
+                             AND (bomitem_rev_id=bomhead_rev_id)),
+     bomitemsub
+   WHERE ((p.item_id=bomitem_parent_item_id)
+   AND (s.item_id=bomitemsub_item_id)
+   AND (bomitemsub_bomitem_id=bomitem_id));
+
+GRANT ALL ON TABLE api.bomitemsubstitute TO xtrole;
+COMMENT ON VIEW api.bomitemsubstitute IS 'Bill of Material Item Substitute';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.bomitemsubstitute DO INSTEAD
+
+  INSERT INTO bomitemsub (
+    bomitemsub_bomitem_id,
+    bomitemsub_item_id,
+    bomitemsub_uomratio,
+    bomitemsub_rank)
+  VALUES (
+    NEW.bomitem_id,
+    getItemId(NEW.substitute_item_number),
+    COALESCE(NEW.sub_parent_uom_ratio,1),
+    COALESCE(NEW.ranking,1));
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.bomitemsubstitute DO INSTEAD
+
+  UPDATE bomitemsub SET
+    bomitemsub_uomratio=NEW.sub_parent_uom_ratio,
+    bomitemsub_rank=NEW.ranking
+  WHERE  ((bomitemsub_bomitem_id=OLD.bomitem_id)
+  AND (bomitemsub_item_id=getItemId(OLD.substitute_item_number)));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.bomitemsubstitute DO INSTEAD
+
+  DELETE FROM bomitemsub
+  WHERE  ((bomitemsub_bomitem_id=OLD.bomitem_id)
+  AND (bomitemsub_item_id=getItemId(OLD.substitute_item_number)));
diff --git a/foundation-database/api/views/budget.sql b/foundation-database/api/views/budget.sql
new file mode 100755 (executable)
index 0000000..1574862
--- /dev/null
@@ -0,0 +1,51 @@
+-- View: api.budget
+
+SELECT dropIfExists('VIEW', 'budget', 'api');
+
+
+CREATE OR REPLACE VIEW api.budget AS
+   SELECT 
+    budghead_name AS name,
+    budghead_descrip AS description
+   FROM budghead
+   ORDER BY name;
+
+--Rules
+--INSERT
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.budget DO INSTEAD
+
+  INSERT INTO budghead (
+   budghead_name,
+   budghead_descrip)
+  VALUES (
+    NEW.name,
+    NEW.description);
+
+--UPDATE
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.budget 
+    DO INSTEAD
+
+  UPDATE budghead SET
+    budghead_name=NEW.name,
+    budghead_descrip=NEW.description
+  WHERE (budghead_name=OLD.name);
+
+--DELETE
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.budget 
+    DO INSTEAD
+
+  DELETE FROM budghead
+  WHERE (budghead_name=OLD.name);
+
+ALTER TABLE api.budget OWNER TO "admin";
+GRANT ALL ON TABLE api.budget TO "admin";
+GRANT ALL ON TABLE api.budget TO xtrole;
+COMMENT ON VIEW api.budget IS 'Budget Header';
+
+
diff --git a/foundation-database/api/views/budgetentry.sql b/foundation-database/api/views/budgetentry.sql
new file mode 100755 (executable)
index 0000000..a47af44
--- /dev/null
@@ -0,0 +1,64 @@
+-- View: api.budgetentry
+
+SELECT dropIfExists('VIEW', 'budgetentry', 'api');
+
+
+CREATE OR REPLACE VIEW api.budgetentry AS
+SELECT budghead_name AS name,
+       formatglaccount(accnt_id) AS account,
+       period_start AS period_start,
+       budgitem_amount AS amount
+FROM 
+     budgitem, budghead, period, accnt
+WHERE
+     budgitem_budghead_id = budghead_id 
+     AND budgitem_period_id = period_id
+     AND budgitem_accnt_id = accnt_id
+ORDER BY name, period_start, account;
+
+--Rules
+--INSERT
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.budgetentry DO INSTEAD
+
+  INSERT INTO budgitem (
+   budgitem_budghead_id,
+   budgitem_period_id,
+   budgitem_accnt_id,
+   budgitem_amount)
+  VALUES (
+    getbudgheadid(NEW.name),
+    getperiodid(NEW.period_start),
+    getglaccntid(NEW.account),
+    NEW.amount);
+
+--UPDATE
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.budgetentry
+    DO INSTEAD
+
+  UPDATE budgitem SET
+           budgitem_amount = (NEW.amount)
+  WHERE (budgitem_budghead_id = getbudgheadid(OLD.name) 
+         AND budgitem_period_id = getperiodid(OLD.period_start)
+         AND budgitem_accnt_id = getglaccntid(OLD.account));
+         
+--DELETE
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.budgetentry 
+    DO INSTEAD
+
+  DELETE FROM budgitem
+  WHERE (budgitem_budghead_id=getbudgheadid(OLD.name) 
+         AND budgitem_period_id=getperiodid(OLD.period_start)
+         AND budgitem_accnt_id=getglaccntid(OLD.account));
+
+ALTER TABLE api.budgetentry OWNER TO "admin";
+GRANT ALL ON TABLE api.budgetentry TO "admin";
+GRANT ALL ON TABLE api.budgetentry TO xtrole;
+COMMENT ON VIEW api.budgetentry IS 'Budget Entry';
+
+
diff --git a/foundation-database/api/views/cashreceipt.sql b/foundation-database/api/views/cashreceipt.sql
new file mode 100644 (file)
index 0000000..c1c7caf
--- /dev/null
@@ -0,0 +1,224 @@
+SELECT dropIfExists('VIEW', 'cashreceipt', 'api');
+CREATE OR REPLACE VIEW api.cashreceipt AS
+  SELECT
+    cust_number::VARCHAR AS customer_number,
+    cashrcpt_number AS cashreceipt_number,
+    CASE
+      WHEN cashrcpt_fundstype='C' THEN
+        'Check'::VARCHAR
+      WHEN cashrcpt_fundstype='T' THEN
+        'Certified Check'::VARCHAR
+      WHEN cashrcpt_fundstype='M' THEN
+        'Master Card'::VARCHAR
+      WHEN cashrcpt_fundstype='V' THEN
+        'Visa'::VARCHAR
+      WHEN cashrcpt_fundstype='A' THEN
+        'American Express'::VARCHAR
+      WHEN cashrcpt_fundstype='D' THEN
+        'Discover Card'::VARCHAR
+      WHEN cashrcpt_fundstype='R' THEN
+        'Other Credit Card'::VARCHAR
+      WHEN cashrcpt_fundstype='K' THEN
+        'Cash'::VARCHAR
+      WHEN cashrcpt_fundstype='W' THEN
+        'Wire Transfer'::VARCHAR
+      WHEN cashrcpt_fundstype='O' THEN
+        'Other'::VARCHAR
+    END AS funds_type,
+    cashrcpt_docnumber::VARCHAR AS check_document_number,
+    cust_name AS customer_name,
+    addr_line1 AS customer_address,
+    curr_abbr AS currency,
+    cashrcpt_amount AS amount_received,
+    bankaccnt_name AS post_to,
+    formatDate(cashrcpt_distdate) AS distribution_date,
+    CASE
+      WHEN cashrcpt_usecustdeposit THEN
+        'Customer Deposit'
+      ELSE
+        'Credit Memo'
+    END AS apply_balance_as,
+    salescat_name AS sales_category,
+    cashrcpt_notes AS notes
+  FROM cashrcpt
+    LEFT OUTER JOIN custinfo ON (cust_id=cashrcpt_cust_id)
+    LEFT OUTER JOIN cntct mc ON (custinfo.cust_cntct_id = mc.cntct_id)
+    LEFT OUTER JOIN addr m ON (mc.cntct_addr_id = m.addr_id)
+    LEFT OUTER JOIN curr_symbol ON (curr_id=cashrcpt_curr_id)
+    LEFT OUTER JOIN bankaccnt ON (bankaccnt_id=cashrcpt_bankaccnt_id)
+    LEFT OUTER JOIN salescat ON (salescat_id=cashrcpt_salescat_id);
+       
+GRANT ALL ON TABLE api.cashreceipt TO xtrole;
+COMMENT ON VIEW api.cashreceipt IS '
+This view can be used as an interface to import Cash Receipt data directly  
+into the system.  Required fields will be checked and default values will be 
+populated';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+  ON INSERT TO api.cashreceipt DO INSTEAD
+
+  INSERT INTO cashrcpt (
+    cashrcpt_cust_id,
+    cashrcpt_number,
+    cashrcpt_amount,
+    cashrcpt_fundstype,
+    cashrcpt_docnumber,
+    cashrcpt_bankaccnt_id,
+    cashrcpt_notes,
+    cashrcpt_distdate,
+    cashrcpt_salescat_id,
+    cashrcpt_curr_id,
+    cashrcpt_usecustdeposit
+    )
+  VALUES (
+    getCustId(NEW.customer_number),
+    (SELECT fetchCashRcptNumber() ),
+    COALESCE(NEW.amount_received, 0),
+    CASE
+      WHEN NEW.funds_type='Check' THEN
+        'C'
+      WHEN NEW.funds_type='Certified Check' THEN
+        'T'
+      WHEN NEW.funds_type='Master Card' THEN
+        'M'
+      WHEN NEW.funds_type='Visa' THEN
+        'V'
+      WHEN NEW.funds_type='American Express' THEN
+        'A'
+      WHEN NEW.funds_type='Discover Card' THEN
+        'D'
+      WHEN NEW.funds_type='Other Credit Card' THEN
+        'R'
+      WHEN NEW.funds_type='Cash' THEN
+        'K'
+      WHEN NEW.funds_type='Wire Transfer' THEN
+        'W'
+      ELSE
+        'O'
+    END,
+    COALESCE(NEW.check_document_number, ''),
+    getBankAccntId(NEW.post_to),
+    COALESCE(NEW.notes, ''),
+    CASE
+      WHEN NEW.distribution_date > '' THEN
+        NEW.distribution_date::DATE
+      ELSE
+        now()
+    END,
+    COALESCE(getSalesCatId(NEW.sales_category), -1),
+    getCurrId(NEW.currency),
+    CASE
+      WHEN NEW.apply_balance_as='Customer Deposit' THEN
+        true
+      ELSE
+        false
+    END
+    );
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+  ON UPDATE TO api.cashreceipt DO INSTEAD
+
+  UPDATE cashrcpt SET
+    cashrcpt_amount=NEW.amount_received,
+    cashrcpt_number=NEW.cashreceipt_number,
+    cashrcpt_fundstype=
+      CASE
+        WHEN NEW.funds_type='Check' THEN
+          'C'
+        WHEN NEW.funds_type='Certified Check' THEN
+          'T'
+        WHEN NEW.funds_type='Master Card' THEN
+          'M'
+        WHEN NEW.funds_type='Visa' THEN
+          'V'
+        WHEN NEW.funds_type='American Express' THEN
+          'A'
+        WHEN NEW.funds_type='Discover Card' THEN
+          'D'
+        WHEN NEW.funds_type='Other Credit Card' THEN
+          'R'
+        WHEN NEW.funds_type='Cash' THEN
+          'K'
+        WHEN NEW.funds_type='Wire Transfer' THEN
+          'W'
+        ELSE
+          'O'
+      END,
+    cashrcpt_docnumber=NEW.check_document_number,
+    cashrcpt_bankaccnt_id=getBankAccntId(NEW.post_to),
+    cashrcpt_notes=NEW.notes,
+    cashrcpt_distdate=
+      CASE
+        WHEN NEW.distribution_date > '' THEN
+          NEW.distribution_date::DATE
+        ELSE
+          NULL
+      END,
+    cashrcpt_salescat_id=getSalesCatId(NEW.sales_category),
+    cashrcpt_curr_id=getCurrId(NEW.currency),
+    cashrcpt_usecustdeposit=
+      CASE
+        WHEN NEW.apply_balance_as='Customer Deposit' THEN
+          true
+        ELSE
+          false
+      END
+    WHERE (cashrcpt_id=getCashrcptId(
+                       OLD.customer_number,
+                       CASE
+                         WHEN OLD.funds_type='Check' THEN
+                           'C'
+                         WHEN OLD.funds_type='Certified Check' THEN
+                           'T'
+                         WHEN OLD.funds_type='Master Card' THEN
+                           'M'
+                         WHEN OLD.funds_type='Visa' THEN
+                           'V'
+                         WHEN OLD.funds_type='American Express' THEN
+                           'A'
+                         WHEN OLD.funds_type='Discover Card' THEN
+                           'D'
+                         WHEN OLD.funds_type='Other Credit Card' THEN
+                           'R'
+                         WHEN OLD.funds_type='Cash' THEN
+                           'K'
+                         WHEN OLD.funds_type='Wire Transfer' THEN
+                           'W'
+                         ELSE
+                           'O'
+                       END,
+                       OLD.check_document_number) );
+
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+  ON DELETE TO api.cashreceipt DO INSTEAD
+       
+    SELECT deleteCashrcpt(cashrcpt_id)
+       FROM cashrcpt
+    WHERE (cashrcpt_id=getCashrcptId(
+                       OLD.customer_number,
+                       CASE
+                         WHEN OLD.funds_type='Check' THEN
+                           'C'
+                         WHEN OLD.funds_type='Certified Check' THEN
+                           'T'
+                         WHEN OLD.funds_type='Master Card' THEN
+                           'M'
+                         WHEN OLD.funds_type='Visa' THEN
+                           'V'
+                         WHEN OLD.funds_type='American Express' THEN
+                           'A'
+                         WHEN OLD.funds_type='Discover Card' THEN
+                           'D'
+                         WHEN OLD.funds_type='Other Credit Card' THEN
+                           'R'
+                         WHEN OLD.funds_type='Cash' THEN
+                           'K'
+                         WHEN OLD.funds_type='Wire Transfer' THEN
+                           'W'
+                         ELSE
+                           'O'
+                       END,
+                       OLD.check_document_number) );
diff --git a/foundation-database/api/views/cashreceiptapply.sql b/foundation-database/api/views/cashreceiptapply.sql
new file mode 100644 (file)
index 0000000..08b05c5
--- /dev/null
@@ -0,0 +1,122 @@
+SELECT dropIfExists('VIEW', 'cashreceiptapply', 'api');
+CREATE OR REPLACE VIEW api.cashreceiptapply AS
+  SELECT
+    cust_number::VARCHAR AS customer_number,
+    CASE WHEN cashrcpt_fundstype='C' THEN 'Check'::VARCHAR
+         WHEN cashrcpt_fundstype='T' THEN 'Certified Check'::VARCHAR
+         WHEN cashrcpt_fundstype='M' THEN 'Master Card'::VARCHAR
+         WHEN cashrcpt_fundstype='V' THEN 'Visa'::VARCHAR
+         WHEN cashrcpt_fundstype='A' THEN 'American Express'::VARCHAR
+         WHEN cashrcpt_fundstype='D' THEN 'Discover Card'::VARCHAR
+         WHEN cashrcpt_fundstype='R' THEN 'Other Credit Card'::VARCHAR
+         WHEN cashrcpt_fundstype='K' THEN 'Cash'::VARCHAR
+         WHEN cashrcpt_fundstype='W' THEN 'Wire Transfer'::VARCHAR
+         WHEN cashrcpt_fundstype='O' THEN 'Other'::VARCHAR
+    END AS funds_type,
+    cashrcpt_docnumber::VARCHAR AS check_document_number,
+    aropen_doctype::VARCHAR AS doc_type,
+    aropen_docnumber::VARCHAR AS doc_number,
+    cust_name AS customer_name,
+    addr_line1 AS customer_address,
+    formatDate(aropen_docdate) AS doc_date,
+    formatDate(aropen_duedate) AS due_date,
+    curr_abbr AS currency,
+    aropen_amount AS open_amount,
+    cashrcptitem_amount AS amount_to_apply,
+    cashrcptitem_discount
+  FROM cashrcptitem
+    LEFT OUTER JOIN cashrcpt ON (cashrcpt_id=cashrcptitem_cashrcpt_id)
+    LEFT OUTER JOIN custinfo ON (cust_id=cashrcpt_cust_id)
+    LEFT OUTER JOIN cntct mc ON (custinfo.cust_cntct_id = mc.cntct_id)
+    LEFT OUTER JOIN addr m ON (mc.cntct_addr_id = m.addr_id)
+    LEFT OUTER JOIN curr_symbol ON (curr_id=cashrcpt_curr_id)
+    LEFT OUTER JOIN aropen ON (aropen_id=cashrcptitem_aropen_id);
+       
+GRANT ALL ON TABLE api.cashreceiptapply TO xtrole;
+COMMENT ON VIEW api.cashreceiptapply IS '
+This view can be used as an interface to import Cash Receipt Application data directly  
+into the system.  Required fields will be checked and default values will be 
+populated';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+  ON INSERT TO api.cashreceiptapply DO INSTEAD
+
+  INSERT INTO cashrcptitem (
+    cashrcptitem_cashrcpt_id,
+    cashrcptitem_aropen_id,
+    cashrcptitem_amount,
+    cashrcptitem_discount
+    )
+  VALUES (
+    getCashrcptId(NEW.customer_number,
+                  CASE
+                    WHEN NEW.funds_type='Check' THEN 'C'
+                    WHEN NEW.funds_type='Certified Check' THEN 'T'
+                    WHEN NEW.funds_type='Master Card' THEN 'M'
+                    WHEN NEW.funds_type='Visa' THEN 'V'
+                    WHEN NEW.funds_type='American Express' THEN 'A'
+                    WHEN NEW.funds_type='Discover Card' THEN 'D'
+                    WHEN NEW.funds_type='Other Credit Card' THEN 'R'
+                    WHEN NEW.funds_type='Cash' THEN 'K'
+                    WHEN NEW.funds_type='Wire Transfer' THEN 'W'
+                    ELSE 'O'
+                  END,
+                  NEW.check_document_number),
+    getAropenId(NEW.customer_number,
+                NEW.doc_type,
+                NEW.doc_number),
+    COALESCE(NEW.amount_to_apply, 0),
+    COALESCE(NEW.cashrcptitem_discount, 0)
+    );
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+  ON UPDATE TO api.cashreceiptapply DO INSTEAD
+
+  UPDATE cashrcptitem SET
+    cashrcptitem_amount=NEW.amount_to_apply,
+    cashrcptitem_discount=NEW.cashrcptitem_discount
+    WHERE ( (cashrcptitem_cashrcpt_id=getCashrcptId(
+                       OLD.customer_number,
+                       CASE
+                         WHEN OLD.funds_type='Check' THEN 'C'
+                         WHEN OLD.funds_type='Certified Check' THEN 'T'
+                         WHEN OLD.funds_type='Master Card' THEN 'M'
+                         WHEN OLD.funds_type='Visa' THEN 'V'
+                         WHEN OLD.funds_type='American Express' THEN 'A'
+                         WHEN OLD.funds_type='Discover Card' THEN 'D'
+                         WHEN OLD.funds_type='Other Credit Card' THEN 'R'
+                         WHEN OLD.funds_type='Cash' THEN 'K'
+                         WHEN OLD.funds_type='Wire Transfer' THEN 'W'
+                         ELSE 'O'
+                       END,
+                       OLD.check_document_number))
+      AND   (cashrcptitem_aropen_id=getAropenId(
+                       OLD.customer_number,
+                       OLD.doc_type,
+                       OLD.doc_number)) );
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+  ON DELETE TO api.cashreceiptapply DO INSTEAD
+       
+    DELETE FROM cashrcptitem
+    WHERE ( (cashrcptitem_cashrcpt_id=getCashrcptId(
+                       OLD.customer_number,
+                       CASE
+                         WHEN OLD.funds_type='Check' THEN 'C'
+                         WHEN OLD.funds_type='Certified Check' THEN 'T'
+                         WHEN OLD.funds_type='Master Card' THEN 'M'
+                         WHEN OLD.funds_type='Visa' THEN 'V'
+                         WHEN OLD.funds_type='American Express' THEN 'A'
+                         WHEN OLD.funds_type='Discover Card' THEN 'D'
+                         WHEN OLD.funds_type='Other Credit Card' THEN 'R'
+                         WHEN OLD.funds_type='Cash' THEN 'K'
+                         WHEN OLD.funds_type='Wire Transfer' THEN 'W'
+                         ELSE 'O'
+                       END,
+                       OLD.check_document_number))
+      AND   (cashrcptitem_aropen_id=getAropenId(
+                       OLD.customer_number,
+                       OLD.doc_type,
+                       OLD.doc_number)) );
diff --git a/foundation-database/api/views/cashreceiptapplymisc.sql b/foundation-database/api/views/cashreceiptapplymisc.sql
new file mode 100644 (file)
index 0000000..5984f49
--- /dev/null
@@ -0,0 +1,153 @@
+SELECT dropIfExists('VIEW', 'cashreceiptapplymisc', 'api');
+CREATE OR REPLACE VIEW api.cashreceiptapplymisc AS
+  SELECT
+    cust_number::VARCHAR AS customer_number,
+    CASE
+      WHEN cashrcpt_fundstype='C' THEN
+        'Check'::VARCHAR
+      WHEN cashrcpt_fundstype='T' THEN
+        'Certified Check'::VARCHAR
+      WHEN cashrcpt_fundstype='M' THEN
+        'Master Card'::VARCHAR
+      WHEN cashrcpt_fundstype='V' THEN
+        'Visa'::VARCHAR
+      WHEN cashrcpt_fundstype='A' THEN
+        'American Express'::VARCHAR
+      WHEN cashrcpt_fundstype='D' THEN
+        'Discover Card'::VARCHAR
+      WHEN cashrcpt_fundstype='R' THEN
+        'Other Credit Card'::VARCHAR
+      WHEN cashrcpt_fundstype='K' THEN
+        'Cash'::VARCHAR
+      WHEN cashrcpt_fundstype='W' THEN
+        'Wire Transfer'::VARCHAR
+      WHEN cashrcpt_fundstype='O' THEN
+        'Other'::VARCHAR
+    END AS funds_type,
+    cashrcpt_docnumber::VARCHAR AS check_document_number,
+    formatGLAccount(accnt_id)::VARCHAR AS account,
+    cust_name AS customer_name,
+    addr_line1 AS customer_address,
+    accnt_descrip AS account_description,
+    curr_abbr AS currency,
+    cashrcptmisc_amount AS amount_to_distribute,
+    cashrcptmisc_notes AS notes
+  FROM cashrcptmisc
+    LEFT OUTER JOIN cashrcpt ON (cashrcpt_id=cashrcptmisc_cashrcpt_id)
+    LEFT OUTER JOIN custinfo ON (cust_id=cashrcpt_cust_id)
+    LEFT OUTER JOIN cntct mc ON (custinfo.cust_cntct_id = mc.cntct_id)
+    LEFT OUTER JOIN addr m ON (mc.cntct_addr_id = m.addr_id)
+    LEFT OUTER JOIN curr_symbol ON (curr_id=cashrcpt_curr_id)
+    LEFT OUTER JOIN accnt ON (accnt_id=cashrcptmisc_accnt_id);
+       
+GRANT ALL ON TABLE api.cashreceiptapplymisc TO xtrole;
+COMMENT ON VIEW api.cashreceiptapplymisc IS '
+This view can be used as an interface to import Cash Receipt Miscellaneous Application
+data directly into the system.  Required fields will be checked and default values
+will be populated';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+  ON INSERT TO api.cashreceiptapplymisc DO INSTEAD
+
+  INSERT INTO cashrcptmisc (
+    cashrcptmisc_cashrcpt_id,
+    cashrcptmisc_accnt_id,
+    cashrcptmisc_amount,
+    cashrcptmisc_notes
+    )
+  VALUES (
+    getCashrcptId(NEW.customer_number,
+                  CASE
+                    WHEN NEW.funds_type='Check' THEN
+                      'C'
+                    WHEN NEW.funds_type='Certified Check' THEN
+                      'T'
+                    WHEN NEW.funds_type='Master Card' THEN
+                      'M'
+                    WHEN NEW.funds_type='Visa' THEN
+                      'V'
+                    WHEN NEW.funds_type='American Express' THEN
+                      'A'
+                    WHEN NEW.funds_type='Discover Card' THEN
+                      'D'
+                    WHEN NEW.funds_type='Other Credit Card' THEN
+                      'R'
+                    WHEN NEW.funds_type='Cash' THEN
+                      'K'
+                    WHEN NEW.funds_type='Wire Transfer' THEN
+                      'W'
+                    ELSE
+                      'O'
+                  END,
+                  NEW.check_document_number),
+    getGlAccntId(NEW.account),
+    COALESCE(NEW.amount_to_distribute, 0),
+    COALESCE(NEW.notes, '')
+    );
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+  ON UPDATE TO api.cashreceiptapplymisc DO INSTEAD
+
+  UPDATE cashrcptmisc SET
+    cashrcptmisc_accnt_id=getGlAccntId(NEW.account),
+    cashrcptmisc_amount=NEW.amount_to_distribute,
+    cashrcptmisc_notes=NEW.notes
+    WHERE ( (cashrcptmisc_cashrcpt_id=getCashrcptId(
+                       OLD.customer_number,
+                       CASE
+                         WHEN OLD.funds_type='Check' THEN
+                           'C'
+                         WHEN OLD.funds_type='Certified Check' THEN
+                           'T'
+                         WHEN OLD.funds_type='Master Card' THEN
+                           'M'
+                         WHEN OLD.funds_type='Visa' THEN
+                           'V'
+                         WHEN OLD.funds_type='American Express' THEN
+                           'A'
+                         WHEN OLD.funds_type='Discover Card' THEN
+                           'D'
+                         WHEN OLD.funds_type='Other Credit Card' THEN
+                           'R'
+                         WHEN OLD.funds_type='Cash' THEN
+                           'K'
+                         WHEN OLD.funds_type='Wire Transfer' THEN
+                           'W'
+                         ELSE
+                           'O'
+                       END,
+                       OLD.check_document_number))
+      AND   (cashrcptmisc_accnt_id=getGlAccntId(OLD.account)) );
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+  ON DELETE TO api.cashreceiptapplymisc DO INSTEAD
+       
+    DELETE FROM cashrcptmisc
+    WHERE ( (cashrcptmisc_cashrcpt_id=getCashrcptId(
+                       OLD.customer_number,
+                       CASE
+                         WHEN OLD.funds_type='Check' THEN
+                           'C'
+                         WHEN OLD.funds_type='Certified Check' THEN
+                           'T'
+                         WHEN OLD.funds_type='Master Card' THEN
+                           'M'
+                         WHEN OLD.funds_type='Visa' THEN
+                           'V'
+                         WHEN OLD.funds_type='American Express' THEN
+                           'A'
+                         WHEN OLD.funds_type='Discover Card' THEN
+                           'D'
+                         WHEN OLD.funds_type='Other Credit Card' THEN
+                           'R'
+                         WHEN OLD.funds_type='Cash' THEN
+                           'K'
+                         WHEN OLD.funds_type='Wire Transfer' THEN
+                           'W'
+                         ELSE
+                           'O'
+                       END,
+                       OLD.check_document_number))
+      AND   (cashrcptmisc_accnt_id=getGlAccntId(OLD.account)) );
diff --git a/foundation-database/api/views/contact.sql b/foundation-database/api/views/contact.sql
new file mode 100644 (file)
index 0000000..1c08fe3
--- /dev/null
@@ -0,0 +1,116 @@
+  --Contact View
+
+SELECT dropIfExists('VIEW', 'contact', 'api');
+  CREATE OR REPLACE VIEW api.contact AS
+  SELECT 
+    cntct_number::varchar AS contact_number,
+    cntct_honorific AS honorific,
+    cntct_first_name AS first,
+    cntct_middle AS middle,
+    cntct_last_name AS last,
+    cntct_suffix AS suffix,
+    cntct_initials AS initials,
+    crmacct_number AS crm_account,
+    cntct_active AS active,
+    cntct_title AS job_title,
+    cntct_phone AS voice,
+    cntct_phone2 AS alternate,
+    cntct_fax AS fax,
+    cntct_email AS email,
+    cntct_webaddr AS web,
+    ''::TEXT AS contact_change, 
+    addr_number AS address_number,
+    addr_line1 AS address1,
+    addr_line2 AS address2,
+    addr_line3 AS address3,
+    addr_city AS city,
+    addr_state AS state,
+    addr_postalcode AS postal_code,
+    addr_country AS country,
+    cntct_notes AS notes, 
+    ''::TEXT AS address_change
+  FROM
+    cntct
+      LEFT OUTER JOIN addr ON (cntct_addr_id=addr_id)
+      LEFT OUTER JOIN crmacct ON (cntct_crmacct_id=crmacct_id);
+
+GRANT ALL ON TABLE api.contact TO xtrole;
+COMMENT ON VIEW api.contact IS 'Contact';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.contact DO INSTEAD
+
+SELECT saveCntct(
+         NULL,
+          NEW.contact_number,
+          getCrmAcctid(NEW.crm_account),
+          saveAddr(
+            getAddrId(NEW.address_number),
+            NEW.address_number,
+            NEW.address1,
+            NEW.address2,
+            NEW.address3,
+            NEW.city,
+            NEW.state,
+            NEW.postal_code,
+            NEW.country,
+            NEW.address_change),
+          NEW.honorific,
+          NEW.first,
+          NEW.middle,
+          NEW.last,
+          NEW.suffix,
+          NEW.initials,
+          COALESCE(NEW.active,TRUE),
+          NEW.voice,
+          NEW.alternate,
+          NEW.fax,
+          NEW.email,
+          NEW.web,
+          NEW.notes,
+          NEW.job_title,
+          NEW.contact_change
+          );
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.contact DO INSTEAD
+
+SELECT saveCntct(
+          getCntctId(NEW.contact_number),
+          NEW.contact_number,
+          getCrmAcctid(NEW.crm_account),
+          saveAddr(
+            getAddrId(NEW.address_number),
+            NEW.address_number,
+            NEW.address1,
+            NEW.address2,
+            NEW.address3,
+            NEW.city,
+            NEW.state,
+            NEW.postal_code,
+            NEW.country,
+            NEW.address_change),
+          NEW.honorific,
+          NEW.first,
+          NEW.middle,
+          NEW.last,
+          NEW.suffix,
+          NEW.initials,
+          NEW.active,
+          NEW.voice,
+          NEW.alternate,
+          NEW.fax,
+          NEW.email,
+          NEW.web,
+          NEW.notes,
+          NEW.job_title,
+          NEW.contact_change
+          );
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.contact DO INSTEAD
+
+DELETE FROM cntct WHERE (cntct_number=OLD.contact_number);
diff --git a/foundation-database/api/views/contactchar.sql b/foundation-database/api/views/contactchar.sql
new file mode 100644 (file)
index 0000000..e837ff8
--- /dev/null
@@ -0,0 +1,52 @@
+-- Contact Characteristic
+
+SELECT dropIfExists('VIEW', 'contactchar', 'api');
+CREATE VIEW api.contactchar
+AS 
+   SELECT 
+     cntct_number AS contact_number,
+     char_name::varchar AS characteristic,
+     charass_value AS value
+   FROM cntct, char, charass
+   WHERE (('CNTCT'=charass_target_type)
+   AND (cntct_id=charass_target_id)
+   AND (charass_char_id=char_id));
+
+GRANT ALL ON TABLE api.contactchar TO xtrole;
+COMMENT ON VIEW api.contactchar IS 'Contact Characteristics';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.contactchar DO INSTEAD
+
+  INSERT INTO charass (
+    charass_target_type,
+    charass_target_id,
+    charass_char_id,
+    charass_value,
+    charass_default
+    )
+  VALUES (
+    'CNTCT',
+    getCntctId(NEW.contact_number),
+    getCharId(NEW.characteristic,'CNTCT'),
+    NEW.value,
+    false);
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.contactchar DO INSTEAD
+
+  UPDATE charass SET
+    charass_value=NEW.value
+  WHERE ((charass_target_type='CNTCT')
+  AND (charass_target_id=getCntctId(OLD.contact_number))
+  AND (charass_char_id=getCharId(OLD.characteristic,'CNTCT')));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.contactchar DO INSTEAD
+
+  DELETE FROM charass
+  WHERE ((charass_target_type='CNTCT')
+  AND (charass_target_id=getCntctId(OLD.contact_number))
+  AND (charass_char_id=getCharId(OLD.characteristic,'CNTCT')));
diff --git a/foundation-database/api/views/contactcomment.sql b/foundation-database/api/views/contactcomment.sql
new file mode 100644 (file)
index 0000000..34fef59
--- /dev/null
@@ -0,0 +1,45 @@
+-- Contact Comment
+
+DROP VIEW api.contactcomment;
+CREATE VIEW api.contactcomment
+AS 
+   SELECT 
+     cntct_number AS contact_number,
+     cmnttype_name AS type,
+     comment_date AS date,
+     comment_user AS username,
+     comment_text AS text
+   FROM cntct, cmnttype, comment
+   WHERE ((comment_source='T')
+   AND (comment_source_id=cntct_id)
+   AND (comment_cmnttype_id=cmnttype_id));
+
+GRANT ALL ON TABLE api.contactcomment TO xtrole;
+COMMENT ON VIEW api.contactcomment IS 'Contact Comment';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.contactcomment DO INSTEAD
+
+  INSERT INTO comment (
+    comment_date,
+    comment_source,
+    comment_source_id,
+    comment_user,
+    comment_cmnttype_id,
+    comment_text
+    )
+  VALUES (
+    COALESCE(NEW.date,now()),
+    'T',
+    getCntctId(NEW.contact_number),
+    COALESCE(NEW.username,getEffectiveXtUser()),
+    getCmntTypeId(NEW.type),
+    NEW.text);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.contactcomment DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.contactcomment DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/creditmemo.sql b/foundation-database/api/views/creditmemo.sql
new file mode 100644 (file)
index 0000000..2fc29a8
--- /dev/null
@@ -0,0 +1,219 @@
+CREATE OR REPLACE RULE "_INSERT" AS ON INSERT TO api.creditmemo DO INSTEAD NOTHING;
+SELECT dropIfExists('FUNCTION', 'insertCreditMemo(api.creditmemo)');
+
+SELECT dropIfExists('VIEW', 'creditmemo', 'api');
+CREATE OR REPLACE VIEW api.creditmemo AS
+  SELECT cmhead_number AS memo_number,
+         CASE
+           WHEN (cmhead_invcnumber = '-1') THEN ''
+           ELSE cmhead_invcnumber
+         END AS apply_to,
+         cmhead_docdate AS memo_date,
+         CASE
+           WHEN (cmhead_posted) THEN 'Posted'
+           ELSE 'Unposted'
+         END AS status,
+         salesrep_number AS sales_rep,
+         cmhead_commission AS commission,
+         COALESCE(taxzone_code, 'None') AS tax_zone,
+         COALESCE(rsncode_code, 'None') AS reason_code,
+         cmhead_hold AS on_hold,
+         cust_number AS customer_number,
+         cmhead_billtoname AS billto_name,
+         cmhead_billtoaddress1 AS billto_address1,
+         cmhead_billtoaddress2 AS billto_address2,
+         cmhead_billtoaddress3 AS billto_address3,
+         cmhead_billtocity AS billto_city,
+         cmhead_billtostate AS billto_state,
+         cmhead_billtozip AS billto_postal_code,
+         cmhead_billtocountry AS billto_country,
+         shipto_num AS shipto_number,
+         cmhead_shipto_name AS shipto_name,
+         cmhead_shipto_address1 AS shipto_address1,
+         cmhead_shipto_address2 AS shipto_address2,
+         cmhead_shipto_address3 AS shipto_address3,
+         cmhead_shipto_city AS shipto_city,
+         cmhead_shipto_state AS shipto_state,
+         cmhead_shipto_zipcode AS shipto_postal_code,
+         cmhead_shipto_country AS shipto_country,
+         cmhead_custponumber AS customer_po_number,
+         cmhead_comments AS notes,
+         curr.curr_abbr AS currency,
+         cmhead_misc_descrip AS misc_charge_description,
+         cmhead_misc AS misc_charge_amount,
+         CASE
+           WHEN cmhead_misc_accnt_id = -1 THEN ''
+           ELSE formatglaccount(cmhead_misc_accnt_id)
+         END AS misc_charge_credit_account,
+         cmhead_freight AS freight
+       FROM cmhead
+         LEFT OUTER JOIN custinfo ON (cust_id=cmhead_cust_id)
+         LEFT OUTER JOIN shiptoinfo ON (shipto_id=cmhead_shipto_id)
+         LEFT OUTER JOIN curr_symbol AS curr ON (curr.curr_id=cmhead_curr_id)
+         LEFT OUTER JOIN salesrep ON (salesrep_id=cmhead_salesrep_id)
+         LEFT OUTER JOIN taxzone ON (taxzone_id=cmhead_taxzone_id)
+         LEFT OUTER JOIN rsncode ON (rsncode_id=cmhead_rsncode_id);
+      
+GRANT ALL ON TABLE api.creditmemo TO xtrole;
+COMMENT ON VIEW api.creditmemo IS 'Credit Memo Header';
+
+
+CREATE OR REPLACE FUNCTION insertCreditMemo(api.creditmemo) RETURNS boolean AS
+$insertCreditMemo$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+       pNew ALIAS FOR $1;
+BEGIN
+       -- NOTE: (SELECT getCustId(...)) seems redundant, but it actually produces
+       -- a HUGE performance increase because it makes the Postgres query planner
+       -- use an index scan rather than an sequential table scan on cust_id
+  INSERT INTO cmhead (
+               cmhead_number,
+               cmhead_posted,
+               cmhead_invcnumber,
+                cmhead_custponumber,
+               cmhead_cust_id,
+               cmhead_docdate,
+               cmhead_shipto_id,
+               cmhead_shipto_name,
+               cmhead_shipto_address1,
+               cmhead_shipto_address2,
+               cmhead_shipto_address3,
+               cmhead_shipto_city,
+               cmhead_shipto_state,
+               cmhead_shipto_zipcode,
+               cmhead_shipto_country,
+               cmhead_salesrep_id,
+               cmhead_freight,
+               cmhead_misc,
+               cmhead_comments,
+               cmhead_printed,
+               cmhead_billtoname,
+               cmhead_billtoaddress1,
+               cmhead_billtoaddress2,
+               cmhead_billtoaddress3,
+               cmhead_billtocity,
+               cmhead_billtostate,
+               cmhead_billtozip,
+               cmhead_billtocountry,
+               cmhead_hold,
+               cmhead_commission,
+               cmhead_misc_accnt_id,
+               cmhead_misc_descrip,
+               cmhead_rsncode_id,
+               cmhead_curr_id,
+               cmhead_taxzone_id,
+                cmhead_gldistdate,
+                cmhead_rahead_id
+               )
+        SELECT
+               (CASE -- use a case here so we don't unnecessarily fetch a new CM number
+                       WHEN pNew.memo_number IS NULL THEN fetchCMNumber()
+                       ELSE pNew.memo_number
+               END),
+               FALSE, -- posted
+               pNew.apply_to,
+               pNew.customer_po_number,
+               cust_id,
+               COALESCE(pNew.memo_date, CURRENT_DATE),
+               COALESCE(shipto_id,-1),
+               pNew.shipto_name,
+               pNew.shipto_address1,
+               pNew.shipto_address2,
+               pNew.shipto_address3,
+               pNew.shipto_city,
+               pNew.shipto_state,
+               pNew.shipto_postal_code,
+               pNew.shipto_country,
+               COALESCE(getSalesRepId(pNew.sales_rep),shipto_salesrep_id,cust_salesrep_id),
+               COALESCE(pNew.freight, 0),
+               COALESCE(pNew.misc_charge_amount, 0),
+               pNew.notes,
+               FALSE, -- printed
+               COALESCE(pNew.billto_name, invchead_billto_name, cust_name),
+               COALESCE(pNew.billto_address1, invchead_billto_address1, addr_line1),
+               COALESCE(pNew.billto_address2, invchead_billto_address2, addr_line2),
+               COALESCE(pNew.billto_address3, invchead_billto_address3, addr_line3),
+               COALESCE(pNew.billto_city, invchead_billto_city, addr_city),
+               COALESCE(pNew.billto_state, invchead_billto_state, addr_state),
+               COALESCE(pNew.billto_postal_code, invchead_billto_zipcode, addr_postalcode),
+               COALESCE(pNew.billto_country, invchead_billto_country, addr_country),
+               COALESCE(pNew.on_hold, FALSE),
+               COALESCE(pNew.commission, 0),
+               COALESCE(getGlAccntId(pNew.misc_charge_credit_account),-1),
+               pNew.misc_charge_description,
+               (SELECT rsncode_id FROM rsncode WHERE rsncode_code = pNew.reason_code),
+               COALESCE(getCurrId(pNew.currency),cust_curr_id,basecurrid()),
+                CASE WHEN pNew.tax_zone = 'None' THEN NULL
+                     ELSE COALESCE(getTaxZoneID(pNew.tax_zone),cust_taxzone_id)
+                END,
+                NULL,
+                NULL
+       FROM custinfo
+               LEFT OUTER JOIN shiptoinfo ON (shipto_id=(SELECT CASE
+                       WHEN getShiptoId(pNew.customer_number,pNew.shipto_number) IS NOT NULL
+                               THEN getShiptoId(pNew.customer_number,pNew.shipto_number)
+                       ELSE (SELECT shipto_id FROM shiptoinfo WHERE shipto_cust_id=cust_id AND shipto_default)
+               END))
+                LEFT OUTER JOIN invchead ON (invchead_id=getInvcheadId(pNEW.apply_to))
+                LEFT OUTER JOIN cntct ON (cntct_id=cust_cntct_id)
+                LEFT OUTER JOIN addr ON (addr_id=cntct_addr_id)
+       WHERE cust_id = (CASE
+               WHEN pNew.customer_number IS NOT NULL THEN (SELECT getCustId(pNew.customer_number))
+               ELSE (SELECT invchead_cust_id FROM invchead WHERE invchead_invcnumber = pNew.apply_to)
+       END);
+       RETURN TRUE;
+END;
+$insertCreditMemo$ LANGUAGE 'plpgsql';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+       ON INSERT TO api.creditmemo DO INSTEAD
+               SELECT insertCreditMemo(NEW);
+
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+       ON UPDATE TO api.creditmemo DO INSTEAD
+       UPDATE cmhead SET
+               cmhead_custponumber=NEW.customer_po_number,
+               cmhead_docdate=NEW.memo_date,
+               cmhead_shipto_id=COALESCE(getShiptoId(NEW.customer_number,NEW.shipto_number),-1),
+               cmhead_shipto_name=NEW.shipto_name,
+               cmhead_shipto_address1=NEW.shipto_address1,
+               cmhead_shipto_address2=NEW.shipto_address2,
+               cmhead_shipto_address3=NEW.shipto_address3,
+               cmhead_shipto_city=NEW.shipto_city,
+               cmhead_shipto_state=NEW.shipto_state,
+               cmhead_shipto_zipcode=NEW.shipto_postal_code,
+               cmhead_shipto_country=NEW.shipto_country,
+               cmhead_salesrep_id=getSalesRepId(NEW.sales_rep),
+               cmhead_freight=COALESCE(NEW.freight,0),
+               cmhead_misc=COALESCE(NEW.misc_charge_amount,0),
+               cmhead_comments=NEW.notes,
+               cmhead_billtoname=NEW.billto_name,
+               cmhead_billtoaddress1=NEW.billto_address1,
+               cmhead_billtoaddress2=NEW.billto_address2,
+               cmhead_billtoaddress3=NEW.billto_address3,
+               cmhead_billtocity=NEW.billto_city,
+               cmhead_billtostate=NEW.billto_state,
+               cmhead_billtozip=NEW.billto_postal_code,
+               cmhead_billtocountry=NEW.billto_country,
+               cmhead_hold=COALESCE(NEW.on_hold,FALSE),
+               cmhead_commission=COALESCE(NEW.commission,0),
+               cmhead_misc_accnt_id=COALESCE(getGlAccntId(NEW.misc_charge_credit_account),-1),
+               cmhead_misc_descrip=NEW.misc_charge_description,
+               cmhead_rsncode_id=(SELECT rsncode_id FROM rsncode WHERE rsncode_code = NEW.reason_code),
+               cmhead_curr_id=COALESCE(getCurrId(NEW.currency),-1),
+               cmhead_taxzone_id=getTaxZoneId(NULLIF(NEW.tax_zone, 'None'))
+       WHERE (cmhead_number=OLD.memo_number)
+               AND (cmhead_posted = FALSE);
+
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+       ON DELETE TO api.creditmemo DO INSTEAD
+       
+       SELECT deleteCreditMemo(cmhead_id)
+       FROM cmhead
+       WHERE cmhead_number = OLD.memo_number AND cmhead_posted = FALSE;
diff --git a/foundation-database/api/views/creditmemoline.sql b/foundation-database/api/views/creditmemoline.sql
new file mode 100644 (file)
index 0000000..3684c75
--- /dev/null
@@ -0,0 +1,164 @@
+CREATE OR REPLACE RULE "_INSERT" AS
+  ON INSERT TO api.creditmemoline DO INSTEAD NOTHING;
+CREATE OR REPLACE RULE "_UPDATE" AS 
+  ON UPDATE TO api.creditmemoline DO INSTEAD NOTHING;
+SELECT dropIfExists('FUNCTION', 'insertCreditMemoLine(api.creditmemoline)');
+SELECT dropIfExists('FUNCTION', 'updateCreditMemoLine(api.creditmemoline, api.creditmemoline)');
+SELECT dropIfExists('VIEW', 'creditmemoline', 'api');
+CREATE OR REPLACE VIEW api.creditmemoline AS
+  SELECT cmhead_number AS memo_number,
+         cmitem_linenumber AS line_number,
+         item_number AS item_number,
+         warehous_code AS recv_site,
+         rsncode_code AS reason_code,
+         cmitem_qtyreturned AS qty_returned,
+         cmitem_qtycredit AS qty_to_credit,
+         COALESCE(qty_uom.uom_name, 'None') AS qty_uom,
+         cmitem_unitprice AS net_unit_price,
+         COALESCE(price_uom.uom_name, 'None') AS price_uom,
+         COALESCE(taxtype_name, 'None') AS tax_type,
+         cmitem_comments AS notes
+  FROM cmitem LEFT OUTER JOIN cmhead ON (cmitem_cmhead_id=cmhead_id)
+              LEFT OUTER JOIN itemsite ON (itemsite_id=cmitem_itemsite_id)
+              LEFT OUTER JOIN item ON (item_id=itemsite_item_id)
+              LEFT OUTER JOIN whsinfo ON (warehous_id=itemsite_warehous_id)
+              LEFT OUTER JOIN rsncode ON (rsncode_id=cmitem_rsncode_id)
+              LEFT OUTER JOIN taxtype ON (taxtype_id=cmitem_taxtype_id)
+              LEFT OUTER JOIN uom AS qty_uom ON (qty_uom.uom_id=cmitem_qty_uom_id)
+              LEFT OUTER JOIN uom AS price_uom ON (price_uom.uom_id=cmitem_price_uom_id);
+       
+GRANT ALL ON TABLE api.creditmemoline TO xtrole;
+COMMENT ON VIEW api.creditmemoline IS 'Credit Memo Line';
+
+
+CREATE OR REPLACE FUNCTION insertcreditmemoline(api.creditmemoline) RETURNS boolean AS
+$insertcreditmemoline$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  pNew ALIAS FOR $1;
+  _check INTEGER;
+  _r RECORD;
+
+BEGIN
+  SELECT cmhead_id INTO _check
+  FROM cmhead
+  WHERE (cmhead_id=getCmheadId(pNew.memo_number, FALSE));
+  IF (NOT FOUND) THEN
+    RAISE EXCEPTION 'Credit Memo # % not found', pNew.memo_number;
+  END IF;
+
+  INSERT INTO cmitem ( cmitem_cmhead_id,
+                       cmitem_linenumber,
+                       cmitem_itemsite_id,
+                       cmitem_qtycredit,
+                       cmitem_qtyreturned,
+                       cmitem_unitprice,
+                       cmitem_comments,
+                       cmitem_rsncode_id,
+                       cmitem_taxtype_id,
+                       cmitem_qty_uom_id,
+                       cmitem_qty_invuomratio,
+                       cmitem_price_uom_id,
+                       cmitem_price_invuomratio        )
+  SELECT cmhead_id,
+         COALESCE(pNew.line_number,
+                  (SELECT (COALESCE(MAX(cmitem_linenumber), 0) + 1)
+                   FROM cmitem WHERE (cmitem_cmhead_id=cmhead_id))),
+         COALESCE(itemsite_id, -1),
+         COALESCE(pNew.qty_to_credit, 0),
+         COALESCE(pNew.qty_returned, 0),
+         COALESCE(pNew.net_unit_price, 0),
+         pNew.notes,
+         getRsnId(pNew.reason_code),
+         taxtype_id,
+         COALESCE(getUomId(pNew.qty_uom), item_inv_uom_id),
+         CASE
+           WHEN item_id IS NOT NULL THEN itemuomtouomratio(item_id, COALESCE(getUomId(pNew.qty_uom),item_inv_uom_id),item_inv_uom_id)
+           ELSE 1
+         END,
+         COALESCE(getUomId(pNew.price_uom),item_price_uom_id),
+         CASE
+           WHEN item_id IS NOT NULL THEN itemuomtouomratio(item_id, COALESCE(getUomId(pNew.price_uom),item_price_uom_id),item_price_uom_id)
+           ELSE 1
+        END
+  FROM cmhead LEFT OUTER JOIN item ON (item_id=getItemId(pNew.item_number))
+              LEFT OUTER JOIN itemsite ON (itemsite_item_id=item_id AND itemsite_warehous_id=getWarehousId(pNew.recv_site, 'ALL'))
+              LEFT OUTER JOIN taxtype ON (taxtype_id=CASE WHEN pNew.tax_type IS NULL THEN getItemTaxType(item_id,cmhead_taxzone_id)
+                                                          WHEN pNew.tax_type = 'None' THEN NULL
+                                                          ELSE getTaxTypeId(pNew.tax_type)
+                                                     END)
+  WHERE (cmhead_id=getCmheadId(pNew.memo_number, FALSE));
+
+  RETURN TRUE;
+END;
+$insertcreditmemoline$ LANGUAGE 'plpgsql';
+
+
+CREATE OR REPLACE FUNCTION updatecreditmemoline(api.creditmemoline, api.creditmemoline) RETURNS boolean AS
+$updatecreditmemoline$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  pNew ALIAS FOR $1;
+  pOld ALIAS FOR $2;
+  _check INTEGER;
+  _r RECORD;
+
+BEGIN
+  SELECT cmitem_id INTO _check
+  FROM cmitem
+  WHERE ( (cmitem_cmhead_id=getCmheadId(pOld.memo_number, FALSE)) AND (cmitem_linenumber=pOld.line_number) );
+  IF (NOT FOUND) THEN
+    RAISE EXCEPTION 'Credit Memo # % Line Number # not found', pOld.memo_number, pOld.line_number;
+  END IF;
+
+  UPDATE cmitem
+    SET cmitem_itemsite_id=COALESCE(itemsite_id, -1),
+        cmitem_qtycredit=pNew.qty_to_credit,
+        cmitem_qtyreturned=pNew.qty_returned,
+        cmitem_unitprice=pNew.net_unit_price,
+        cmitem_comments=pNew.notes,
+        cmitem_rsncode_id=getRsnId(pNew.reason_code),
+        cmitem_taxtype_id=taxtype_id,
+        cmitem_qty_uom_id=COALESCE(getUomId(pNew.qty_uom), item_inv_uom_id),
+        cmitem_qty_invuomratio=CASE WHEN item_id IS NOT NULL THEN itemuomtouomratio(item_id, COALESCE(getUomId(pNew.qty_uom),item_inv_uom_id),item_inv_uom_id)
+                                    ELSE 1
+                               END,
+        cmitem_price_uom_id=COALESCE(getUomId(pNew.price_uom),item_price_uom_id),
+        cmitem_price_invuomratio=CASE WHEN item_id IS NOT NULL THEN itemuomtouomratio(item_id, COALESCE(getUomId(pNew.price_uom),item_price_uom_id),item_price_uom_id)
+                                      ELSE 1
+                                 END
+  FROM cmhead LEFT OUTER JOIN item ON (item_id=getItemId(pNew.item_number))
+              LEFT OUTER JOIN itemsite ON (itemsite_item_id=item_id AND
+                                           itemsite_warehous_id=getWarehousId(pNew.recv_site, 'ALL'))
+              LEFT OUTER JOIN taxtype ON (taxtype_id=CASE WHEN pNew.tax_type IS NULL THEN getItemTaxType(item_id,cmhead_taxzone_id)
+                                                          WHEN pNew.tax_type = 'None' THEN NULL
+                                                          ELSE getTaxTypeId(pNew.tax_type)
+                                                     END)
+  WHERE cmitem_cmhead_id=cmhead_id
+    AND cmhead_number=pOld.memo_number
+    AND cmitem_linenumber=pOld.line_number
+    AND cmhead_posted=FALSE;
+
+  RETURN TRUE;
+END;
+$updatecreditmemoline$ LANGUAGE 'plpgsql';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+  ON INSERT TO api.creditmemoline DO INSTEAD
+    SELECT insertcreditmemoline(NEW);
+
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+  ON UPDATE TO api.creditmemoline DO INSTEAD
+    SELECT updatecreditmemoline(NEW, OLD);
+
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+  ON DELETE TO api.creditmemoline DO INSTEAD
+    DELETE FROM cmitem
+    WHERE ( (cmitem_cmhead_id=getCmheadId(OLD.memo_number, FALSE))
+      AND   (cmitem_linenumber = OLD.line_number) );
diff --git a/foundation-database/api/views/custchar.sql b/foundation-database/api/views/custchar.sql
new file mode 100644 (file)
index 0000000..6df810c
--- /dev/null
@@ -0,0 +1,52 @@
+-- Customer Characteristic
+
+SELECT dropIfExists('VIEW', 'custchar', 'api');
+CREATE VIEW api.custchar
+AS 
+   SELECT 
+     cust_number::varchar AS customer_number,
+     char_name::varchar AS characteristic,
+     charass_value AS value
+   FROM custinfo, char, charass
+   WHERE (('C'=charass_target_type)
+   AND (cust_id=charass_target_id)
+   AND (charass_char_id=char_id));
+
+GRANT ALL ON TABLE api.custchar TO xtrole;
+COMMENT ON VIEW api.custchar IS 'Customer Characteristics';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.custchar DO INSTEAD
+
+  INSERT INTO charass (
+    charass_target_type,
+    charass_target_id,
+    charass_char_id,
+    charass_value,
+    charass_default
+    )
+  VALUES (
+    'C',
+    getCustId(NEW.customer_number),
+    getCharId(NEW.characteristic,'C'),
+    NEW.value,
+    false);
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.custchar DO INSTEAD
+
+  UPDATE charass SET
+    charass_value=NEW.value
+  WHERE ((charass_target_type='C')
+  AND (charass_target_id=getCustId(OLD.customer_number))
+  AND (charass_char_id=getCharId(OLD.characteristic,'C')));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.custchar DO INSTEAD
+
+  DELETE FROM charass
+  WHERE ((charass_target_type='C')
+  AND (charass_target_id=getCustId(OLD.customer_number))
+  AND (charass_char_id=getCharId(OLD.characteristic,'C')));
diff --git a/foundation-database/api/views/custcomment.sql b/foundation-database/api/views/custcomment.sql
new file mode 100644 (file)
index 0000000..d645f72
--- /dev/null
@@ -0,0 +1,45 @@
+-- Customer Comment
+
+SELECT dropIfExists('VIEW', 'custcomment', 'api');
+CREATE VIEW api.custcomment
+AS 
+   SELECT 
+     cust_number::varchar AS customer_number,
+     cmnttype_name AS type,
+     comment_date AS date,
+     comment_user AS username,
+     comment_text AS text
+   FROM custinfo, cmnttype, comment
+   WHERE ((comment_source='C')
+   AND (comment_source_id=cust_id)
+   AND (comment_cmnttype_id=cmnttype_id));
+
+GRANT ALL ON TABLE api.custcomment TO xtrole;
+COMMENT ON VIEW api.custcomment IS 'Customer Comment';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.custcomment DO INSTEAD
+
+  INSERT INTO comment (
+    comment_date,
+    comment_source,
+    comment_source_id,
+    comment_user,
+    comment_cmnttype_id,
+    comment_text
+    )
+  VALUES (
+    COALESCE(NEW.date,now()),
+    'C',
+    getCustId(NEW.customer_number),
+    COALESCE(NEW.username,getEffectiveXtUser()),
+    getCmntTypeId(NEW.type),
+    NEW.text);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.custcomment DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.custcomment DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/custcreditcard.sql b/foundation-database/api/views/custcreditcard.sql
new file mode 100644 (file)
index 0000000..68e5baa
--- /dev/null
@@ -0,0 +1,64 @@
+-- Customer Credit Card
+
+SELECT dropIfExists('VIEW', 'custcreditcard', 'api');
+CREATE VIEW api.custcreditcard
+AS 
+   SELECT 
+     cust_number::varchar AS customer_number,
+     CASE
+       WHEN ccard_type = 'V' THEN
+         'Visa'
+       WHEN ccard_type = 'M' THEN
+         'Master Card'
+       WHEN ccard_type = 'A' THEN
+         'American Express'
+       WHEN ccard_type = 'D' THEN
+         'Discover'
+       ELSE
+         'Not Supported'
+     END AS credit_card_type,
+     ccard_active AS active,
+     ccard_number AS credit_card_number,
+     ccard_name AS name, 
+     ccard_address1 AS street_address1,
+     ccard_address2 AS street_address2,
+     ccard_city AS city, 
+     ccard_state AS state, 
+     ccard_zip AS postal_code,
+     ccard_country AS country, 
+     ccard_month_expired AS expiration_month, 
+     ccard_year_expired AS expiration_year,
+     (''::text) AS key
+   FROM ccard, custinfo
+   WHERE (ccard_cust_id=cust_id);
+
+GRANT ALL ON TABLE api.custcreditcard TO xtrole;
+COMMENT ON VIEW api.custcreditcard IS 'Customer Credit Cards.';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.custcreditcard DO INSTEAD
+
+SELECT insertccard(
+   NEW.customer_number,
+   NEW.active,
+   NEW.credit_card_type,
+   NEW.credit_card_number,
+   NEW.name,
+   NEW.street_address1,
+   NEW.street_address2,
+   NEW.city,
+   NEW.state,
+   NEW.postal_code,
+   NEW.country,
+   NEW.expiration_month,
+   NEW.expiration_year,
+   NEW.key);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.custcreditcard DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.custcreditcard DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/customer.sql b/foundation-database/api/views/customer.sql
new file mode 100644 (file)
index 0000000..fd99fb6
--- /dev/null
@@ -0,0 +1,369 @@
+
+  --Customer View
+
+  SELECT dropIfExists('VIEW', 'customer', 'api');
+  CREATE OR REPLACE VIEW api.customer AS
+  SELECT 
+    cust_number::varchar AS customer_number,
+    custtype_code AS customer_type,
+    cust_name AS customer_name,
+    cust_active AS active,
+    salesrep_number AS sales_rep,
+    cust_commprcnt * 100 AS commission,
+    cust_shipvia AS ship_via,
+    shipform_name AS ship_form,
+    shipchrg_name AS shipping_charges,
+    cust_backorder AS accepts_backorders,
+    cust_partialship AS accepts_partial_shipments,
+    cust_ffshipto AS allow_free_form_shipto,
+    cust_ffbillto AS allow_free_form_billto,
+    warehous_code AS preferred_selling_site,
+    taxzone_code AS default_tax_zone,
+    terms_code AS default_terms,
+    CASE 
+      WHEN cust_balmethod='B' THEN
+       'Balance Forward'
+      ELSE
+       'Open Item'
+      END AS balance_method,
+    cust_discntprcnt AS default_discount,
+    dc.curr_abbr AS default_currency,
+    clc.curr_abbr AS credit_limit_currency,
+    cust_creditlmt AS credit_limit,
+    CASE
+      WHEN (COALESCE(cust_gracedays, 0) > 0) THEN cust_gracedays
+    END AS alternate_grace_days,
+    cust_creditrating AS credit_rating,
+    CASE
+      WHEN (cust_creditstatus = 'G') THEN
+        'In Good Standing'
+      WHEN (cust_creditstatus = 'W') THEN
+        'On Credit Warning'
+      ELSE
+        'On Credit Hold'
+    END AS credit_status,
+    cust_autoupdatestatus AS credit_status_exceed_warn,
+    cust_autoholdorders AS credit_status_exceed_hold,
+    cust_usespos AS uses_purchase_orders,
+    cust_blanketpos AS uses_blanket_pos,
+    mc.cntct_number AS billing_contact_number,
+    mc.cntct_honorific AS billing_contact_honorific,
+    mc.cntct_first_name AS billing_contact_first,
+    mc.cntct_middle AS billing_contact_middle,   
+    mc.cntct_last_name AS billing_contact_last,
+    mc.cntct_suffix AS billing_contact_suffix,
+    mc.cntct_title AS billing_contact_job_title,
+    mc.cntct_phone AS billing_contact_voice,
+    mc.cntct_phone2 AS billing_contact_alternate,
+    mc.cntct_fax AS billing_contact_fax,
+    mc.cntct_email AS billing_contact_email,
+    mc.cntct_webaddr AS billing_contact_web,
+    (''::TEXT) AS billing_contact_change,
+    m.addr_number AS billing_contact_address_number,
+    m.addr_line1 AS billing_contact_address1,
+    m.addr_line2 AS billing_contact_address2,
+    m.addr_line3 AS billing_contact_address3,
+    m.addr_city AS billing_contact_city,
+    m.addr_state AS billing_contact_state,
+    m.addr_postalcode AS billing_contact_postalcode,
+    m.addr_country AS billing_contact_country,
+    (''::TEXT) AS billing_contact_address_change,
+    cc.cntct_number AS correspond_contact_number,
+    cc.cntct_honorific AS correspond_contact_honorific,
+    cc.cntct_first_name AS correspond_contact_first,
+    cc.cntct_middle AS correspond_contact_middle,
+    cc.cntct_last_name AS correspond_contact_last,
+    cc.cntct_suffix AS correspond_contact_suffix,
+    cc.cntct_title AS correspond_contact_job_title,
+    cc.cntct_phone AS correspond_contact_voice,
+    cc.cntct_phone2 AS correspond_contact_alternate,
+    cc.cntct_fax AS correspond_contact_fax,
+    cc.cntct_email AS correspond_contact_email,
+    cc.cntct_webaddr AS correspond_contact_web,
+    (''::TEXT) AS correspond_contact_change,
+    c.addr_number AS correspond_contact_address_number,
+    c.addr_line1 AS correspond_contact_address1,
+    c.addr_line2 AS correspond_contact_address2,
+    c.addr_line3 AS correspond_contact_address3,
+    c.addr_city AS correspond_contact_city,
+    c.addr_state AS correspond_contact_state,
+    c.addr_postalcode AS correspond_contact_postalcode,
+    c.addr_country AS correspond_contact_country,
+    (''::TEXT) AS correspond_contact_address_change,
+    cust_comments AS notes         
+  FROM
+    custinfo
+      LEFT OUTER JOIN shipchrg ON (cust_shipchrg_id=shipchrg_id)
+      LEFT OUTER JOIN whsinfo ON (cust_preferred_warehous_id=warehous_id)
+      LEFT OUTER JOIN cntct mc ON (cust_cntct_id=mc.cntct_id)
+      LEFT OUTER JOIN addr m ON (mc.cntct_addr_id=m.addr_id)
+      LEFT OUTER JOIN cntct cc ON (cust_corrcntct_id=cc.cntct_id)
+      LEFT OUTER JOIN addr c ON (cc.cntct_addr_id=c.addr_id)
+      LEFT OUTER JOIN taxzone ON (cust_taxzone_id=taxzone_id)
+      LEFT OUTER JOIN shipform ON (cust_shipform_id=shipform_id),
+    custtype,salesrep,
+    curr_symbol dc, curr_symbol clc, terms
+  WHERE ((cust_custtype_id=custtype_id)
+  AND (cust_salesrep_id=salesrep_id)
+  AND (cust_curr_id=dc.curr_id)
+  AND (cust_creditlmt_curr_id=clc.curr_id)
+  AND (cust_terms_id=terms_id))
+  ;
+
+GRANT ALL ON TABLE api.customer TO xtrole;
+COMMENT ON VIEW api.customer IS 'Customer';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.customer DO INSTEAD
+
+INSERT INTO custinfo
+       (cust_active,
+       cust_custtype_id,
+        cust_salesrep_id,
+        cust_commprcnt,
+        cust_name,
+        cust_creditlmt,
+       cust_creditrating,
+       cust_backorder,
+       cust_partialship,
+       cust_terms_id,
+       cust_discntprcnt,
+       cust_balmethod,
+       cust_ffshipto,
+       cust_shipform_id,
+       cust_shipvia,
+       cust_blanketpos,
+       cust_shipchrg_id,
+       cust_creditstatus,
+       cust_comments,
+        cust_ffbillto,
+        cust_usespos,
+        cust_number,
+        cust_autoupdatestatus,
+        cust_autoholdorders,
+        cust_preferred_warehous_id,
+        cust_curr_id,
+        cust_creditlmt_curr_id,
+        cust_cntct_id,
+        cust_corrcntct_id,
+        cust_taxzone_id,
+        cust_gracedays )
+        VALUES (
+       COALESCE(NEW.active,true),
+       COALESCE(getcusttypeid(NEW.customer_type),FetchMetricValue('DefaultCustType')),
+        COALESCE(getSalesRepId(NEW.sales_rep),FetchMetricValue('DefaultSalesRep')),
+        COALESCE(NEW.commission * .01,(
+          SELECT salesrep_commission
+          FROM salesrep
+          WHERE (salesrep_id=getSalesRepId(NEW.sales_rep)))),
+        COALESCE(NEW.customer_name,''),
+        COALESCE(NEW.credit_limit,FetchMetricValue('SOCreditLimit')),  
+        COALESCE(NEW.credit_rating,FetchMetricText('SOCreditRate')),
+        COALESCE(NEW.accepts_backorders,FetchMetricBool('DefaultBackOrders'),false),
+        COALESCE(NEW.accepts_partial_shipments,FetchMetricBool('DefaultPartialShipments'::text),false),
+        COALESCE(getTermsId(NEW.default_terms),FetchMetricValue('DefaultTerms')),
+        COALESCE(NEW.default_discount,0),
+       CASE 
+         WHEN NEW.balance_method='Balance Forward' THEN
+           'B'
+         WHEN NEW.balance_method='Open Items' THEN
+           'O'
+          ELSE
+            COALESCE(FetchMetricText('DefaultBalanceMethod'),'B')
+       END,
+        COALESCE(NEW.allow_free_form_shipto,FetchMetricBool('DefaultFreeFormShiptos'),false),
+        COALESCE(getShipFormId(NEW.ship_form),FetchMetricValue('DefaultShipFormId')),
+        COALESCE(NEW.ship_via,FetchDefaultShipVia()),
+        COALESCE(NEW.uses_blanket_pos,false),
+        COALESCE(getShipChrgId(NEW.shipping_charges),-1),
+        CASE
+         WHEN (NEW.credit_status = 'On Credit Warning') THEN
+          'W'
+         WHEN (NEW.credit_status = 'On Credit Hold') THEN
+          'H'
+         ELSE
+           'G'
+       END,
+        COALESCE(NEW.notes,''),
+        COALESCE(NEW.allow_free_form_billto,false),
+        COALESCE(NEW.uses_purchase_orders,false),
+        COALESCE(UPPER(NEW.customer_number),CAST(fetchCRMAccountNumber() AS text)),
+        COALESCE(NEW.credit_status_exceed_warn,false),
+        COALESCE(NEW.credit_status_exceed_hold,false),
+        COALESCE(getWarehousId(NEW.preferred_selling_site,'ACTIVE'),-1),
+        COALESCE(getCurrId(NEW.default_currency),basecurrid()),
+        COALESCE(getCurrID(NEW.credit_limit_currency),basecurrid()),
+        saveCntct(
+          getCntctId(NEW.billing_contact_number,false),
+          NEW.billing_contact_number,
+          saveAddr(
+            getAddrId(NEW.billing_contact_address_number),
+            NEW.billing_contact_address_number,
+            NEW.billing_contact_address1,
+            NEW.billing_contact_address2,
+            NEW.billing_contact_address3,
+            NEW.billing_contact_city,
+            NEW.billing_contact_state,
+            NEW.billing_contact_postalcode,
+            NEW.billing_contact_country,
+            NEW.billing_contact_address_change),
+          NEW.billing_contact_honorific,
+          NEW.billing_contact_first,
+          NEW.billing_contact_middle,
+          NEW.billing_contact_last,
+          NEW.billing_contact_suffix,
+          NEW.billing_contact_voice,
+          NEW.billing_contact_alternate,
+          NEW.billing_contact_fax,
+          NEW.billing_contact_email,
+          NEW.billing_contact_web,
+          NEW.billing_contact_job_title,
+          NEW.billing_contact_change
+          ),
+        saveCntct(
+          getCntctId(NEW.correspond_contact_number,false),
+          NEW.correspond_contact_number,
+          saveAddr(
+            getAddrId(NEW.correspond_contact_address_number),
+            NEW.correspond_contact_address_number,
+            NEW.correspond_contact_address1,
+            NEW.correspond_contact_address2,
+            NEW.correspond_contact_address3,
+            NEW.correspond_contact_city,
+            NEW.correspond_contact_state,
+            NEW.correspond_contact_postalcode,
+            NEW.correspond_contact_country,
+            NEW.correspond_contact_address_change),
+          NEW.correspond_contact_honorific,
+          NEW.correspond_contact_first,
+          NEW.correspond_contact_middle,
+          NEW.correspond_contact_last,
+          NEW.correspond_contact_suffix,
+          NEW.correspond_contact_voice,
+          NEW.correspond_contact_alternate,
+          NEW.correspond_contact_fax,
+          NEW.correspond_contact_email,
+          NEW.correspond_contact_web,
+          NEW.correspond_contact_job_title,
+          NEW.correspond_contact_change
+          ),
+        getTaxZoneId(NEW.default_tax_zone),
+        CASE WHEN (COALESCE(NEW.alternate_grace_days, 0) > 0) THEN NEW.alternate_grace_days
+             ELSE NULL
+        END
+         );
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.customer DO INSTEAD
+
+UPDATE custinfo SET
+       cust_active=NEW.active,
+       cust_custtype_id=getCustTypeId(NEW.customer_type),
+        cust_salesrep_id=getSalesRepId(NEW.sales_rep),
+        cust_commprcnt=NEW.commission * .01,
+        cust_name=NEW.customer_name,
+        cust_creditlmt=NEW.credit_limit,
+       cust_creditrating=NEW.credit_rating,
+       cust_backorder=NEW.accepts_backorders,
+       cust_partialship=NEW.accepts_partial_shipments,
+       cust_terms_id=getTermsId(NEW.default_terms),
+       cust_discntprcnt=NEW.default_discount,
+       cust_balmethod=
+         CASE 
+           WHEN NEW.balance_method='Balance Forward' THEN
+             'B'
+           WHEN NEW.balance_method='Open Items' THEN
+             'O'
+            ELSE
+              NULL
+         END,
+       cust_ffshipto=NEW.allow_free_form_shipto,
+       cust_shipform_id=getShipFormId(NEW.ship_form),
+       cust_shipvia=NEW.ship_via,
+       cust_blanketpos=NEW.uses_blanket_pos,
+       cust_shipchrg_id=COALESCE(getShipChrgId(NEW.shipping_charges),-1),
+       cust_creditstatus=
+          CASE
+           WHEN (NEW.credit_status = 'On Credit Warning') THEN
+             'W'
+           WHEN (NEW.credit_status = 'On Credit Hold') THEN
+             'H'
+            ELSE
+              'G'
+        END,
+       cust_comments=NEW.notes,
+        cust_ffbillto=NEW.allow_free_form_billto,
+        cust_usespos=NEW.uses_purchase_orders,
+        cust_number=NEW.customer_number,
+        cust_autoupdatestatus=NEW.credit_status_exceed_warn,
+        cust_autoholdorders=NEW.credit_status_exceed_hold,
+        cust_preferred_warehous_id=COALESCE(getWarehousId(NEW.preferred_selling_site,'ACTIVE'),-1),
+        cust_curr_id=getCurrId(NEW.default_currency),
+        cust_creditlmt_curr_id=getCurrId(NEW.credit_limit_currency),
+        cust_cntct_id=saveCntct(
+          getCntctId(NEW.billing_contact_number,false),
+          NEW.billing_contact_number,
+          saveAddr(
+            getAddrId(NEW.billing_contact_address_number),
+            NEW.billing_contact_address_number,
+            NEW.billing_contact_address1,
+            NEW.billing_contact_address2,
+            NEW.billing_contact_address3,
+            NEW.billing_contact_city,
+            NEW.billing_contact_state,
+            NEW.billing_contact_postalcode,
+            NEW.billing_contact_country,
+            NEW.billing_contact_address_change),
+          NEW.billing_contact_honorific,
+          NEW.billing_contact_first,
+          NEW.billing_contact_middle,
+          NEW.billing_contact_last,
+          NEW.billing_contact_suffix,
+          NEW.billing_contact_voice,
+          NEW.billing_contact_alternate,
+          NEW.billing_contact_fax,
+          NEW.billing_contact_email,
+          NEW.billing_contact_web,
+          NEW.billing_contact_job_title,
+          NEW.billing_contact_change
+          ),
+        cust_corrcntct_id=saveCntct(
+          getCntctId(NEW.correspond_contact_number,false),
+          NEW.correspond_contact_number,
+          saveAddr(
+            getAddrId(NEW.correspond_contact_address_number),
+            NEW.correspond_contact_address_number,
+            NEW.correspond_contact_address1,
+            NEW.correspond_contact_address2,
+            NEW.correspond_contact_address3,
+            NEW.correspond_contact_city,
+            NEW.correspond_contact_state,
+            NEW.correspond_contact_postalcode,
+            NEW.correspond_contact_country,
+            NEW.correspond_contact_address_change),
+          NEW.correspond_contact_honorific,
+          NEW.correspond_contact_first,
+          NEW.correspond_contact_middle,
+          NEW.correspond_contact_last,
+          NEW.correspond_contact_suffix,
+          NEW.correspond_contact_voice,
+          NEW.correspond_contact_alternate,
+          NEW.correspond_contact_fax,
+          NEW.correspond_contact_email,
+          NEW.correspond_contact_web,
+          NEW.correspond_contact_job_title,
+          NEW.correspond_contact_change
+          ),
+        cust_taxzone_id=getTaxZoneId(NEW.default_tax_zone),
+        cust_gracedays=
+          CASE WHEN (COALESCE(NEW.alternate_grace_days, 0) > 0) THEN NEW.alternate_grace_days
+          END
+        WHERE cust_id=getCustId(OLD.customer_number);
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.customer DO INSTEAD
+    DELETE FROM custinfo WHERE (cust_number=OLD.customer_number);
+
diff --git a/foundation-database/api/views/customertaxreg.sql b/foundation-database/api/views/customertaxreg.sql
new file mode 100644 (file)
index 0000000..bd18d06
--- /dev/null
@@ -0,0 +1,62 @@
+--Customer Tax Registration View
+
+SELECT dropIfExists('VIEW', 'customertaxreg', 'api');
+CREATE OR REPLACE VIEW api.customertaxreg AS
+
+SELECT
+  cust_number::varchar AS customer_number,
+  COALESCE(taxzone_code, 'Any')::varchar AS tax_zone,
+  taxauth_code::varchar AS tax_authority,
+  taxreg_number AS registration_number,
+  CASE WHEN
+    taxreg_effective = startoftime() THEN
+      'Always'
+    ELSE
+      formatdate(taxreg_effective)
+  END AS start_date,
+  CASE WHEN
+    taxreg_expires = endoftime() THEN
+      'Never'
+    ELSE
+      formatdate(taxreg_expires)
+  END AS end_date,
+  taxreg_notes AS notes
+FROM taxreg
+     LEFT OUTER JOIN custinfo ON (cust_id=taxreg_rel_id)
+     LEFT OUTER JOIN taxauth ON (taxauth_id=taxreg_taxauth_id)
+     LEFT OUTER JOIN taxzone ON (taxzone_id=taxreg_taxzone_id)
+WHERE (taxreg_rel_type='C')
+ORDER BY cust_number, taxreg_number;
+
+GRANT ALL ON TABLE api.customertaxreg TO xtrole;
+COMMENT ON VIEW api.customertaxreg IS 'Customer Tax Registrations';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+  ON INSERT TO api.customertaxreg DO INSTEAD
+
+INSERT INTO taxreg (
+  taxreg_rel_id,
+  taxreg_rel_type,
+  taxreg_taxauth_id,
+  taxreg_taxzone_id,
+  taxreg_number,
+  taxreg_effective,
+  taxreg_expires,
+  taxreg_notes )
+VALUES (
+  getCustId(NEW.customer_number),
+  'C',
+  getTaxauthId(NEW.tax_authority),
+  (SELECT cust_taxzone_id
+   FROM custinfo
+   WHERE cust_id=getCustId(NEW.customer_number)),
+  COALESCE(NEW.registration_number,''),
+  CASE WHEN (NEW.start_date = 'Always') THEN startoftime()
+       ELSE COALESCE(NEW.start_date::date,startoftime())
+  END, 
+  CASE WHEN (NEW.end_date = 'Never') THEN endoftime()
+       ELSE COALESCE(NEW.end_date::date,endoftime())
+  END,
+  NEW.notes );
diff --git a/foundation-database/api/views/customertype.sql b/foundation-database/api/views/customertype.sql
new file mode 100644 (file)
index 0000000..76d0e5e
--- /dev/null
@@ -0,0 +1,42 @@
+  --Customer Type View
+
+  SELECT dropIfExists('VIEW', 'customertype', 'api');
+  CREATE OR REPLACE VIEW api.customertype AS
+
+  SELECT
+    custtype_code::varchar AS code,
+    custtype_descrip AS description,
+    custtype_char AS enable_characteristics_profile
+  FROM custtype
+  ORDER BY custtype_code;
+
+GRANT ALL ON TABLE api.customertype TO xtrole;
+COMMENT ON VIEW api.customertype IS 'Customer Type';
+
+  --Rules
+
+  CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.customertype DO INSTEAD
+
+  INSERT INTO custtype (
+    custtype_code,
+    custtype_descrip,
+    custtype_char)
+  VALUES (
+    NEW.code,
+    COALESCE(NEW.description,''),
+    COALESCE(NEW.enable_characteristics_profile,FALSE));
+  CREATE OR REPLACE RULE "_UPDATE" AS
+  ON UPDATE TO api.customertype DO INSTEAD
+
+  UPDATE custtype SET
+    custtype_code=NEW.code,
+    custtype_descrip=NEW.description,
+    custtype_char=NEW.enable_characteristics_profile
+  WHERE (custtype_code=OLD.code);
+
+  CREATE OR REPLACE RULE "_DELETE" AS
+  ON DELETE TO api.customertype DO INSTEAD
+
+  DELETE FROM custtype WHERE (custtype_code=OLD.code);
diff --git a/foundation-database/api/views/customertypechar.sql b/foundation-database/api/views/customertypechar.sql
new file mode 100644 (file)
index 0000000..0c388d8
--- /dev/null
@@ -0,0 +1,54 @@
+-- Customer Type Characteristic
+
+SELECT dropIfExists('VIEW', 'customertypechar', 'api');
+CREATE VIEW api.customertypechar
+AS 
+   SELECT 
+     custtype_code::varchar AS customer_type,
+     char_name::varchar AS characteristic,
+     charass_value AS value,
+     charass_default AS is_default
+   FROM custtype, char, charass
+   WHERE (('CT'=charass_target_type)
+   AND (custtype_id=charass_target_id)
+   AND (charass_char_id=char_id));
+
+GRANT ALL ON TABLE api.customertypechar TO xtrole;
+COMMENT ON VIEW api.customertypechar IS 'Customer Type Characteristics';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.customertypechar DO INSTEAD
+
+  INSERT INTO charass (
+    charass_target_type,
+    charass_target_id,
+    charass_char_id,
+    charass_value,
+    charass_default
+    )
+  VALUES (
+    'CT',
+    getCusttypeId(NEW.customer_type),
+    getCharId(NEW.characteristic,'CT'),
+    NEW.value,
+    COALESCE(NEW.is_default,false));
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.customertypechar DO INSTEAD
+
+  UPDATE charass SET
+    charass_value=NEW.value,
+    charass_default=NEW.is_default
+  WHERE ((charass_target_type='CT')
+  AND (charass_target_id=getCusttypeId(OLD.customer_type))
+  AND (charass_char_id=getCharId(OLD.characteristic,'CT')));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.customertypechar DO INSTEAD
+
+  DELETE FROM charass
+  WHERE ((charass_target_type='CT')
+  AND (charass_target_id=getCusttypeId(OLD.customer_type))
+  AND (charass_char_id=getCharId(OLD.characteristic,'CT')));
diff --git a/foundation-database/api/views/custshipto.sql b/foundation-database/api/views/custshipto.sql
new file mode 100644 (file)
index 0000000..39e3760
--- /dev/null
@@ -0,0 +1,216 @@
+-- Customer Shipto
+
+SELECT dropIfExists('VIEW', 'custshipto', 'api');
+CREATE VIEW api.custshipto
+AS
+   SELECT
+     cust_number::varchar AS customer_number,
+     shipto_num::varchar AS shipto_number,
+     shipto_active AS active,
+     shipto_name AS name,
+     shipto_default AS default_flag,
+     addr_number AS address_number,
+     addr_line1 AS address1,
+     addr_line2 AS address2,
+     addr_line3 AS address3,
+     addr_city AS city,
+     addr_state AS state,
+     addr_postalcode AS postal_code,
+     addr_country AS country,
+     (''::text) AS address_change,
+     cntct_number AS contact_number,
+     cntct_honorific AS honorific,
+     cntct_first_name AS first,
+     cntct_middle AS middle,
+     cntct_last_name AS last,
+     cntct_suffix AS suffix,
+     cntct_title AS job_title,
+     cntct_phone AS phone,
+     cntct_fax AS fax,
+     cntct_email AS email,
+     (''::text) AS contact_change,
+     salesrep_number AS sales_rep,
+     (shipto_commission * 100.0) AS commission,
+     shipzone_name AS zone,
+     taxzone_code AS tax_zone,
+     shipto_shipvia AS ship_via,
+     shipform_name AS ship_form,
+     shipchrg_name AS shipping_charges,
+     CASE
+       WHEN shipto_ediprofile_id = -1 THEN
+         'No EDI'
+       WHEN shipto_ediprofile_id = -2 THEN
+         'Use Customer Master'
+       ELSE
+         getEdiProfileName(shipto_ediprofile_id)
+     END AS edi_profile,
+     shipto_comments AS general_notes,
+     shipto_shipcomments AS shipping_notes
+     FROM custinfo, shiptoinfo
+  LEFT OUTER JOIN shipchrg ON (shipto_shipchrg_id=shipchrg_id)
+  LEFT OUTER JOIN cntct ON (shipto_cntct_id=cntct_id)
+  LEFT OUTER JOIN addr ON (shipto_addr_id=addr_id)
+  LEFT OUTER JOIN taxzone ON (shipto_taxzone_id=taxzone_id)
+  LEFT OUTER JOIN shipzone ON (shipto_shipzone_id=shipzone_id)
+  LEFT OUTER JOIN salesrep ON (shiptoinfo.shipto_salesrep_id = salesrep_id)
+  ,shipform
+     WHERE ((cust_id=shipto_cust_id)
+     AND (cust_shipform_id=shipform_id));
+
+GRANT ALL ON TABLE api.custshipto TO xtrole;
+COMMENT ON VIEW api.custshipto IS 'Customer Shipto Address';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.custshipto DO INSTEAD
+
+  INSERT INTO shiptoinfo (
+    shipto_cust_id,
+    shipto_name,
+    shipto_salesrep_id,
+    shipto_comments,
+    shipto_shipcomments,
+    shipto_shipzone_id,
+    shipto_shipvia,
+    shipto_commission,
+    shipto_shipform_id,
+    shipto_shipchrg_id,
+    shipto_active,
+    shipto_default,
+    shipto_num,
+    shipto_ediprofile_id,
+    shipto_cntct_id,
+    shipto_addr_id,
+    shipto_taxzone_id
+    )
+  VALUES (
+    getCustId(NEW.customer_number),
+    COALESCE(NEW.name,''),
+    COALESCE(getSalesRepId(NEW.sales_rep),(
+      SELECT cust_salesrep_id
+      FROM custinfo
+      WHERE (cust_id=getCustId(NEW.customer_number)))),
+    COALESCE(NEW.general_notes,''),
+    COALESCE(NEW.shipping_notes,''),
+    getShipZoneId(NEW.zone),
+    COALESCE(NEW.ship_via,(
+      SELECT cust_shipvia
+      FROM custinfo
+      WHERE (cust_id=getCustId(NEW.customer_number)))),
+    COALESCE((NEW.commission / 100.0),0),
+    COALESCE(getShipFormId(NEW.ship_form),(
+      SELECT cust_shipform_id
+      FROM custinfo
+      WHERE (cust_id=getCustId(NEW.customer_number)))),
+    COALESCE(getShipChrgId(NEW.shipping_charges),(
+      SELECT cust_shipchrg_id
+      FROM custinfo
+      WHERE (cust_id=getCustId(NEW.customer_number)))),
+    COALESCE(NEW.active,true),
+    COALESCE(NEW.default_flag,false),
+    COALESCE(NEW.shipto_number,CAST((
+      SELECT (COALESCE(MAX(CAST(shipto_num AS INTEGER)), 0) + 1)
+      FROM shiptoinfo
+      WHERE (shipto_cust_id=getCustId(NEW.customer_number))
+      AND  (shipto_num~'^[0-9]*$')) AS TEXT)),
+    CASE
+      WHEN NEW.edi_profile = 'No EDI' THEN
+        -1
+      WHEN NEW.edi_profile = 'Use Customer Master' THEN
+        -2
+      ELSE
+        getEdiProfileId(NEW.edi_profile)
+    END,
+    saveCntct(
+      getCntctId(NEW.contact_number),
+      NEW.contact_number,
+      NULL,
+      NEW.honorific,
+      NEW.first,
+      NEW.middle,
+      NEW.last,
+      NEW.suffix,
+      NEW.phone,
+      NULL,
+      NEW.fax,
+      NEW.email,
+      NULL,
+      NEW.job_title,
+      NEW.contact_change),
+    saveAddr(
+      getAddrId(NEW.address_number),
+      NEW.address_number,
+      NEW.address1,
+      NEW.address2,
+      NEW.address3,
+      NEW.city,
+      NEW.state,
+      NEW.postal_code,
+      NEW.country,
+      NEW.address_change),
+    COALESCE(getTaxZoneId(NEW.tax_zone),(
+      SELECT cust_taxzone_id
+      FROM custinfo
+      WHERE (cust_id=getCustId(NEW.customer_number)))));
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.custshipto DO INSTEAD
+
+  UPDATE shiptoinfo SET
+    shipto_cust_id=getCustId(NEW.customer_number),
+    shipto_name=NEW.name,
+    shipto_salesrep_id=getSalesRepId(NEW.sales_rep),
+    shipto_comments=NEW.general_notes,
+    shipto_shipcomments=NEW.shipping_notes,
+    shipto_shipzone_id=getShipZoneId(NEW.zone),
+    shipto_shipvia=NEW.ship_via,
+    shipto_commission=(NEW.commission / 100),
+    shipto_shipform_id=getShipFormId(NEW.ship_form),
+    shipto_shipchrg_id=getShipChrgId(NEW.shipping_charges),
+    shipto_active=NEW.active,
+    shipto_default=NEW.default_flag,
+    shipto_num=OLD.shipto_number,
+    shipto_ediprofile_id=
+    CASE
+      WHEN NEW.edi_profile = 'No EDI' THEN
+        -1
+      WHEN NEW.edi_profile = 'Use Customer Master' THEN
+        -2
+      ELSE
+        getEdiProfileId(NEW.edi_profile)
+    END,
+    shipto_cntct_id=saveCntct(
+      getCntctId(NEW.contact_number),
+      NEW.contact_number,
+      NULL,
+      NEW.honorific,
+      NEW.first,
+      NEW.middle,
+      NEW.last,
+      NEW.suffix,
+      NEW.phone,
+      NULL,
+      NEW.fax,
+      NEW.email,
+      NULL,
+      NEW.job_title,
+      NEW.contact_change),
+    shipto_addr_id=saveAddr(
+      getAddrId(NEW.address_number),
+      NEW.address_number,
+      NEW.address1,
+      NEW.address2,
+      NEW.address3,
+      NEW.city,
+      NEW.state,
+      NEW.postal_code,
+      NEW.country,
+      NEW.address_change),
+    shipto_taxzone_id=getTaxZoneId(NEW.tax_zone)
+  WHERE  (shipto_id=getShiptoId(OLD.customer_number,OLD.shipto_number));
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.custshipto DO INSTEAD
+
+  SELECT deleteShipto(getShiptoId(OLD.customer_number,OLD.shipto_number));
diff --git a/foundation-database/api/views/custtax.sql b/foundation-database/api/views/custtax.sql
new file mode 100644 (file)
index 0000000..d2c91f4
--- /dev/null
@@ -0,0 +1,49 @@
+-- Customer Tax Registration
+
+SELECT dropIfExists('VIEW', 'custtax', 'api');
+CREATE VIEW api.custtax
+AS 
+   SELECT 
+     cust_number::varchar AS customer_number,
+     taxauth_code::varchar AS tax_authority,
+     taxreg_number AS registration_number
+   FROM custinfo, taxauth, taxreg
+   WHERE ((taxreg_rel_type='C')
+   AND (taxreg_rel_id=cust_id)
+   AND (taxreg_taxauth_id=taxauth_id));
+
+GRANT ALL ON TABLE api.custtax TO xtrole;
+COMMENT ON VIEW api.custtax IS 'Customer Tax Registration';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.custtax DO INSTEAD
+
+  INSERT INTO taxreg (
+    taxreg_rel_type,
+    taxreg_rel_id,
+    taxreg_taxauth_id,
+    taxreg_number)
+  VALUES (
+    'C',
+    getCustId(NEW.customer_number),
+    getTaxAuthId(NEW.tax_authority),
+    NEW.registration_number);
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.custtax DO INSTEAD
+
+  UPDATE taxreg SET
+    taxreg_number=NEW.registration_number
+  WHERE  ((taxreg_rel_type='C')
+  AND (taxreg_rel_id=getCustId(OLD.customer_number))
+  AND (taxreg_taxauth_id=getTaxAuthID(OLD.tax_authority)));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.custtax DO INSTEAD
+
+  DELETE FROM taxreg
+  WHERE  ((taxreg_rel_type='C')
+  AND (taxreg_rel_id=getCustId(OLD.customer_number))
+  AND (taxreg_taxauth_id=getTaxAuthID(OLD.tax_authority)));
diff --git a/foundation-database/api/views/employee.sql b/foundation-database/api/views/employee.sql
new file mode 100644 (file)
index 0000000..65e4021
--- /dev/null
@@ -0,0 +1,238 @@
+
+  SELECT dropIfExists('VIEW', 'employee', 'api');
+
+  CREATE OR REPLACE VIEW api.employee AS 
+  SELECT 
+    e.emp_code::varchar                AS code, 
+    e.emp_number::varchar      AS number, 
+    e.emp_active               AS active, 
+    e.emp_startdate            AS start_date, 
+    cntct.cntct_number         AS contact_number, 
+    cntct.cntct_honorific      AS honorific, 
+    cntct.cntct_first_name     AS first, 
+    cntct.cntct_middle         AS middle, 
+    cntct.cntct_last_name      AS last, 
+    cntct.cntct_suffix         AS suffix, 
+    cntct.cntct_title          AS job_title, 
+    cntct.cntct_phone          AS voice, 
+    cntct.cntct_phone2         AS alternate, 
+    cntct.cntct_fax            AS fax, 
+    cntct.cntct_email          AS email, 
+    cntct.cntct_webaddr        AS web, 
+    (''::TEXT)                         AS contact_change, 
+    addr.addr_number           AS address_number, 
+    addr.addr_line1            AS address1, 
+    addr.addr_line2            AS address2, 
+    addr.addr_line3            AS address3, 
+    addr.addr_city                     AS city, 
+    addr.addr_state            AS state, 
+    addr.addr_postalcode       AS postalcode, 
+    addr.addr_country          AS country, 
+    (''::TEXT)                                 AS address_change, 
+    whsinfo.warehous_code      AS site, 
+    m.emp_code                                 AS manager_code, 
+    
+    CASE WHEN (e.emp_wage_type = 'H')          THEN 'Hourly'
+         WHEN (e.emp_wage_type = 'S')          THEN 'Salaried'
+         WHEN e.emp_wage_type IS NULL THEN NULL
+                ELSE 'Error'
+    END AS wage_type, 
+    e.emp_wage         AS wage, 
+    curr_symbol.curr_abbr AS wage_currency, 
+    CASE WHEN (e.emp_wage_period = 'H')        THEN 'Hour'
+         WHEN (e.emp_wage_period = 'D')        THEN 'Day'
+         WHEN (e.emp_wage_period = 'W')        THEN 'Week'
+         WHEN (e.emp_wage_period = 'BW')       THEN 'Biweek'
+         WHEN (e.emp_wage_period = 'M')        THEN 'Month'
+         WHEN (e.emp_wage_period = 'Y')        THEN 'Year'
+         WHEN (e.emp_wage_period IS NULL)      THEN NULL
+         ELSE 'Error'
+    END AS wage_period, 
+    dept.dept_number AS department, 
+    shift.shift_number AS shift, 
+    crmacct_usr_username IS NOT NULL AS is_user,
+    salesrep.salesrep_id IS NOT NULL AS is_salesrep,
+    vendinfo.vend_id IS NOT NULL AS is_vendor,
+    e.emp_notes AS notes,
+    image.image_name AS image,
+    e.emp_extrate AS rate,
+    curr_symbol.curr_abbr AS billing_currency, 
+    CASE WHEN (e.emp_extrate_period = 'H')     THEN 'Hour'
+         WHEN (e.emp_extrate_period = 'D')     THEN 'Day'
+         WHEN (e.emp_extrate_period = 'W')     THEN 'Week'
+         WHEN (e.emp_extrate_period = 'BW') THEN 'Biweek'
+         WHEN (e.emp_extrate_period = 'M')     THEN 'Month'
+         WHEN (e.emp_extrate_period = 'Y')     THEN 'Year'
+         WHEN (e.emp_extrate_period IS NULL) THEN NULL
+         ELSE 'Error'
+       END AS billing_period
+  FROM emp e
+         JOIN crmacct           ON (e.emp_id = crmacct_emp_id)
+        LEFT JOIN cntct        ON (e.emp_cntct_id = cntct.cntct_id)
+        LEFT JOIN addr         ON (cntct.cntct_addr_id = addr.addr_id)
+        LEFT JOIN whsinfo      ON (e.emp_warehous_id = whsinfo.warehous_id)
+        LEFT JOIN emp m        ON (e.emp_mgr_emp_id = m.emp_id)
+        LEFT JOIN dept         ON (e.emp_dept_id = dept.dept_id)
+        LEFT JOIN shift        ON (e.emp_shift_id = shift.shift_id)
+        LEFT JOIN salesrep     ON (crmacct_salesrep_id = salesrep_id)
+        LEFT JOIN vendinfo     ON (crmacct_vend_id = vend_id)
+        LEFT JOIN image        ON (e.emp_image_id = image.image_id)
+        JOIN curr_symbol       ON (e.emp_wage_curr_id = curr_symbol.curr_id);
+
+ALTER TABLE api.employee OWNER TO "admin";
+GRANT ALL ON TABLE api.employee TO "admin";
+GRANT ALL ON TABLE api.employee TO xtrole;
+COMMENT ON VIEW api.employee IS 'Employee';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS ON INSERT TO api.employee DO INSTEAD  
+  INSERT INTO emp (
+      emp_code, 
+      emp_number, 
+      emp_active, 
+      emp_cntct_id, 
+      emp_warehous_id, 
+      emp_mgr_emp_id, 
+      emp_wage_type, 
+      emp_wage, 
+      emp_wage_curr_id,
+      emp_wage_period,
+      emp_dept_id,
+      emp_shift_id,
+      emp_image_id,
+      emp_extrate, 
+      emp_extrate_period,
+      emp_startdate, 
+      emp_notes
+    ) VALUES (
+      new.code,
+      new.number,
+      COALESCE(new.active, true), 
+      savecntct(getcntctid(new.contact_number),
+                       new.contact_number,
+                               saveaddr(getaddrid(new.address_number),
+                                        new.address_number,
+                                        new.address1,
+                                        new.address2,
+                                        new.address3,
+                                        new.city,
+                                        new.state,
+                                        new.postalcode,
+                                        new.country,
+                                        new.address_change),
+                       new.honorific, 
+                       new.first,
+                       new.middle,
+                       new.last,
+                       new.suffix,
+                       new.voice,
+                       new.alternate,
+                       new.fax,
+                       new.email,
+                       new.web,
+                       new.job_title,
+                       new.contact_change
+      ), 
+      getwarehousid(new.site, 'ALL'),
+      (SELECT emp.emp_id FROM emp WHERE (emp.emp_code = new.manager_code)), 
+      CASE WHEN new.wage_type = 'Hourly' THEN 'H'
+           WHEN new.wage_type = 'Salaried' THEN 'S'
+           ELSE NULL
+      END, 
+      new.wage, 
+      COALESCE(getcurrid(new.wage_currency), basecurrid()), 
+      CASE WHEN new.wage_period = 'Hour'       THEN 'H'
+           WHEN new.wage_period = 'Day'        THEN 'D'
+           WHEN new.wage_period = 'Week'       THEN 'W'
+           WHEN new.wage_period = 'Biweek'     THEN 'BW'
+           WHEN new.wage_period = 'Month'      THEN 'M'
+           WHEN new.wage_period = 'Year'       THEN 'Y'
+           ELSE NULL
+        END, 
+        getdeptid(new.department), 
+        getshiftid(new.shift), 
+        getimageid(new.image), 
+        new.rate, 
+        CASE
+           WHEN new.billing_period = 'Hour' THEN 'H'
+           WHEN new.billing_period = 'Day'     THEN 'D'
+           WHEN new.billing_period = 'Week' THEN 'W'
+           WHEN new.billing_period = 'Biweek' THEN 'BW'
+           WHEN new.billing_period = 'Month' THEN 'M'
+           WHEN new.billing_period = 'Year' THEN 'Y'
+           ELSE NULL
+        END, 
+        new.start_date, 
+        COALESCE(new.notes, '')
+      );
+
+
+CREATE OR REPLACE RULE "_UPDATE" AS ON UPDATE TO api.employee DO INSTEAD
+  
+  UPDATE emp SET 
+    emp_code = new.code, 
+    emp_number = new.number, 
+    emp_active = new.active, 
+    emp_startdate = new.start_date, 
+    emp_cntct_id = savecntct(getcntctid(new.contact_number), 
+                                                               new.contact_number, 
+                                                               saveaddr(getaddrid(new.address_number), 
+                                                                                new.address_number, 
+                                                                                new.address1, 
+                                                                                new.address2, 
+                                                                                new.address3, 
+                                                                                new.city, 
+                                                                                new.state, 
+                                                                                new.postalcode, 
+                                                                                new.country, 
+                                                                                new.address_change), 
+                                                               new.honorific, 
+                                                               new.first, 
+                                                               new.middle, 
+                                                               new.last, 
+                                                               new.suffix, 
+                                                               new.voice,
+                                                               new.alternate,
+                                                               new.fax,
+                                                               new.email,
+                                                               new.web,
+                                                               new.job_title,
+                                                               new.contact_change
+                               ), 
+       emp_warehous_id = getwarehousid(new.site, 'ALL'),
+       emp_mgr_emp_id = ( SELECT emp.emp_id FROM emp WHERE emp.emp_code = new.manager_code), 
+       emp_wage_type = CASE WHEN new.wage_type = 'Hourly'       THEN 'H'
+                                WHEN new.wage_type = 'Salaried' THEN 'S'
+                                ELSE NULL
+                               END, 
+    emp_wage = new.wage, 
+    emp_wage_curr_id = COALESCE(getcurrid(new.wage_currency), basecurrid()), 
+    emp_wage_period = CASE     WHEN new.wage_period = 'Hour' THEN 'H'
+                                               WHEN new.wage_period = 'Day' THEN 'D'
+                                       WHEN new.wage_period = 'Week' THEN 'W'
+                                           WHEN new.wage_period = 'Biweek' THEN 'BW'
+                                       WHEN new.wage_period = 'Month' THEN 'M'
+                                           WHEN new.wage_period = 'Year' THEN 'Y'
+                                       ELSE NULL
+                                     END, 
+       emp_dept_id = getdeptid(new.department), 
+       emp_shift_id = getshiftid(new.shift), 
+       emp_image_id = getimageid(new.image), 
+       emp_extrate = new.rate, 
+       emp_extrate_period = CASE WHEN new.billing_period = 'Hour'      THEN 'H'
+                                         WHEN new.billing_period = 'Day'       THEN 'D'
+                              WHEN new.billing_period = 'Week'         THEN 'W'
+                                             WHEN new.billing_period = 'Biweek' THEN 'BW'
+                                             WHEN new.billing_period = 'Month' THEN 'M'
+                                             WHEN new.billing_period = 'Year'  THEN 'Y'
+                                         ELSE NULL
+                                        END, 
+       emp_notes = COALESCE(new.notes, '')
+  WHERE emp.emp_code = old.code;
+
+
+CREATE OR REPLACE RULE "_DELETE" AS ON DELETE TO api.employee DO INSTEAD  
+    DELETE FROM emp WHERE (emp_code=old.code::text);
+
diff --git a/foundation-database/api/views/employeechar.sql b/foundation-database/api/views/employeechar.sql
new file mode 100644 (file)
index 0000000..c8c2099
--- /dev/null
@@ -0,0 +1,50 @@
+SELECT dropIfExists('VIEW', 'employeechar', 'api');
+CREATE VIEW api.employeechar
+AS
+   SELECT
+     emp_code::varchar AS employee_code,
+     char_name::varchar AS characteristic,
+     charass_value AS value
+   FROM emp, char, charass
+   WHERE (('EMP'=charass_target_type)
+   AND (emp_id=charass_target_id)
+   AND (charass_char_id=char_id));
+
+GRANT ALL ON TABLE api.employeechar TO xtrole;
+COMMENT ON VIEW api.employeechar IS 'Employee Characteristics';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.employeechar DO INSTEAD
+
+  INSERT INTO charass (
+    charass_target_type,
+    charass_target_id,
+    charass_char_id,
+    charass_value,
+    charass_default
+    )
+  VALUES (
+    'EMP',
+    getEmpId(NEW.employee_code),
+    getCharId(NEW.characteristic,'EMP'),
+    NEW.value,
+    false);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.employeechar DO INSTEAD
+
+  UPDATE charass SET
+    charass_value=NEW.value
+  WHERE ((charass_target_type='EMP')
+  AND (charass_target_id=getEmpId(OLD.employee_code))
+  AND (charass_char_id=getCharId(OLD.characteristic,'EMP')));
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.employeechar DO INSTEAD
+
+  DELETE FROM charass
+  WHERE ((charass_target_type='EMP')
+  AND (charass_target_id=getEmpId(OLD.employee_code))
+  AND (charass_char_id=getCharId(OLD.characteristic,'EMP')));
diff --git a/foundation-database/api/views/employeecomment.sql b/foundation-database/api/views/employeecomment.sql
new file mode 100644 (file)
index 0000000..75cfdd1
--- /dev/null
@@ -0,0 +1,43 @@
+SELECT dropIfExists('VIEW', 'employeecomment', 'api');
+CREATE VIEW api.employeecomment
+AS 
+   SELECT 
+     emp_code::varchar AS code,
+     cmnttype_name::varchar AS type,
+     comment_date AS date,
+     comment_user AS username,
+     comment_text AS text
+   FROM emp, cmnttype, comment
+   WHERE ((comment_source='EMP')
+   AND (comment_source_id=emp_id)
+   AND (comment_cmnttype_id=cmnttype_id));
+
+GRANT ALL ON TABLE api.employeecomment TO xtrole;
+COMMENT ON VIEW api.employeecomment IS 'Employee Comment';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.employeecomment DO INSTEAD
+
+  INSERT INTO comment (
+    comment_date,
+    comment_source,
+    comment_source_id,
+    comment_user,
+    comment_cmnttype_id,
+    comment_text
+    )
+  VALUES (
+    COALESCE(NEW.date,now()),
+    'EMP',
+    getEmpId(NEW.code),
+    COALESCE(NEW.username,getEffectiveXtUser()),
+    getCmntTypeId(NEW.type),
+    NEW.text);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.employeecomment DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.employeecomment DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/extshipmaint.sql b/foundation-database/api/views/extshipmaint.sql
new file mode 100644 (file)
index 0000000..30617b6
--- /dev/null
@@ -0,0 +1,96 @@
+  --External Shipping Maintenance View
+
+  SELECT dropifexists('view', 'extshipmaint','api');
+
+  CREATE OR REPLACE VIEW api.extshipmaint AS
+
+  SELECT
+    shipdata_cohead_number::VARCHAR AS so_number,
+    shipdata_shiphead_number::VARCHAR AS shipment_number,
+    shipdata_shipper::VARCHAR AS shipper,
+    shipdata_cosmisc_packnum_tracknum::VARCHAR AS package_tracking_number,
+    shipdata_void_ind AS void,
+    shipdata_billing_option AS billing_option,
+    shipdata_weight AS weight,
+    shipdata_base_freight AS base_freight,
+    base.curr_abbr AS base_freight_currency,
+    shipdata_total_freight AS total_freight,
+    total.curr_abbr AS total_freight_currency,
+    shipdata_package_type AS package_type,
+    shipdata_cosmisc_tracknum AS tracking_number,
+    shipdata_lastupdated AS last_updated
+  FROM shipdata, curr_symbol base, curr_symbol total
+  WHERE ((shipdata_base_freight_curr_id=base.curr_id)
+  AND (shipdata_total_freight_curr_id=total.curr_id))
+  ORDER BY shipdata_cohead_number,shipdata_shiphead_number;
+
+GRANT ALL ON TABLE api.extshipmaint TO xtrole;
+COMMENT ON VIEW api.extshipmaint IS 'External Shipping Maintenance';
+
+  --Rules
+
+  CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.extshipmaint DO INSTEAD
+
+  INSERT INTO shipdata (
+    shipdata_cohead_number,
+    shipdata_shiphead_number,
+    shipdata_void_ind,
+    shipdata_shipper,
+    shipdata_billing_option,
+    shipdata_weight,
+    shipdata_base_freight,
+    shipdata_base_freight_curr_id,
+    shipdata_total_freight,
+    shipdata_total_freight_curr_id,
+    shipdata_package_type,
+    shipdata_cosmisc_tracknum,
+    shipdata_cosmisc_packnum_tracknum,
+    shipdata_lastupdated)
+  VALUES (
+    NEW.so_number,
+    NEW.shipment_number,
+    NEW.void,
+    NEW.shipper,
+    NEW.billing_option,
+    NEW.weight,
+    NEW.base_freight,
+    getCurrId(NEW.base_freight_currency),
+    NEW.total_freight,
+    getCurrId(NEW.total_freight_currency),
+    NEW.package_type,
+    NEW.tracking_number,
+    NEW.package_tracking_number,
+    NEW.last_updated);
+  CREATE OR REPLACE RULE "_UPDATE" AS
+  ON UPDATE TO api.extshipmaint DO INSTEAD
+
+  UPDATE shipdata SET
+    shipdata_cohead_number=NEW.so_number,
+    shipdata_shiphead_number=NEW.shipment_number,
+    shipdata_void_ind=NEW.void,
+    shipdata_shipper=NEW.shipper,
+    shipdata_billing_option=NEW.billing_option,
+    shipdata_weight=NEW.weight,
+    shipdata_base_freight=NEW.base_freight,
+    shipdata_base_freight_curr_id=getCurrId(NEW.base_freight_currency),
+    shipdata_total_freight=NEW.total_freight,
+    shipdata_total_freight_curr_id=getCurrId(NEW.total_freight_currency),
+    shipdata_package_type=NEW.package_type,
+    shipdata_cosmisc_tracknum=NEW.tracking_number,
+    shipdata_cosmisc_packnum_tracknum=NEW.package_tracking_number,
+    shipdata_lastupdated=NEW.last_updated
+  WHERE ((shipdata_cohead_number=OLD.so_number)
+  AND (shipdata_shiphead_number=OLD.shipment_number)
+  AND (shipdata_shipper=OLD.shipper)
+  AND (shipdata_cosmisc_packnum_tracknum=OLD.package_tracking_number));
+
+  CREATE OR REPLACE RULE "_DELETE" AS
+  ON DELETE TO api.extshipmaint DO INSTEAD
+
+  DELETE FROM shipdata 
+  WHERE ((shipdata_cohead_number=OLD.so_number)
+  AND (shipdata_shiphead_number=OLD.shipment_number)
+  AND (shipdata_shipper=OLD.shipper)
+  AND (shipdata_cosmisc_packnum_tracknum=OLD.package_tracking_number));
diff --git a/foundation-database/api/views/freightpricingscheduleitem.sql b/foundation-database/api/views/freightpricingscheduleitem.sql
new file mode 100644 (file)
index 0000000..f44a62b
--- /dev/null
@@ -0,0 +1,94 @@
+-- Freight Pricing Schedule Item
+
+SELECT dropIfExists('VIEW', 'freightpricingscheduleitem', 'api');
+CREATE OR REPLACE VIEW api.freightpricingscheduleitem AS 
+ SELECT 
+   ipshead_name::VARCHAR AS pricing_schedule, 
+   ipsfreight_qtybreak AS qty_break, 
+   qtyuom.uom_name::VARCHAR AS qty_uom, 
+   ipsfreight_price AS price,
+   CASE WHEN (ipsfreight_type='F') THEN 'Flat Rate'
+        ELSE 'Price Per UOM'
+   END AS price_type,
+   COALESCE(warehous_code, 'Any') AS from_site,
+   COALESCE(shipzone_name, 'Any') AS to_shipzone,
+   COALESCE(ipsfreight_shipvia, 'Any') AS ship_via,
+   COALESCE(freightclass_code, 'Any') AS freight_class
+ FROM ipsfreight
+   JOIN ipshead ON (ipsfreight_ipshead_id = ipshead_id)
+   LEFT OUTER JOIN uom qtyuom ON (qtyuom.uom_item_weight)
+   LEFT OUTER JOIN whsinfo ON (warehous_id=ipsfreight_warehous_id)
+   LEFT OUTER JOIN shipzone ON (shipzone_id=ipsfreight_shipzone_id)
+   LEFT OUTER JOIN freightclass ON (freightclass_id=ipsfreight_freightclass_id);
+
+GRANT ALL ON TABLE api.freightpricingscheduleitem TO xtrole;
+COMMENT ON VIEW api.freightpricingscheduleitem IS 'Freight Pricing Schedule Item';
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.freightpricingscheduleitem DO INSTEAD  
+
+  INSERT INTO ipsfreight (
+    ipsfreight_ipshead_id,
+    ipsfreight_qtybreak,
+    ipsfreight_price,
+    ipsfreight_type,
+    ipsfreight_warehous_id,
+    ipsfreight_shipzone_id,
+    ipsfreight_freightclass_id,
+    ipsfreight_shipvia
+    )
+  VALUES (
+    getIpsheadId(NEW.pricing_schedule),
+    NEW.qty_break,
+    NEW.price,
+    CASE WHEN (NEW.price_type = 'Flat Rate') THEN 'F' ELSE 'P' END,
+    CASE WHEN (NEW.from_site = 'Any') THEN NULL ELSE getWarehousId(NEW.from_site, 'All') END,
+    CASE WHEN (NEW.to_shipzone = 'Any') THEN NULL ELSE getShipzoneId(NEW.to_shipzone) END,
+    CASE WHEN (NEW.freight_class = 'Any') THEN NULL ELSE getFreightClassId(NEW.freight_class) END,
+    CASE WHEN (NEW.ship_via = 'Any') THEN NULL ELSE NEW.ship_via END
+    );
+          
+CREATE OR REPLACE RULE "_UPDATE" AS
+  ON UPDATE TO api.freightpricingscheduleitem DO INSTEAD  
+
+  UPDATE ipsfreight SET
+    ipsfreight_ipshead_id = getIpsheadId(OLD.pricing_schedule),
+    ipsfreight_qtybreak = NEW.qty_break,
+    ipsfreight_price = NEW.price,
+    ipsfreight_type = CASE WHEN (NEW.price_type = 'Flat Rate') THEN 'F'
+                           WHEN (NEW.price_type = 'Price Per UOM') THEN 'P' END,
+    ipsfreight_warehous_id = CASE WHEN (NEW.from_site = 'Any') THEN NULL ELSE getWarehousId(NEW.from_site, 'All') END,
+    ipsfreight_shipzone_id = CASE WHEN (NEW.to_shipzone = 'Any') THEN NULL ELSE getShipzoneId(NEW.to_shipzone) END,
+    ipsfreight_freightclass_id = CASE WHEN (NEW.freight_class = 'Any') THEN NULL ELSE getFreightClassId(NEW.freight_class) END,
+    ipsfreight_shipvia = CASE WHEN (NEW.ship_via = 'Any') THEN NULL ELSE NEW.ship_via END
+  WHERE ( (ipsfreight_ipshead_id = getIpsheadId(OLD.pricing_schedule))
+    AND   (ipsfreight_qtybreak = OLD.qty_break)
+    AND   (ipsfreight_price = OLD.price)
+    AND   (ipsfreight_type = CASE WHEN (OLD.price_type = 'Flat Rate') THEN 'F'
+                                  WHEN (OLD.price_type = 'Price Per UOM') THEN 'P' END)
+    AND  (((ipsfreight_warehous_id IS NULL) AND (OLD.from_site = 'Any'))) OR
+          (ipsfreight_warehous_id = CASE WHEN (OLD.from_site = 'Any') THEN 0 ELSE getWarehousId(OLD.from_site, 'All') END)
+    AND  (((ipsfreight_shipzone_id IS NULL) AND (OLD.to_shipzone = 'Any'))) OR
+          (ipsfreight_shipzone_id = CASE WHEN (OLD.to_shipzone = 'Any') THEN 0 ELSE getShipzoneId(OLD.to_shipzone) END)
+    AND  (((ipsfreight_freightclass_id IS NULL) AND (OLD.freight_class = 'Any'))) OR
+          (ipsfreight_freightclass_id = CASE WHEN (OLD.freight_class = 'Any') THEN 0 ELSE getFreightClassId(OLD.freight_class) END)
+    AND  (((ipsfreight_shipvia IS NULL) AND (OLD.ship_via = 'Any'))) OR
+          (ipsfreight_shipvia = OLD.ship_via) );
+
+CREATE OR REPLACE RULE "_DELETE" AS
+  ON DELETE TO api.freightpricingscheduleitem DO INSTEAD  
+
+  DELETE FROM ipsfreight
+  WHERE ( (ipsfreight_ipshead_id = getIpsheadId(OLD.pricing_schedule))
+    AND   (ipsfreight_qtybreak = OLD.qty_break)
+    AND   (ipsfreight_price = OLD.price)
+    AND   (ipsfreight_type = CASE WHEN (OLD.price_type = 'Flat Rate') THEN 'F'
+                                  WHEN (OLD.price_type = 'Price Per UOM') THEN 'P' END)
+    AND  (((ipsfreight_warehous_id IS NULL) AND (OLD.from_site = 'Any'))) OR
+          (ipsfreight_warehous_id = CASE WHEN (OLD.from_site = 'Any') THEN 0 ELSE getWarehousId(OLD.from_site, 'All') END)
+    AND  (((ipsfreight_shipzone_id IS NULL) AND (OLD.to_shipzone = 'Any'))) OR
+          (ipsfreight_shipzone_id = CASE WHEN (OLD.to_shipzone = 'Any') THEN 0 ELSE getShipzoneId(OLD.to_shipzone) END)
+    AND  (((ipsfreight_freightclass_id IS NULL) AND (OLD.freight_class = 'Any'))) OR
+          (ipsfreight_freightclass_id = CASE WHEN (OLD.freight_class = 'Any') THEN 0 ELSE getFreightClassId(OLD.freight_class) END)
+    AND  (((ipsfreight_shipvia IS NULL) AND (OLD.ship_via = 'Any'))) OR
+          (ipsfreight_shipvia = OLD.ship_via) );
diff --git a/foundation-database/api/views/glaccount.sql b/foundation-database/api/views/glaccount.sql
new file mode 100644 (file)
index 0000000..1e67cb0
--- /dev/null
@@ -0,0 +1,87 @@
+--GL Account View
+
+SELECT dropIfExists('VIEW', 'glaccount', 'api');
+CREATE OR REPLACE VIEW api.glaccount AS
+SELECT 
+  accnt_company::varchar AS company,
+  accnt_profit::varchar AS profit_center,
+  accnt_number::varchar AS account_number,
+  accnt_sub::varchar AS sub_account,
+  accnt_descrip AS description,
+  accnt_extref AS ext_reference,
+  CASE
+    WHEN accnt_type='A' THEN 'Asset'
+    WHEN accnt_type='L' THEN 'Liability'
+    WHEN accnt_type='E' THEN 'Expense'
+    WHEN accnt_type='R' THEN 'Revenue'
+    WHEN accnt_type='Q' THEN 'Equity'
+    ELSE '?'
+  END AS type,
+  accnt_subaccnttype_code AS sub_type,
+  accnt_forwardupdate AS forward_update_trial_balances,
+  accnt_comments AS notes
+FROM
+  accnt
+ORDER BY accnt_company, accnt_profit, accnt_number, accnt_sub;
+
+GRANT ALL ON TABLE api.glaccount TO xtrole;
+COMMENT ON VIEW api.glaccount IS 'GL Account';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.glaccount DO INSTEAD
+
+INSERT INTO accnt (
+  accnt_number,
+  accnt_descrip,
+  accnt_comments,
+  accnt_profit,
+  accnt_sub,
+  accnt_type,
+  accnt_extref,
+  accnt_company,
+  accnt_forwardupdate,
+  accnt_subaccnttype_code )
+VALUES (
+  COALESCE(NEW.account_number, ''),
+  COALESCE(NEW.description, ''),
+  COALESCE(NEW.notes, ''),
+  NEW.profit_center,
+  NEW.sub_account,
+  CASE
+    WHEN NEW.type='Asset' THEN 'A'
+    WHEN NEW.type='Liability' THEN 'L'
+    WHEN NEW.type='Expense' THEN 'E'
+    WHEN NEW.type='Revenue' THEN 'R'
+    WHEN NEW.type='Equity' THEN 'Q'
+    ELSE NULL
+  END,
+  COALESCE(NEW.ext_reference, ''),
+  NEW.company,
+  COALESCE(NEW.forward_update_trial_balances, false),
+  COALESCE(NEW.sub_type, '') );
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.glaccount DO INSTEAD
+
+UPDATE accnt SET
+  accnt_number=NEW.account_number,
+  accnt_descrip=NEW.description,
+  accnt_comments=NEW.notes,
+  accnt_profit=NEW.profit_center,
+  accnt_sub=NEW.sub_account,
+  accnt_type=CASE
+               WHEN NEW.type='Asset' THEN 'A'
+               WHEN NEW.type='Liability' THEN 'L'
+               WHEN NEW.type='Expense' THEN 'E'
+               WHEN NEW.type='Revenue' THEN 'R'
+               WHEN NEW.type='Equity' THEN 'Q'
+               ELSE NULL
+             END,
+  accnt_extref=NEW.ext_reference,
+  accnt_company=NEW.company,
+  accnt_forwardupdate=NEW.forward_update_trial_balances,
+  accnt_subaccnttype_code=NEW.sub_type
+WHERE accnt.accnt_id = getglaccntid(old.company::text,old.profit_center::text,old.account_number::text,old.sub_account::text);
diff --git a/foundation-database/api/views/incident.sql b/foundation-database/api/views/incident.sql
new file mode 100644 (file)
index 0000000..d92d79c
--- /dev/null
@@ -0,0 +1,192 @@
+-- Incident View
+
+SELECT dropIfExists('VIEW', 'incident', 'api');
+CREATE OR REPLACE VIEW api.incident AS
+  SELECT
+    incdt_number AS incident_number,
+    incdtcat_name AS category,
+    incdt_summary AS description,
+    crmacct_number AS crm_account,
+    incdt_assigned_username AS assigned_to,
+    CASE
+      WHEN incdt_status='N' THEN
+        'New'
+      WHEN incdt_status='F' THEN
+        'Feedback'
+      WHEN incdt_status='C' THEN
+        'Confirmed'
+      WHEN incdt_status='A' THEN
+        'Assigned'
+      WHEN incdt_status='R' THEN
+        'Resolved'
+      WHEN incdt_status='L' THEN
+        'Closed'
+      ELSE
+        '?'
+    END AS status,
+    incdtseverity_name AS severity,
+    incdtpriority_name AS priority,
+    incdtresolution_name AS resolution,
+    cntct_number AS contact_number,
+    cntct_honorific AS honorific,
+    cntct_first_name AS first,
+    cntct_middle AS middle,
+    cntct_last_name AS last,
+    cntct_suffix AS suffix,
+    cntct_title AS job_title,
+    cntct_phone AS phone,
+    cntct_fax AS fax,
+    cntct_email AS email,
+    (''::TEXT) AS contact_change,
+    incdt_descrip AS notes,
+    item_number AS item_number,
+    incdt_lotserial AS lot_serial_number,
+    CASE
+      WHEN aropen_doctype='C' THEN
+        'C/M'
+      WHEN aropen_doctype='D' THEN
+        'D/M'
+      WHEN aropen_doctype='I' THEN
+        'Invoice'
+      WHEN aropen_doctype='R' THEN
+        'C/D'
+      ELSE
+        ''
+    END AS ar_doc_type,
+    aropen_docnumber AS ar_doc_number
+  FROM incdt
+     LEFT OUTER JOIN incdtcat ON (incdtcat_id=incdt_incdtcat_id)
+     LEFT OUTER JOIN crmacct ON (crmacct_id=incdt_crmacct_id)
+     LEFT OUTER JOIN incdtseverity ON (incdtseverity_id=incdt_incdtseverity_id)
+     LEFT OUTER JOIN incdtpriority ON (incdtpriority_id=incdt_incdtpriority_id)
+     LEFT OUTER JOIN incdtresolution ON (incdtresolution_id=incdt_incdtresolution_id)
+     LEFT OUTER JOIN cntct ON (cntct_id=incdt_cntct_id)
+     LEFT OUTER JOIN item ON (item_id=incdt_item_id)
+     LEFT OUTER JOIN aropen ON (aropen_id=incdt_aropen_id);
+
+GRANT ALL ON TABLE api.incident TO xtrole;
+COMMENT ON VIEW api.incident IS 'Incident';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.incident DO INSTEAD
+
+  INSERT INTO incdt (
+    incdt_number,
+    incdt_crmacct_id,
+    incdt_cntct_id,
+    incdt_summary,
+    incdt_descrip,
+    incdt_item_id,
+    incdt_status,
+    incdt_assigned_username,
+    incdt_incdtcat_id,
+    incdt_incdtseverity_id,
+    incdt_incdtpriority_id,
+    incdt_incdtresolution_id,
+    incdt_lotserial,
+    incdt_ls_id
+    )
+  VALUES (
+    NEW.incident_number,
+    getCrmAcctId(NEW.crm_account),
+    saveCntct(
+      getCntctId(NEW.contact_number),
+      NEW.contact_number,
+      NULL,
+      NEW.honorific,
+      NEW.first,
+      NEW.middle,
+      NEW.last,
+      NEW.suffix,
+      NEW.phone,
+      NULL,
+      NEW.fax,
+      NEW.email,
+      NULL,
+      NEW.job_title,
+      NEW.contact_change),
+    COALESCE(NEW.description, ''),
+    COALESCE(NEW.notes, ''),
+    getItemId(NEW.item_number),
+    CASE
+      WHEN NEW.status='New' THEN
+        'N'
+      WHEN NEW.status='Feedback' THEN
+        'F'
+      WHEN NEW.status='Confirmed' THEN
+        'C'
+      WHEN NEW.status='Assigned' THEN
+        'A'
+      WHEN NEW.status='Resolved' THEN
+        'R'
+      WHEN NEW.status='Closed' THEN
+        'L'
+      ELSE
+        ''
+    END,
+    COALESCE(NEW.assigned_to, ''),
+    getIncdtCatId(NEW.category),
+    getIncdtSeverityId(NEW.severity),
+    getIncdtPriorityId(NEW.priority),
+    getIncdtResolutionId(NEW.resolution),
+    COALESCE(NEW.lot_serial_number, ''),
+    getLotSerialId(NEW.item_number, NEW.lot_serial_number)
+    );
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.incident DO INSTEAD
+
+  UPDATE incdt SET
+    incdt_crmacct_id=getCrmAcctId(NEW.crm_account),
+    incdt_cntct_id=
+     saveCntct(
+      getCntctId(NEW.contact_number),
+      NEW.contact_number,
+      NULL,
+      NEW.honorific,
+      NEW.first,
+      NEW.middle,
+      NEW.last,
+      NEW.suffix,
+      NEW.phone,
+      NULL,
+      NEW.fax,
+      NEW.email,
+      NULL,
+      NEW.job_title,
+      NEW.contact_change),
+    incdt_descrip=NEW.notes,
+    incdt_summary=NEW.description,
+    incdt_item_id=getItemId(NEW.item_number),
+    incdt_status=
+      CASE
+        WHEN NEW.status='New' THEN
+          'N'
+        WHEN NEW.status='Feedback' THEN
+          'F'
+        WHEN NEW.status='Confirmed' THEN
+          'C'
+        WHEN NEW.status='Assigned' THEN
+          'A'
+        WHEN NEW.status='Resolved' THEN
+          'R'
+        WHEN NEW.status='Closed' THEN
+          'L'
+        ELSE
+          NULL
+      END,
+    incdt_assigned_username=NEW.assigned_to,
+    incdt_incdtcat_id=getIncdtCatId(NEW.category),
+    incdt_incdtseverity_id=getIncdtSeverityId(NEW.severity),
+    incdt_incdtpriority_id=getIncdtPriorityId(NEW.priority),
+    incdt_incdtresolution_id=getIncdtResolutionId(NEW.resolution),
+    incdt_lotserial=NEW.lot_serial_number,
+    incdt_ls_id=getLotSerialId(NEW.item_number, NEW.lot_serial_number)
+  WHERE (incdt_id=getIncidentId(OLD.incident_number));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.incident DO INSTEAD
+
+  NOTHING;
diff --git a/foundation-database/api/views/incidentchar.sql b/foundation-database/api/views/incidentchar.sql
new file mode 100644 (file)
index 0000000..23ac1d3
--- /dev/null
@@ -0,0 +1,52 @@
+-- Incident     Characteristic
+
+SELECT dropIfExists('VIEW', 'incidentchar', 'api');
+CREATE VIEW api.incidentchar
+AS 
+   SELECT 
+     incdt_number AS incident_number,
+     char_name::varchar AS characteristic,
+     charass_value AS value
+   FROM incdt, char, charass
+   WHERE (('INCDT'=charass_target_type)
+   AND (incdt_id=charass_target_id)
+   AND (charass_char_id=char_id));
+
+GRANT ALL ON TABLE api.incidentchar TO xtrole;
+COMMENT ON VIEW api.incidentchar IS 'Incident Characteristics';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.incidentchar DO INSTEAD
+
+  INSERT INTO charass (
+    charass_target_type,
+    charass_target_id,
+    charass_char_id,
+    charass_value,
+    charass_default
+    )
+  VALUES (
+    'INCDT',
+    getIncidentId(NEW.incident_number),
+    getCharId(NEW.characteristic,'INCDT'),
+    NEW.value,
+    false);
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.incidentchar DO INSTEAD
+
+  UPDATE charass SET
+    charass_value=NEW.value
+  WHERE ((charass_target_type='INCDT')
+  AND (charass_target_id=getIncidentId(OLD.incident_number))
+  AND (charass_char_id=getCharId(OLD.characteristic,'INCDT')));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.incidentchar DO INSTEAD
+
+  DELETE FROM charass
+  WHERE ((charass_target_type='INCDT')
+  AND (charass_target_id=getIncidentId(OLD.incident_number))
+  AND (charass_char_id=getCharId(OLD.characteristic,'INCDT')));
diff --git a/foundation-database/api/views/incidentcomment.sql b/foundation-database/api/views/incidentcomment.sql
new file mode 100644 (file)
index 0000000..e8fecd6
--- /dev/null
@@ -0,0 +1,33 @@
+
+SELECT dropIfExists('VIEW', 'incidentcomment', 'api');
+
+CREATE OR REPLACE VIEW api.incidentcomment AS 
+ SELECT incdt.incdt_number AS incident_number, cmnttype.cmnttype_name AS type, comment.comment_date AS date, comment.comment_user AS username, comment.comment_text AS text, comment.comment_public AS public
+   FROM incdt, cmnttype, comment
+  WHERE comment.comment_source = 'INCDT'::text AND comment.comment_source_id = incdt.incdt_id AND comment.comment_cmnttype_id = cmnttype.cmnttype_id;
+
+GRANT ALL ON TABLE api.incidentcomment TO xtrole;
+COMMENT ON VIEW api.incidentcomment IS 'Incident Comment';
+
+
+-- Rule: "_DELETE" ON api.incidentcomment
+-- DROP RULE "_DELETE" ON api.incidentcomment;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.incidentcomment DO INSTEAD NOTHING;
+
+-- Rule: "_INSERT" ON api.incidentcomment
+
+-- DROP RULE "_INSERT" ON api.incidentcomment;
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.incidentcomment DO INSTEAD  INSERT INTO comment (comment_date, comment_source, comment_source_id, comment_user, comment_cmnttype_id, comment_text, comment_public) 
+  VALUES (COALESCE(new.date, now()), 'INCDT'::text, getincidentid(new.incident_number), COALESCE(new.username, getEffectiveXtUser()), getcmnttypeid(new.type), new.text, COALESCE(new.public, true));
+
+-- Rule: "_UPDATE" ON api.incidentcomment
+
+-- DROP RULE "_UPDATE" ON api.incidentcomment;
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.incidentcomment DO INSTEAD NOTHING;
+
diff --git a/foundation-database/api/views/incidentfile.sql b/foundation-database/api/views/incidentfile.sql
new file mode 100644 (file)
index 0000000..918f88b
--- /dev/null
@@ -0,0 +1,51 @@
+-- Incident File
+
+SELECT dropifexists('VIEW', 'incidentfile','API'); 
+CREATE VIEW api.incidentfile
+AS 
+   SELECT 
+     incdt_number AS incident_number,
+     url_title AS title,
+     url_url AS url
+   FROM incdt, url
+   WHERE ((incdt_id=url_source_id)
+   AND (url_source='INCDT'));
+
+GRANT ALL ON TABLE api.incidentfile TO xtrole;
+COMMENT ON VIEW api.incidentfile IS 'Incident File';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.incidentfile DO INSTEAD
+
+  INSERT INTO url (
+    url_source_id,
+    url_source,
+    url_title,
+    url_url)
+  VALUES (
+    getIncidentId(NEW.incident_number),
+    'INCDT',
+    NEW.title,
+    NEW.url);
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.incidentfile DO INSTEAD
+
+  UPDATE url SET
+    url_title=NEW.title,
+    url_url=NEW.url
+  WHERE  ((url_source_id=getIncidentId(OLD.incident_number))
+  AND (url_source='INCDT')
+  AND (url_title=OLD.title)
+  AND (url_url=OLD.url));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.incidentfile DO INSTEAD
+
+  DELETE FROM url
+  WHERE  ((url_source_id=getIncidentId(OLD.incident_number))
+  AND (url_source='INCDT')
+  AND (url_title=OLD.title)
+  AND (url_url=OLD.url));
diff --git a/foundation-database/api/views/incidentimage.sql b/foundation-database/api/views/incidentimage.sql
new file mode 100644 (file)
index 0000000..d237665
--- /dev/null
@@ -0,0 +1,43 @@
+-- Incident Image
+
+SELECT dropifexists('VIEW', 'incidentimage','API');
+CREATE VIEW api.incidentimage
+AS 
+   SELECT 
+     incdt_number AS incident_number,
+     image_name AS image_name
+   FROM incdt, imageass, image
+   WHERE ((incdt_id=imageass_source_id)
+   AND (imageass_source='INCDT')
+   AND (imageass_image_id=image_id));
+
+GRANT ALL ON TABLE api.incidentimage TO xtrole;
+COMMENT ON VIEW api.incidentimage IS 'Incident Image';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.incidentimage DO INSTEAD
+
+  SELECT saveImageAss(
+    'INCDT',
+    getIncidentId(NEW.incident_number),
+    'M',
+    getImageId(NEW.image_name));
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.incidentimage DO INSTEAD
+
+  UPDATE imageass
+  SET imageass_image_id=getImageId(NEW.image_name)
+  WHERE ((imageass_source_id=getIncidentId(OLD.incident_number))
+  AND (imageass_source='INCDT')
+  AND (imageass_image_id=getImageId(OLD.image_name)));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.incidentimage DO INSTEAD
+
+  DELETE FROM imageass
+  WHERE ((imageass_source_id=getIncidentId(OLD.incident_number))
+  AND (imageass_source='INCDT')
+  AND (imageass_image_id=getImageId(OLD.image_name)));
diff --git a/foundation-database/api/views/invoice.sql b/foundation-database/api/views/invoice.sql
new file mode 100644 (file)
index 0000000..55448cf
--- /dev/null
@@ -0,0 +1,268 @@
+CREATE OR REPLACE RULE "_INSERT" AS ON INSERT TO api.invoice DO INSTEAD NOTHING;
+SELECT dropIfExists('FUNCTION', 'insertInvoice(api.invoice)');
+SELECT dropIfExists('VIEW', 'invoice', 'api');
+CREATE OR REPLACE VIEW api.invoice
+AS
+       SELECT
+               invchead_invcnumber AS invoice_number,
+               invchead_ordernumber AS order_number,
+               invchead_invcdate AS invoice_date,
+               invchead_shipdate AS ship_date,
+               invchead_orderdate AS order_date,
+                saletype_code AS sale_type,
+               salesrep_number as sales_rep,
+               invchead_commission AS commission,
+               COALESCE(taxzone_code, 'None') AS tax_zone,
+               terms_code AS terms,
+               cust_number AS customer_number,
+               invchead_billto_name AS billto_name,
+               invchead_billto_address1 AS billto_address1,
+               invchead_billto_address2 AS billto_address2,
+               invchead_billto_address3 AS billto_address3,
+               invchead_billto_city AS billto_city,
+               invchead_billto_state AS billto_state,
+               invchead_billto_zipcode AS billto_postal_code,
+               invchead_billto_country AS billto_country,
+               invchead_billto_phone AS billto_phone,
+               shipto_num AS shipto_number,
+               invchead_shipto_name AS shipto_name,
+               invchead_shipto_address1 AS shipto_address1,
+               invchead_shipto_address2 AS shipto_address2,
+               invchead_shipto_address3 AS shipto_address3,
+               invchead_shipto_city AS shipto_city,
+               invchead_shipto_state AS shipto_state,
+               invchead_shipto_zipcode AS shipto_postal_code,
+               invchead_shipto_country AS shipto_country,
+                shipzone_name AS shipto_shipzone,
+               invchead_shipto_phone AS shipto_phone,
+               invchead_ponumber AS po_number,
+               invchead_shipvia AS ship_via,
+               prj_number AS project_number,
+               invchead_fob AS fob,
+               invchead_misc_descrip AS misc_charge_description,
+               invchead_misc_amount AS misc_charge,
+               CASE
+                       WHEN invchead_misc_accnt_id = -1 THEN NULL
+                       ELSE formatglaccount(invchead_misc_accnt_id)
+               END AS misc_charge_account_number,
+               invchead_freight AS freight,
+               curr.curr_abbr AS currency,
+               invchead_payment AS payment,
+               invchead_notes AS notes
+       FROM invchead
+               LEFT OUTER JOIN custinfo ON (cust_id=invchead_cust_id)
+               LEFT OUTER JOIN shiptoinfo ON (shipto_id=invchead_shipto_id)
+               LEFT OUTER JOIN prj ON (prj_id=invchead_prj_id)
+               LEFT OUTER JOIN curr_symbol AS curr ON (curr.curr_id=invchead_curr_id)
+               LEFT OUTER JOIN salesrep ON (salesrep_id=invchead_salesrep_id)
+               LEFT OUTER JOIN terms ON (terms_id=invchead_terms_id)
+               LEFT OUTER JOIN taxzone ON (taxzone_id=invchead_taxzone_id)
+                LEFT OUTER JOIN saletype ON (invchead_saletype_id=saletype_id)
+                LEFT OUTER JOIN shipzone ON (invchead_shipzone_id=shipzone_id)
+;
+       
+GRANT ALL ON TABLE api.invoice TO xtrole;
+COMMENT ON VIEW api.invoice IS '
+This view can be used as an interface to import Invioce Header data directly  
+into the system.  Required fields will be checked and default values will be 
+populated';
+
+
+CREATE OR REPLACE FUNCTION insertInvoice(api.invoice) RETURNS BOOLEAN AS
+$insertInvoice$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+       pNew ALIAS FOR $1;
+BEGIN
+       -- NOTE: (SELECT getCustId(...)) seems redundant, but it actually produces
+       -- a HUGE performance increase because it makes the Postgres query planner
+       -- use an index scan rather than an sequential table scan on cust_id
+       INSERT INTO invchead (
+               invchead_invcnumber,
+               invchead_ordernumber,
+               invchead_invcdate,
+               invchead_shipdate,
+               invchead_orderdate,
+               invchead_printed,
+               invchead_posted,
+               invchead_salesrep_id,
+               invchead_commission,
+               invchead_taxzone_id,
+               invchead_terms_id,
+               invchead_cust_id,
+               invchead_billto_name,
+               invchead_billto_address1,
+               invchead_billto_address2,
+               invchead_billto_address3,
+               invchead_billto_city,
+               invchead_billto_state,
+               invchead_billto_zipcode,
+               invchead_billto_country,
+               invchead_billto_phone,
+               invchead_shipto_id,
+               invchead_shipto_name,
+               invchead_shipto_address1,
+               invchead_shipto_address2,
+               invchead_shipto_address3,
+               invchead_shipto_city,
+               invchead_shipto_state,
+               invchead_shipto_zipcode,
+               invchead_shipto_country,
+               invchead_shipto_phone,
+               invchead_ponumber,
+               invchead_shipvia,
+               invchead_prj_id,
+               invchead_fob,
+               invchead_misc_descrip,
+               invchead_misc_amount,
+               invchead_misc_accnt_id,
+               invchead_freight,
+               invchead_curr_id,
+               invchead_payment,
+               invchead_notes,
+                invchead_saletype_id,
+                invchead_shipzone_id
+       ) SELECT
+               (CASE -- use a case here so we don't unnecessarily fetch a new invoice number
+                       WHEN pNew.invoice_number IS NULL THEN CAST(fetchInvcNumber() AS TEXT)
+                       WHEN pNew.invoice_number = '' THEN CAST(fetchInvcNumber() AS TEXT)
+                       ELSE pNew.invoice_number
+               END),
+               pNew.order_number,
+               COALESCE(pNew.invoice_date, CURRENT_DATE),
+               pNew.ship_date,
+               pNew.order_date,
+               FALSE,
+               FALSE,
+               COALESCE(getSalesRepId(pNew.sales_rep),shipto_salesrep_id,cust_salesrep_id),
+               COALESCE(pNew.commission, 0),
+               CASE
+                       WHEN pNew.tax_zone = 'None' THEN NULL
+                       ELSE COALESCE(getTaxZoneId(pNew.tax_zone),shipto_taxzone_id,cust_taxzone_id)
+               END,
+               COALESCE(getTermsId(pNew.terms),cust_terms_id),
+               (SELECT getCustId(pNew.customer_number)),
+               COALESCE(pNew.billto_name, cohead_billtoname, cust_name),
+               COALESCE(pNew.billto_address1, cohead_billtoaddress1, addr_line1),
+               COALESCE(pNew.billto_address2, cohead_billtoaddress2, addr_line2),
+               COALESCE(pNew.billto_address3, cohead_billtoaddress3, addr_line3),
+               COALESCE(pNew.billto_city, cohead_billtocity, addr_city),
+               COALESCE(pNew.billto_state, cohead_billtostate, addr_state),
+               COALESCE(pNew.billto_postal_code, cohead_billtozipcode, addr_postalcode),
+               COALESCE(pNew.billto_country, cohead_billtocountry, addr_country),
+               COALESCE(pNew.billto_phone, ''),
+               COALESCE(shipto_id,-1),
+               pNew.shipto_name,
+               pNew.shipto_address1,
+               pNew.shipto_address2,
+               pNew.shipto_address3,
+               pNew.shipto_city,
+               pNew.shipto_state,
+               pNew.shipto_postal_code,
+               pNew.shipto_country,
+               pNew.shipto_phone,
+               COALESCE(pNew.po_number, ''),
+               COALESCE(pNew.ship_via,shipto_shipvia,cust_shipvia),
+               COALESCE(getPrjId(pNew.project_number),-1),
+               COALESCE(pNew.fob,fetchDefaultFob((
+                       SELECT CAST(usrpref_value AS INTEGER) 
+                       FROM usrpref, whsinfo
+                       WHERE ((warehous_id=CAST(usrpref_value AS INTEGER))
+                               AND (warehous_shipping)
+                               AND (warehous_active)
+                               AND (usrpref_username=getEffectiveXtUser())
+                               AND (usrpref_name='PreferredWarehouse')
+                       )
+               ))),
+               pNew.misc_charge_description,
+               COALESCE(pNew.misc_charge, 0),
+               COALESCE(getGlAccntId(pNew.misc_charge_account_number),-1),
+               COALESCE(pNew.freight, 0),
+               COALESCE(getCurrId(pNew.currency),(
+                       SELECT cust_curr_id
+                       FROM custinfo
+                       WHERE (cust_id=(SELECT getCustId(pNew.customer_number)))
+               ),basecurrid()),
+               COALESCE(pNew.payment,0),
+               COALESCE(pNew.notes,''),
+                getSaleTypeId(pNew.sale_type),
+                getShipZoneId(pNew.shipto_shipzone)
+       FROM custinfo
+               LEFT OUTER JOIN shiptoinfo ON (shipto_id=(SELECT CASE
+                       WHEN getShiptoId(pNew.customer_number,pNew.shipto_number) IS NOT NULL
+                               THEN getShiptoId(pNew.customer_number,pNew.shipto_number)
+                       ELSE (SELECT shipto_id FROM shiptoinfo WHERE shipto_cust_id=cust_id AND shipto_default)
+               END))
+               LEFT OUTER JOIN cohead ON (cohead_number=pNEW.order_number)
+               LEFT OUTER JOIN cntct ON (cntct_id=cust_cntct_id)
+               LEFT OUTER JOIN addr ON (addr_id=cntct_addr_id)
+       WHERE cust_id = (SELECT getCustId(pNew.customer_number));
+       RETURN TRUE;
+END;
+$insertInvoice$ LANGUAGE 'plpgsql';
+
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+       ON INSERT TO api.invoice DO INSTEAD
+               SELECT insertInvoice(NEW);
+
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+       ON UPDATE TO api.invoice DO INSTEAD
+
+       UPDATE invchead SET
+               invchead_invcnumber=OLD.invoice_number,
+               invchead_ordernumber=NEW.order_number,
+               invchead_invcdate=NEW.invoice_date,
+               invchead_shipdate=NEW.ship_date,
+               invchead_orderdate=NEW.order_date,
+               invchead_salesrep_id=getSalesRepId(NEW.sales_rep),
+               invchead_commission=NEW.commission,
+               invchead_taxzone_id=getTaxZoneId(NULLIF(NEW.tax_zone, 'None')),
+               invchead_terms_id=getTermsId(NEW.terms),
+               invchead_cust_id=(SELECT getCustId(NEW.customer_number)),
+               invchead_billto_name=NEW.billto_name,
+               invchead_billto_address1=NEW.billto_address1,
+               invchead_billto_address2=NEW.billto_address2,
+               invchead_billto_address3=NEW.billto_address3,
+               invchead_billto_city=NEW.billto_city,
+               invchead_billto_state=NEW.billto_state,
+               invchead_billto_zipcode=NEW.billto_postal_code,
+               invchead_billto_country=NEW.billto_country,
+               invchead_billto_phone=NEW.billto_phone,
+               invchead_shipto_id=COALESCE(getShiptoId(NEW.customer_number,NEW.shipto_number),-1),
+               invchead_shipto_name=NEW.shipto_name,
+               invchead_shipto_address1=NEW.shipto_address1,
+               invchead_shipto_address2=NEW.shipto_address2,
+               invchead_shipto_address3=NEW.shipto_address3,
+               invchead_shipto_city=NEW.shipto_city,
+               invchead_shipto_state=NEW.shipto_state,
+               invchead_shipto_zipcode=NEW.shipto_postal_code,
+               invchead_shipto_country=NEW.shipto_country,
+               invchead_shipto_phone=NEW.shipto_phone,
+               invchead_ponumber=NEW.po_number,
+               invchead_shipvia=NEW.ship_via,
+               invchead_prj_id=COALESCE(getPrjId(NEW.project_number),-1),
+               invchead_fob=NEW.fob,
+               invchead_misc_descrip=NEW.misc_charge_description,
+               invchead_misc_amount=NEW.misc_charge,
+               invchead_misc_accnt_id=COALESCE(getGlAccntId(NEW.misc_charge_account_number),-1),
+               invchead_freight=NEW.freight,
+               invchead_curr_id=COALESCE(getCurrId(NEW.currency),-1),
+               invchead_payment=NEW.payment,
+               invchead_notes=NEW.notes,
+                invchead_saletype_id=getSaleTypeId(NEW.sale_type),
+                invchead_shipzone_id=getShipZoneId(NEW.shipto_shipzone)
+       WHERE (invchead_invcnumber=OLD.invoice_number)
+               AND (invchead_posted = FALSE);
+
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+       ON DELETE TO api.invoice DO INSTEAD
+       
+       SELECT deleteInvoice(invchead_id)
+       FROM invchead
+       WHERE invchead_invcnumber = OLD.invoice_number AND invchead_posted = FALSE;
diff --git a/foundation-database/api/views/invoiceline.sql b/foundation-database/api/views/invoiceline.sql
new file mode 100644 (file)
index 0000000..32a03da
--- /dev/null
@@ -0,0 +1,230 @@
+CREATE OR REPLACE RULE "_INSERT" AS
+       ON INSERT TO api.invoiceline DO INSTEAD NOTHING;
+CREATE OR REPLACE RULE "_UPDATE" AS
+       ON UPDATE TO api.invoiceline DO INSTEAD NOTHING;
+SELECT dropIfExists('FUNCTION', 'insertInvoiceLineItem(api.invoiceline)');
+SELECT dropIfExists('FUNCTION', 'updateInvoiceLineItem(api.invoiceline, api.invoiceline)');
+SELECT dropIfExists('VIEW', 'invoiceline', 'api');
+CREATE OR REPLACE VIEW api.invoiceline
+AS
+       SELECT
+               invchead_invcnumber AS invoice_number,
+               invcitem_linenumber AS line_number,
+               item_number,
+               invcitem_number AS misc_item_number,
+               warehous_code AS site,
+               invcitem_descrip AS misc_item_description,
+               salescat_name as sales_category,
+               invcitem_custpn AS customer_part_number,
+               invcitem_ordered AS qty_ordered,
+               invcitem_billed AS qty_billed,
+                invcitem_updateinv AS update_inventory,
+               invcitem_price AS net_unit_price,
+               COALESCE(taxtype_name, 'None') AS tax_type,
+               COALESCE(qty_uom.uom_name, 'None') AS qty_uom,
+               COALESCE(price_uom.uom_name, 'None') AS price_uom,
+               invcitem_notes AS notes,
+                CASE WHEN (invcitem_rev_accnt_id IS NOT NULL) THEN formatglaccount(invcitem_rev_accnt_id)
+                     ELSE NULL::text
+                END AS alternate_rev_account
+       FROM invcitem
+               LEFT OUTER JOIN invchead ON (invcitem_invchead_id=invchead_id)
+               LEFT OUTER JOIN item ON (item_id=invcitem_item_id)
+               LEFT OUTER JOIN whsinfo ON (invcitem_warehous_id=warehous_id)
+               LEFT OUTER JOIN salescat ON (salescat_id=invcitem_salescat_id)
+               LEFT OUTER JOIN taxtype ON (taxtype_id=invcitem_taxtype_id)
+               LEFT OUTER JOIN uom AS qty_uom ON (qty_uom.uom_id=invcitem_qty_uom_id)
+               LEFT OUTER JOIN uom AS price_uom ON (price_uom.uom_id=invcitem_price_uom_id);
+       
+GRANT ALL ON TABLE api.invoiceline TO xtrole;
+COMMENT ON VIEW api.invoiceline IS '
+This view can be used as an interface to import Invoice Line Items data directly
+into the system.  Required fields will be checked and default values will be
+populated';
+
+
+CREATE OR REPLACE FUNCTION insertInvoiceLineItem(api.invoiceline) RETURNS BOOLEAN AS
+$insertInvoiceLineItem$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+       pNew ALIAS FOR $1;
+       _r RECORD;
+BEGIN
+       INSERT INTO invcitem (
+               invcitem_invchead_id,
+               invcitem_linenumber,
+               invcitem_item_id,
+               invcitem_warehous_id,
+               invcitem_custpn,
+               invcitem_number,
+               invcitem_descrip,
+               invcitem_ordered,
+               invcitem_billed,
+                invcitem_updateinv,
+               invcitem_custprice,
+               invcitem_price,
+               invcitem_notes,
+               invcitem_salescat_id,
+               invcitem_taxtype_id,
+               invcitem_qty_uom_id,
+               invcitem_qty_invuomratio,
+               invcitem_price_uom_id,
+               invcitem_price_invuomratio,
+                invcitem_rev_accnt_id
+       ) SELECT
+               invchead_id,
+               COALESCE(pNew.line_number,(
+                       SELECT (COALESCE(MAX(invcitem_linenumber), 0) + 1)
+                       FROM invcitem WHERE (invcitem_invchead_id=invchead_id)
+               )),
+               COALESCE(item_id, -1),
+               COALESCE(getwarehousid(pNew.site,'ALL'),-1),
+               pNew.customer_part_number,
+               (CASE WHEN item_id IS NULL THEN pNew.misc_item_number ELSE NULL END),
+               (CASE WHEN item_id IS NULL THEN pNew.misc_item_description ELSE NULL END),
+               pNew.qty_ordered,
+               COALESCE(pNew.qty_billed, 0),
+                COALESCE(pNew.update_inventory,FALSE),
+               0, -- invcitem_custprice
+               COALESCE(pNew.net_unit_price,itemPrice(item_id,invchead_cust_id,
+                       invchead_shipto_id,pNew.qty_ordered,invchead_curr_id,invchead_orderdate)),
+               COALESCE(pNew.notes,''),
+               CASE
+                       WHEN item_id IS NULL THEN
+                               (SELECT salescat_id FROM salescat WHERE salescat_name = pNew.sales_category)
+                       ELSE NULL
+               END,
+               taxtype_id,
+               CASE
+                       WHEN item_id IS NOT NULL THEN
+                               COALESCE((SELECT uom_id FROM uom WHERE (uom_name=pNew.qty_uom)), item_price_uom_id)
+                       ELSE NULL
+               END,
+               CASE
+                       WHEN item_id IS NOT NULL THEN
+                               itemuomtouomratio(item_id,
+                                       COALESCE((SELECT uom_id FROM uom WHERE uom_name=pNew.qty_uom),item_price_uom_id),
+                                       item_price_uom_id
+                               )
+                       ELSE 1
+               END,
+               CASE
+                       WHEN item_id IS NOT NULL THEN
+                               COALESCE((SELECT uom_id FROM uom WHERE uom_name=pNew.price_uom),item_price_uom_id)
+                       ELSE NULL
+               END,
+               CASE
+                       WHEN item_id IS NOT NULL THEN
+                               itemuomtouomratio(item_id,
+                                       COALESCE((SELECT uom_id FROM uom WHERE uom_name=pNew.price_uom),item_price_uom_id),
+                                       item_price_uom_id
+                               )
+                       ELSE 1
+               END,
+                getGlAccntId(pNew.alternate_rev_account)
+       FROM invchead
+               LEFT OUTER JOIN item ON (item_id=getItemId(pNew.item_number))
+               LEFT OUTER JOIN taxtype ON (taxtype_id=CASE
+                       WHEN pNew.tax_type IS NULL THEN getItemTaxType(item_id,invchead_taxzone_id)
+                       WHEN pNew.tax_type = 'None' THEN NULL
+                       ELSE (SELECT taxtype_id FROM taxtype WHERE taxtype_name=pNew.tax_type)
+               END)
+       WHERE (invchead_invcnumber=pNew.invoice_number) AND (invchead_posted=FALSE);
+       RETURN TRUE;
+END;
+$insertInvoiceLineItem$ LANGUAGE 'plpgsql';
+
+
+CREATE OR REPLACE FUNCTION updateInvoiceLineItem(api.invoiceline, api.invoiceline) RETURNS BOOLEAN AS
+$updateInvoiceLineItem$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+       pNew ALIAS FOR $1;
+       pOld ALIAS FOR $2;
+       _r RECORD;
+BEGIN
+       UPDATE invcitem SET
+               invcitem_linenumber=pNew.line_number,
+               invcitem_item_id=COALESCE(item_id, -1),
+               invcitem_custpn=pNew.customer_part_number,
+               invcitem_number=(CASE WHEN item_id IS NULL THEN pNew.misc_item_number ELSE NULL END),
+               invcitem_warehous_id=(CASE WHEN invcitem_warehous_id IS NULL THEN COALESCE(getwarehousid(pNew.site,'ALL'),-1) ELSE NULL END),
+               invcitem_descrip=(CASE WHEN item_id IS NULL THEN pNew.misc_item_description ELSE NULL END),
+               invcitem_ordered=pNew.qty_ordered,
+               invcitem_billed=COALESCE(pNew.qty_billed, 0),
+                invcitem_updateinv=COALESCE(pNew.update_inventory,FALSE),
+               invcitem_price=COALESCE(pNew.net_unit_price,itemPrice(item_id,invchead_cust_id,
+                       invchead_shipto_id,pNew.qty_ordered,invchead_curr_id,invchead_orderdate)),
+               invcitem_notes=COALESCE(pNew.notes,''),
+               invcitem_salescat_id=CASE
+                       WHEN item_id IS NULL THEN
+                               (SELECT salescat_id FROM salescat WHERE salescat_name = pNew.sales_category)
+                       ELSE NULL
+               END,
+               invcitem_taxtype_id=taxtype_id,
+               invcitem_qty_uom_id=CASE
+                       WHEN item_id IS NOT NULL THEN
+                               COALESCE((SELECT uom_id FROM uom WHERE (uom_name=pNew.qty_uom)), item_price_uom_id)
+                       ELSE NULL
+               END,
+               invcitem_qty_invuomratio=CASE
+                       WHEN item_id IS NOT NULL THEN
+                               itemuomtouomratio(item_id,
+                                       COALESCE((SELECT uom_id FROM uom WHERE uom_name=pNew.qty_uom),item_price_uom_id),
+                                       item_price_uom_id
+                               )
+                       ELSE 1
+               END,
+               invcitem_price_uom_id=CASE
+                       WHEN item_id IS NOT NULL THEN
+                               COALESCE((SELECT uom_id FROM uom WHERE uom_name=pNew.price_uom),item_price_uom_id)
+                       ELSE NULL
+               END,
+               invcitem_price_invuomratio=CASE
+                       WHEN item_id IS NOT NULL THEN
+                               itemuomtouomratio(item_id,
+                                       COALESCE((SELECT uom_id FROM uom WHERE uom_name=pNew.price_uom),item_price_uom_id),
+                                       item_price_uom_id
+                               )
+                       ELSE 1
+               END,
+                invcitem_rev_accnt_id=getGlAccntId(alternate_rev_account)
+       FROM invchead
+               LEFT OUTER JOIN item ON (item_id=getItemId(pNew.item_number))
+               LEFT OUTER JOIN taxtype ON (taxtype_id=CASE
+                       WHEN pNew.tax_type IS NULL THEN getItemTaxType(item_id,invchead_taxzone_id)
+                       WHEN pNew.tax_type = 'None' THEN NULL
+                       ELSE (SELECT taxtype_id FROM taxtype WHERE taxtype_name=pNew.tax_type)
+               END)
+       WHERE invcitem_invchead_id=invchead_id
+               AND invcitem_linenumber=pOld.line_number
+               AND invchead_invcnumber=pOld.invoice_number
+               AND invchead_posted=FALSE;
+       RETURN TRUE;
+END;
+$updateInvoiceLineItem$ LANGUAGE 'plpgsql';
+
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+       ON INSERT TO api.invoiceline DO INSTEAD
+               SELECT insertInvoiceLineItem(NEW);
+
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+       ON UPDATE TO api.invoiceline DO INSTEAD
+               SELECT updateInvoiceLineItem(NEW, OLD);
+
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+       ON DELETE TO api.invoiceline DO INSTEAD
+       
+       DELETE FROM invcitem
+       WHERE invcitem_invchead_id=(
+               SELECT invchead_id FROM invchead
+               WHERE invchead_invcnumber=OLD.invoice_number
+                       AND invchead_posted = FALSE
+       );
diff --git a/foundation-database/api/views/item.sql b/foundation-database/api/views/item.sql
new file mode 100644 (file)
index 0000000..622c050
--- /dev/null
@@ -0,0 +1,204 @@
+  --Item View
+
+  SELECT dropIfExists('VIEW', 'item', 'api');
+  CREATE OR REPLACE VIEW api.item AS
+
+  SELECT
+    item_number::varchar AS item_number,
+    item_active AS active,
+    item_descrip1 AS description1,
+    item_descrip2 AS description2,
+    CASE
+      WHEN item_type = 'P' THEN
+        'Purchased'
+      WHEN item_type = 'M' THEN
+        'Manufactured'
+      WHEN item_type = 'J' THEN
+        'Job'
+      WHEN item_type = 'K' THEN
+        'Kit'
+      WHEN item_type = 'F' THEN
+        'Phantom'
+      WHEN item_type = 'R' THEN
+        'Reference'
+      WHEN item_type = 'S' THEN
+        'Costing'
+      WHEN item_type = 'T' THEN
+        'Tooling'
+      WHEN item_type = 'O' THEN
+        'Outside Process'
+      WHEN item_type = 'L' THEN
+        'Planning'
+      WHEN item_type = 'B' THEN
+        'Breeder'
+      WHEN item_type = 'C' THEN
+        'Co-Product'
+      WHEN item_type = 'Y' THEN
+        'By-Product'
+    END AS item_type,
+    item_maxcost AS maximum_desired_cost,
+    classcode_code AS class_code,
+    i.uom_name AS inventory_uom,
+    item_picklist AS pick_list_item,
+    item_fractional AS fractional,
+    item_config AS configured,
+    item_sold AS item_is_sold,
+    prodcat_code AS product_category,
+    item_exclusive AS exclusive,
+    item_listprice AS list_price,
+    item_listcost AS list_cost,
+    p.uom_name AS list_price_uom,
+    item_upccode AS upc_code,
+    item_prodweight AS product_weight,
+    item_packweight AS packaging_weight,
+    item_comments AS notes,
+    item_extdescrip AS ext_description
+  FROM item
+         LEFT OUTER JOIN prodcat ON (item_prodcat_id=prodcat_id), 
+         classcode, uom AS i, uom AS p
+  WHERE ((item_classcode_id=classcode_id)
+  AND (item_inv_uom_id=i.uom_id)
+  AND (item_price_uom_id=p.uom_id))
+  ORDER BY item_number;
+
+GRANT ALL ON TABLE api.item TO xtrole;
+COMMENT ON VIEW api.item IS 'Item';
+
+  --Rules
+
+  CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.item DO INSTEAD
+
+  INSERT INTO item
+          (item_number,
+           item_active,
+           item_descrip1,
+           item_descrip2,
+           item_type,
+           item_maxcost,
+           item_classcode_id,
+           item_inv_uom_id,
+           item_picklist,
+           item_fractional,
+           item_config,
+           item_sold,
+           item_prodcat_id,
+           item_exclusive,
+           item_listprice,
+           item_listcost,
+           item_price_uom_id,
+           item_upccode,
+           item_prodweight,
+           item_packweight,
+           item_comments,
+           item_extdescrip)
+          VALUES
+          (UPPER(NEW.item_number),
+           COALESCE(NEW.active,TRUE),
+           COALESCE(NEW.description1,''),
+           COALESCE(NEW.description2,''),
+           CASE
+             WHEN NEW.item_type = 'Purchased' THEN
+               'P'
+             WHEN NEW.item_type = 'Manufactured' THEN
+               'M'
+             WHEN NEW.item_type = 'Job' THEN
+               'J'
+             WHEN NEW.item_type = 'Kit' THEN
+               'K'
+             WHEN NEW.item_type = 'Phantom' THEN
+               'F'
+             WHEN NEW.item_type = 'Reference' THEN
+               'R'
+             WHEN NEW.item_type = 'Costing' THEN
+               'S'
+             WHEN NEW.item_type = 'Tooling' THEN
+               'T'
+             WHEN NEW.item_type = 'Outside Process' THEN
+               'O'
+             WHEN NEW.item_type = 'Planning' THEN
+               'L'
+             WHEN NEW.item_type = 'Breeder' THEN
+               'B'
+             WHEN NEW.item_type = 'Co-Product' THEN
+               'C'
+             WHEN NEW.item_type = 'By-Product' THEN
+               'Y'
+           END,
+           COALESCE(NEW.maximum_desired_cost,0),
+           getClassCodeId(NEW.class_code),
+           getUomId(NEW.inventory_uom),
+           COALESCE(NEW.pick_list_item,TRUE),
+           COALESCE(NEW.fractional,FALSE),
+           COALESCE(NEW.configured,FALSE),
+           COALESCE(NEW.item_is_sold,TRUE),
+           COALESCE(getProdCatId(NEW.product_category),-1),
+           COALESCE(NEW.exclusive,FALSE),
+           COALESCE(NEW.list_price,0),
+           COALESCE(NEW.list_cost,0),
+           COALESCE(getUomId(NEW.list_price_uom),getUomId(NEW.inventory_uom)),
+           NEW.upc_code,
+           COALESCE(NEW.product_weight,0),
+           COALESCE(NEW.packaging_weight,0),
+           NEW.notes,
+           NEW.ext_description);
+    CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.item DO INSTEAD
+
+    UPDATE item SET
+      item_active=NEW.active,
+      item_descrip1=NEW.description1,
+      item_descrip2=NEW.description2,
+      item_type=
+           CASE
+             WHEN NEW.item_type = 'Purchased' THEN
+               'P'
+             WHEN NEW.item_type = 'Manufactured' THEN
+               'M'
+             WHEN NEW.item_type = 'Job' THEN
+               'J'
+             WHEN NEW.item_type = 'Kit' THEN
+               'K'
+             WHEN NEW.item_type = 'Phantom' THEN
+               'F'
+             WHEN NEW.item_type = 'Reference' THEN
+               'R'
+             WHEN NEW.item_type = 'Costing' THEN
+               'S'
+             WHEN NEW.item_type = 'Tooling' THEN
+               'T'
+             WHEN NEW.item_type = 'Outside Process' THEN
+               'O'
+             WHEN NEW.item_type = 'Planning' THEN
+               'L'
+             WHEN NEW.item_type = 'Breeder' THEN
+               'B'
+             WHEN NEW.item_type = 'Co-Product' THEN
+               'C'
+             WHEN NEW.item_type = 'By-Product' THEN
+               'Y'
+           END,
+      item_maxcost=NEW.maximum_desired_cost,
+      item_classcode_id=getClassCodeId(NEW.class_code),
+      item_inv_uom_id=getUomId(NEW.inventory_uom),
+      item_picklist=NEW.pick_list_item,
+      item_fractional=NEW.fractional,
+      item_config=NEW.configured,
+      item_sold=NEW.item_is_sold,
+      item_prodcat_id=COALESCE(getProdCatId(NEW.product_category),-1),
+      item_exclusive=NEW.exclusive,
+      item_listprice=NEW.list_price,
+      item_listcost=NEW.list_cost,
+      item_price_uom_id=getUomId(NEW.list_price_uom),
+      item_upccode=NEW.upc_code,
+      item_prodweight=NEW.product_weight,
+      item_packweight=NEW.packaging_weight,
+      item_comments=NEW.notes,
+      item_extdescrip=NEW.ext_description
+    WHERE (item_id=getItemId(OLD.item_number));
+
+    CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.item DO INSTEAD
+
+    SELECT deleteitem(getItemId(OLD.item_number));
diff --git a/foundation-database/api/views/itemalias.sql b/foundation-database/api/views/itemalias.sql
new file mode 100644 (file)
index 0000000..1b1e99e
--- /dev/null
@@ -0,0 +1,56 @@
+-- Item Alias
+
+SELECT dropIfExists('VIEW', 'itemalias', 'api');
+CREATE VIEW api.itemalias
+AS 
+   SELECT 
+     item_number::varchar AS item_number,
+     itemalias_number AS alias_number,
+     itemalias_usedescrip AS use_description,
+     itemalias_descrip1 AS description1,
+     itemalias_descrip2 AS description2,
+     itemalias_comments AS comments
+   FROM item, itemalias
+   WHERE (item_id=itemalias_item_id);
+
+GRANT ALL ON TABLE api.itemalias TO xtrole;
+COMMENT ON VIEW api.itemalias IS 'Item Alias';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.itemalias DO INSTEAD
+
+  INSERT INTO itemalias (
+    itemalias_item_id,
+    itemalias_number,
+    itemalias_usedescrip,
+    itemalias_descrip1,
+    itemalias_descrip2,
+    itemalias_comments)
+  VALUES (
+    getItemId(NEW.item_number),
+    NEW.alias_number,
+    COALESCE(NEW.use_description,FALSE),
+    COALESCE(NEW.description1,''),
+    COALESCE(NEW.description2,''),
+    NEW.comments);
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.itemalias DO INSTEAD
+
+  UPDATE itemalias SET
+    itemalias_number=NEW.alias_number,
+    itemalias_usedescrip=NEW.use_description,
+    itemalias_descrip1=NEW.description1,
+    itemalias_descrip2=NEW.description2,
+    itemalias_comments=NEW.comments
+  WHERE  ((itemalias_item_id=getItemId(OLD.item_number))
+  AND (itemalias_number=OLD.alias_number));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.itemalias DO INSTEAD
+
+  DELETE FROM itemalias
+  WHERE  ((itemalias_item_id=getItemId(OLD.item_number))
+  AND (itemalias_number=OLD.alias_number));
diff --git a/foundation-database/api/views/itemchar.sql b/foundation-database/api/views/itemchar.sql
new file mode 100644 (file)
index 0000000..ba62bbb
--- /dev/null
@@ -0,0 +1,54 @@
+-- Item Characteristic
+
+SELECT dropIfExists('VIEW', 'itemchar', 'api');
+CREATE VIEW api.itemchar
+AS 
+   SELECT 
+     item_number::varchar AS item_number,
+     char_name::varchar AS characteristic,
+     charass_value AS value,
+     charass_default AS is_default
+   FROM item, char, charass
+   WHERE (('I'=charass_target_type)
+   AND (item_id=charass_target_id)
+   AND (charass_char_id=char_id));
+
+GRANT ALL ON TABLE api.itemchar TO xtrole;
+COMMENT ON VIEW api.itemchar IS 'Item Characteristic';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.itemchar DO INSTEAD
+
+  INSERT INTO charass (
+    charass_target_type,
+    charass_target_id,
+    charass_char_id,
+    charass_value,
+    charass_default
+    )
+  VALUES (
+    'I',
+    getItemId(NEW.item_number),
+    getCharId(NEW.characteristic,'I'),
+    NEW.value,
+    COALESCE(NEW.is_default,false));
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.itemchar DO INSTEAD
+
+  UPDATE charass SET
+    charass_value=NEW.value,
+    charass_default=NEW.is_default
+  WHERE ((charass_target_type='I')
+  AND (charass_target_id=getItemId(OLD.item_number))
+  AND (charass_char_id=getCharId(OLD.characteristic,'I')));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.itemchar DO INSTEAD
+
+  DELETE FROM charass
+  WHERE ((charass_target_type='I')
+  AND (charass_target_id=getItemId(OLD.item_number))
+  AND (charass_char_id=getCharId(OLD.characteristic,'I')));
diff --git a/foundation-database/api/views/itemcomment.sql b/foundation-database/api/views/itemcomment.sql
new file mode 100644 (file)
index 0000000..dd5067f
--- /dev/null
@@ -0,0 +1,46 @@
+-- Item Comment
+
+SELECT dropIfExists('VIEW', 'itemcomment', 'api');
+CREATE VIEW api.itemcomment
+AS 
+   SELECT 
+     item_number::varchar AS item_number,
+     cmnttype_name AS type,
+     comment_date AS date,
+     comment_user AS username,
+     comment_text AS text
+   FROM item, cmnttype, comment
+   WHERE ((comment_source='I')
+   AND (comment_source_id=item_id)
+   AND (comment_cmnttype_id=cmnttype_id));
+
+GRANT ALL ON TABLE api.itemcomment TO admin;
+GRANT ALL ON TABLE api.itemcomment TO xtrole;
+COMMENT ON VIEW api.itemcomment IS 'Item Comments';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.itemcomment DO INSTEAD
+
+  INSERT INTO comment (
+    comment_date,
+    comment_source,
+    comment_source_id,
+    comment_user,
+    comment_cmnttype_id,
+    comment_text
+    )
+  VALUES (
+    COALESCE(NEW.date,now()),
+    'IS',
+    getItemId(NEW.item_number),
+    COALESCE(NEW.username,getEffectiveXtUser()),
+    getCmntTypeId(NEW.type),
+    NEW.text);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.itemcomment DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.itemcomment DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/itemcost.sql b/foundation-database/api/views/itemcost.sql
new file mode 100644 (file)
index 0000000..9acd913
--- /dev/null
@@ -0,0 +1,45 @@
+-- Item Cost
+
+SELECT dropIfExists('VIEW', 'itemcost', 'api');
+CREATE OR REPLACE VIEW api.itemcost
+AS 
+  SELECT item.item_number::character varying(100) AS item_number,
+         costelem.costelem_type::character varying(100) AS costing_element,
+         itemcost.itemcost_actcost AS actual_cost,
+         curr_symbol.curr_abbr AS currency,
+         false AS post_to_standard
+  FROM itemcost
+       LEFT JOIN item ON (itemcost.itemcost_item_id = item.item_id)
+       LEFT JOIN costelem ON (itemcost.itemcost_costelem_id = costelem.costelem_id)
+       LEFT JOIN curr_symbol ON (itemcost.itemcost_curr_id = curr_symbol.curr_id)
+ ORDER BY item.item_number::character varying(100), costelem.costelem_type::character varying(100);
+
+GRANT ALL ON TABLE api.itemcost TO xtrole;
+COMMENT ON VIEW api.itemcost IS 'Item Cost';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+  ON INSERT TO api.itemcost DO INSTEAD
+
+  SELECT insertItemCost(getItemId(NEW.item_number),
+                        getCostElemId(NEW.costing_element),
+                        getCurrId(NEW.currency),
+                        NEW.actual_cost,
+                        NEW.post_to_standard);
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+  ON UPDATE TO api.itemcost DO INSTEAD
+
+  SELECT updateItemCost(getItemId(NEW.item_number),
+                        getCostElemId(NEW.costing_element),
+                        getCurrId(NEW.currency),
+                        NEW.actual_cost,
+                        NEW.post_to_standard);
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+  ON DELETE TO api.itemcost DO INSTEAD
+
+  SELECT deleteItemCost(getItemId(OLD.item_number),
+                        getCostElemId(OLD.costing_element));
+
diff --git a/foundation-database/api/views/itemfile.sql b/foundation-database/api/views/itemfile.sql
new file mode 100644 (file)
index 0000000..1346ac3
--- /dev/null
@@ -0,0 +1,51 @@
+-- Item File
+SELECT dropIfExists('VIEW', 'itemfile', 'api'); 
+CREATE VIEW api.itemfile
+AS 
+   SELECT 
+     item_number::varchar AS item_number,
+     url_title AS title,
+     url_url AS url
+   FROM item, url
+   WHERE ((item_id=url_source_id)
+   AND (url_source='I'));
+
+GRANT ALL ON TABLE api.itemfile TO xtrole;
+COMMENT ON VIEW api.itemfile IS 'Item File';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.itemfile DO INSTEAD
+
+  INSERT INTO url (
+    url_source_id,
+    url_source,
+    url_title,
+    url_url)
+  VALUES (
+    getItemId(NEW.item_number),
+    'I',
+    NEW.title,
+    NEW.url);
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.itemfile DO INSTEAD
+
+  UPDATE url SET
+    url_title=NEW.title,
+    url_url=NEW.url
+  WHERE  ((url_source_id=getItemId(OLD.item_number))
+  AND (url_source='I')
+  AND (url_title=OLD.title)
+  AND (url_url=OLD.url));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.itemfile DO INSTEAD
+
+  DELETE FROM url
+  WHERE  ((url_source_id=getItemId(OLD.item_number))
+  AND (url_source='I')
+  AND (url_title=OLD.title)
+  AND (url_url=OLD.url));
diff --git a/foundation-database/api/views/itemimage.sql b/foundation-database/api/views/itemimage.sql
new file mode 100644 (file)
index 0000000..22647f5
--- /dev/null
@@ -0,0 +1,77 @@
+-- Item Image
+
+SELECT dropIfExists('VIEW', 'itemimage', 'api');
+CREATE VIEW api.itemimage
+AS 
+   SELECT 
+     item_number::varchar AS item_number,
+     CASE
+       WHEN imageass_purpose = 'P' THEN
+        'Product Description'
+       WHEN imageass_purpose = 'I' THEN
+        'Inventory Description'
+       WHEN imageass_purpose = 'E' THEN
+        'Engineering Reference'
+       WHEN imageass_purpose = 'M' THEN
+        'Miscellaneous'
+       ELSE
+        'Other'
+     END AS purpose,
+     image_name AS image_name
+   FROM item, imageass, image
+   WHERE ((item_id=imageass_source_id)
+   AND (imageass_source='I')
+   AND (imageass_image_id=image_id));
+
+GRANT ALL ON TABLE api.itemimage TO xtrole;
+COMMENT ON VIEW api.itemimage IS 'Item Image';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.itemimage DO INSTEAD
+
+  SELECT saveImageAss(
+    'I',
+    getItemId(NEW.item_number),
+    CASE
+      WHEN NEW.purpose = 'Product Description' THEN
+        'P'
+      WHEN NEW.purpose = 'Inventory Description' THEN
+        'I'
+      WHEN NEW.purpose = 'Engineering Reference' THEN
+        'E'
+      WHEN NEW.purpose = 'Miscellaneous' THEN
+        'M'
+      ELSE
+        'X'
+     END,
+    getImageId(NEW.image_name));
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.itemimage DO INSTEAD
+
+  SELECT saveImageAss(
+    'I',
+    getItemId(NEW.item_number),
+    CASE
+      WHEN NEW.purpose = 'Product Description' THEN
+        'P'
+      WHEN NEW.purpose = 'Inventory Description' THEN
+        'I'
+      WHEN NEW.purpose = 'Engineering Reference' THEN
+        'E'
+      WHEN NEW.purpose = 'Miscellaneous' THEN
+        'M'
+      ELSE
+        'X'
+     END,
+    getImageId(NEW.image_name));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.itemimage DO INSTEAD
+
+  DELETE FROM imageass
+  WHERE ((imageass_source_id=getItemId(OLD.item_number))
+  AND (imageass_source='I')
+  AND (imageass_image_id=getImageId(OLD.image_name)));
diff --git a/foundation-database/api/views/itemsite.sql b/foundation-database/api/views/itemsite.sql
new file mode 100644 (file)
index 0000000..970152c
--- /dev/null
@@ -0,0 +1,345 @@
+-- Item Site
+
+SELECT dropIfExists('VIEW', 'itemsite', 'api');
+CREATE VIEW api.itemsite
+AS 
+   SELECT
+     item_number::varchar AS item_number,
+     warehous_code::varchar AS site,
+     itemsite_active AS active,
+     itemsite_wosupply AS wo_supplied_at_site,
+     itemsite_createwo AS create_wos,
+     itemsite_posupply AS po_supplied_at_site,
+     itemsite_createpr AS create_prs,
+     itemsite_createsopr AS create_soprs,
+     itemsite_createsopo AS create_sopos,
+     itemsite_dropship AS dropship,
+     itemsite_sold AS sold_from_site,
+     itemsite_soldranking AS ranking,
+     CASE
+       WHEN itemsite_costmethod = 'N' THEN
+         'None'
+       WHEN itemsite_costmethod = 'A' THEN
+         'Average'
+       WHEN itemsite_costmethod = 'S' THEN
+         'Standard'
+       WHEN itemsite_costmethod = 'J' THEN
+         'Job'
+     END AS cost_method,     
+     CASE
+       WHEN itemsite_controlmethod = 'N' THEN
+         'None'
+       WHEN itemsite_controlmethod = 'R' THEN
+         'Regular'
+       WHEN itemsite_controlmethod = 'S' THEN
+         'Serial #'
+       WHEN itemsite_controlmethod = 'L' THEN
+         'Lot #'
+     END AS control_method,
+     plancode_code AS planner_code,
+     costcat_code AS cost_category,
+     itemsite_stocked AS stocked,
+     itemsite_abcclass AS abc_class,
+     itemsite_autoabcclass AS allow_automatic_updates,
+     itemsite_cyclecountfreq AS cycl_cnt_freq,
+     itemsite_eventfence AS event_fence,
+     itemsite_loccntrl AS multiple_location_control,
+     formatlocationname(itemsite_location_id) AS location,
+     formatlocationname(itemsite_recvlocation_id) AS receive_location,
+     formatlocationname(itemsite_issuelocation_id) AS issue_location,
+     itemsite_location_dist AS auto_distr_location,
+     itemsite_recvlocation_dist AS auto_distr_receive_location,
+     itemsite_issuelocation_dist AS auto_distr_issue_location,
+     itemsite_location AS user_defined_location,
+     itemsite_location_comments AS location_comment,
+     itemsite_disallowblankwip AS disallow_blank_wip_locations,
+     itemsite_useparams AS enforce_order_parameters,
+     itemsite_reorderlevel AS reorder_level,
+     itemsite_ordertoqty AS order_up_to,
+     itemsite_minordqty AS minimum_order,
+     itemsite_maxordqty AS maximum_order,
+     itemsite_multordqty AS order_multiple,
+     itemsite_useparamsmanual AS enforce_on_manual_orders,
+     CASE
+       WHEN itemsite_planning_type = 'N' THEN
+         'None'
+       WHEN itemsite_planning_type = 'M' THEN
+         'MRP'
+       WHEN itemsite_planning_type = 'S' THEN
+         'MPS'
+     END AS planning_system,
+     itemsite_ordergroup AS group_mps_mrp_orders,
+     itemsite_ordergroup_first AS first_group,
+     itemsite_mps_timefence AS mps_time_fence,
+     itemsite_leadtime AS lead_time,
+     itemsite_safetystock AS safety_stock,
+     COALESCE( (SELECT warehous_code
+                FROM itemsite supplysite JOIN whsinfo ON (warehous_id=supplysite.itemsite_warehous_id)
+                WHERE supplysite.itemsite_id=itemsite.itemsite_supply_itemsite_id), 'None') AS supplied_from_site,
+     itemsite_notes AS notes,
+     itemsite_perishable AS perishable,
+     itemsite_warrpurc AS require_warranty,
+     itemsite_autoreg AS auto_register
+   FROM itemsite JOIN item ON (item_id=itemsite_item_id)
+                 JOIN plancode ON (plancode_id=itemsite_plancode_id)
+                 JOIN costcat ON (costcat_id=itemsite_costcat_id)
+                 JOIN whsinfo ON (warehous_id=itemsite_warehous_id);
+
+GRANT ALL ON TABLE api.itemsite TO xtrole;
+COMMENT ON VIEW api.itemsite IS 'Item Site';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.itemsite DO INSTEAD
+
+INSERT INTO itemsite (
+     itemsite_item_id,
+     itemsite_warehous_id,
+     itemsite_active,
+     itemsite_dropship,
+     itemsite_posupply,
+     itemsite_createpr,
+     itemsite_wosupply,
+     itemsite_createwo,
+     itemsite_createsopr,
+     itemsite_createsopo,
+     itemsite_sold,
+     itemsite_soldranking,
+     itemsite_costmethod,
+     itemsite_controlmethod,
+     itemsite_perishable,
+     itemsite_plancode_id,
+     itemsite_costcat_id,
+     itemsite_loccntrl,
+     itemsite_location_id,
+     itemsite_recvlocation_id,
+     itemsite_issuelocation_id,
+     itemsite_location_dist,
+     itemsite_recvlocation_dist,
+     itemsite_issuelocation_dist,
+     itemsite_location,
+     itemsite_location_comments,
+     itemsite_disallowblankwip,
+     itemsite_stocked,
+     itemsite_abcclass,
+     itemsite_autoabcclass,
+     itemsite_cyclecountfreq,
+     itemsite_eventfence,
+     itemsite_useparams,
+     itemsite_reorderlevel,
+     itemsite_ordertoqty,
+     itemsite_minordqty,
+     itemsite_maxordqty,
+     itemsite_multordqty,
+     itemsite_useparamsmanual,
+     itemsite_ordergroup,
+     itemsite_ordergroup_first,
+     itemsite_mps_timefence,
+     itemsite_leadtime,
+     itemsite_safetystock,
+     itemsite_supply_itemsite_id,
+     itemsite_notes,
+     itemsite_qtyonhand,
+     itemsite_warrpurc,
+     itemsite_autoreg,
+     itemsite_freeze,
+     itemsite_value,
+     itemsite_planning_type)
+     VALUES (
+       getItemId(NEW.item_number),
+       getWarehousId(NEW.site,'ACTIVE'),
+       COALESCE(NEW.active,TRUE),
+       COALESCE(NEW.dropship,FALSE),
+       COALESCE(NEW.po_supplied_at_site,FALSE),
+       COALESCE(NEW.create_prs,FALSE),
+       COALESCE(NEW.wo_supplied_at_site,FALSE),
+       COALESCE(NEW.create_wos,FALSE),
+       COALESCE(NEW.create_soprs,FALSE),
+       COALESCE(NEW.create_sopos,FALSE),
+       COALESCE(NEW.sold_from_site,TRUE),
+       COALESCE(NEW.ranking,1),
+       CASE
+         WHEN NEW.cost_method = 'None' THEN
+           'N'
+         WHEN NEW.cost_method = 'Average' THEN
+           'A'
+         WHEN NEW.cost_method = 'Standard' THEN
+           'S'
+         WHEN NEW.cost_method = 'Job' THEN
+           'J'
+       END,
+       CASE
+         WHEN NEW.control_method = 'None' THEN
+           'N'
+         WHEN NEW.control_method = 'Regular' THEN
+           'R'
+         WHEN NEW.control_method = 'Serial #' THEN
+           'S'
+         WHEN NEW.control_method = 'Lot #' THEN
+           'L'
+       END,
+       COALESCE(NEW.perishable,FALSE),
+       getPlanCodeId(NEW.planner_code),
+       getCostCatId(NEW.cost_category),
+       COALESCE(NEW.multiple_location_control,FALSE),
+       COALESCE(getLocationId(NEW.site,NEW.location),-1),
+       COALESCE(getLocationId(NEW.site,NEW.receive_location),-1),
+       COALESCE(getLocationId(NEW.site,NEW.issue_location),-1),
+       COALESCE(NEW.auto_distr_location,FALSE),
+       COALESCE(NEW.auto_distr_receive_location,FALSE),
+       COALESCE(NEW.auto_distr_issue_location,FALSE),
+       COALESCE(NEW.user_defined_location,''),
+       COALESCE(NEW.location_comment,''),
+       COALESCE(NEW.disallow_blank_wip_locations,FALSE),
+       COALESCE(NEW.stocked,FALSE),
+       COALESCE(NEW.abc_class,'A'),
+       COALESCE(NEW.allow_automatic_updates,FALSE),
+       COALESCE(NEW.cycl_cnt_freq,0),
+       COALESCE(NEW.event_fence,fetchMetricValue('DefaultEventFence')),
+       COALESCE(NEW.enforce_order_parameters,FALSE),
+       COALESCE(NEW.reorder_level,0),
+       COALESCE(NEW.order_up_to,0),
+       COALESCE(NEW.minimum_order,0),
+       COALESCE(NEW.maximum_order,0),
+       COALESCE(NEW.order_multiple,0),
+       COALESCE(NEW.enforce_on_manual_orders,FALSE),
+       COALESCE(NEW.group_mps_mrp_orders,0),
+       COALESCE(NEW.first_group,FALSE),
+       COALESCE(NEW.mps_time_fence,0),
+       COALESCE(NEW.lead_time,0),
+       COALESCE(NEW.safety_stock,0),
+       CASE
+         WHEN NEW.supplied_from_site = 'None' THEN
+           NULL
+         WHEN NEW.supplied_from_site = '' THEN
+           NULL
+         ELSE
+           getItemsiteId(NEW.supplied_from_site, NEW.item_number)
+       END,
+       COALESCE(NEW.notes,''),
+       0,
+       COALESCE(NEW.require_warranty,FALSE),
+       COALESCE(NEW.auto_register,FALSE),
+       false,
+       0,
+       CASE
+         WHEN NEW.planning_system = 'None' THEN
+           'N'
+         WHEN NEW.planning_system = 'MPS' THEN
+           'S'
+         ELSE
+           'M'
+       END );
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.itemsite DO INSTEAD
+
+UPDATE itemsite SET 
+     itemsite_active=NEW.active,
+     itemsite_dropship=NEW.dropship,
+     itemsite_posupply=NEW.po_supplied_at_site,
+     itemsite_createpr=NEW.create_prs,
+     itemsite_wosupply=NEW.wo_supplied_at_site,
+     itemsite_createwo=NEW.create_wos,
+     itemsite_createsopr=NEW.create_soprs,
+     itemsite_createsopo=NEW.create_sopos,
+     itemsite_sold=NEW.sold_from_site,
+     itemsite_soldranking=NEW.ranking,
+     itemsite_costmethod=
+       CASE
+         WHEN NEW.cost_method = 'None' THEN
+           'N'
+         WHEN NEW.cost_method = 'Average' THEN
+           'A'
+         WHEN NEW.cost_method = 'Standard' THEN
+           'S'
+         WHEN NEW.cost_method = 'Job' THEN
+           'J'
+       END,
+     itemsite_controlmethod=
+       CASE
+         WHEN NEW.control_method = 'None' THEN
+           'N'
+         WHEN NEW.control_method = 'Regular' THEN
+           'R'
+         WHEN NEW.control_method = 'Serial #' THEN
+           'S'
+         WHEN NEW.control_method = 'Lot #' THEN
+           'L'
+       END,
+     itemsite_perishable=NEW.perishable,
+     itemsite_plancode_id=getPlanCodeId(NEW.planner_code),
+     itemsite_costcat_id=getCostCatId(NEW.cost_category),
+     itemsite_loccntrl=NEW.multiple_location_control,
+     itemsite_location_id=
+     CASE
+       WHEN (NEW.location = 'N/A') THEN
+         -1
+       ELSE
+         getLocationId(NEW.site,NEW.location)
+     END,
+     itemsite_recvlocation_id=
+     CASE
+       WHEN (NEW.receive_location = 'N/A') THEN
+         -1
+       ELSE
+         getLocationId(NEW.site,NEW.receive_location)
+     END,
+     itemsite_issuelocation_id=
+     CASE
+       WHEN (NEW.issue_location = 'N/A') THEN
+         -1
+       ELSE
+         getLocationId(NEW.site,NEW.issue_location)
+     END,
+     itemsite_location_dist=NEW.auto_distr_location,
+     itemsite_recvlocation_dist=NEW.auto_distr_receive_location,
+     itemsite_issuelocation_dist=NEW.auto_distr_issue_location,
+     itemsite_location=NEW.user_defined_location,
+     itemsite_location_comments=NEW.user_defined_location,
+     itemsite_disallowblankwip=NEW.disallow_blank_wip_locations,
+     itemsite_stocked=NEW.stocked,
+     itemsite_abcclass=NEW.abc_class,
+     itemsite_autoabcclass=NEW.allow_automatic_updates,
+     itemsite_cyclecountfreq=NEW.cycl_cnt_freq,
+     itemsite_eventfence=NEW.event_fence,
+     itemsite_useparams=NEW.enforce_order_parameters,
+     itemsite_reorderlevel=NEW.reorder_level,
+     itemsite_ordertoqty=NEW.order_up_to,
+     itemsite_minordqty=NEW.minimum_order,
+     itemsite_maxordqty=NEW.maximum_order,
+     itemsite_multordqty=NEW.order_multiple,
+     itemsite_useparamsmanual=NEW.enforce_on_manual_orders,
+     itemsite_ordergroup=NEW.group_mps_mrp_orders,
+     itemsite_ordergroup_first=NEW.first_group,
+     itemsite_mps_timefence=NEW.mps_time_fence,
+     itemsite_leadtime=NEW.lead_time,
+     itemsite_safetystock=NEW.safety_stock,
+     itemsite_supply_itemsite_id=
+       CASE
+         WHEN NEW.supplied_from_site = 'None' THEN
+           NULL
+         WHEN NEW.supplied_from_site = '' THEN
+           NULL
+         ELSE
+           getItemsiteId(NEW.supplied_from_site, NEW.item_number)
+       END,
+     itemsite_notes=NEW.notes,
+     itemsite_warrpurc=NEW.require_warranty,
+     itemsite_autoreg=NEW.auto_register,
+     itemsite_planning_type=
+       CASE
+         WHEN NEW.planning_system = 'None' THEN
+           'N'
+         WHEN NEW.planning_system = 'MPS' THEN
+           'S'
+         ELSE
+           'M'
+       END
+   WHERE (itemsite_id=getItemSiteId(OLD.site,OLD.item_number));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.itemsite DO INSTEAD
+
+   SELECT deleteitemsite(getItemSiteId(OLD.site,OLD.item_number));
diff --git a/foundation-database/api/views/itemsitecomment.sql b/foundation-database/api/views/itemsitecomment.sql
new file mode 100644 (file)
index 0000000..4948e46
--- /dev/null
@@ -0,0 +1,49 @@
+-- Item Site Comment
+
+SELECT dropIfExists('VIEW', 'itemsitecomment', 'api');
+CREATE VIEW api.itemsitecomment
+AS 
+   SELECT 
+     item_number::varchar,
+     warehous_code::varchar AS site,
+     cmnttype_name AS type,
+     comment_date AS date,
+     comment_user AS username,
+     comment_text AS text
+   FROM itemsite, item, whsinfo, cmnttype, comment
+   WHERE (itemsite_item_id=item_id)
+   AND (itemsite_warehous_id=warehous_id
+   AND (comment_source='IS')
+   AND (comment_source_id=itemsite_id)
+   AND (comment_cmnttype_id=cmnttype_id));
+
+GRANT ALL ON TABLE api.itemsitecomment TO admin;
+GRANT ALL ON TABLE api.itemsitecomment TO xtrole;
+COMMENT ON VIEW api.itemsitecomment IS 'Item Site Comments';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.itemsitecomment DO INSTEAD
+
+  INSERT INTO comment (
+    comment_date,
+    comment_source,
+    comment_source_id,
+    comment_user,
+    comment_cmnttype_id,
+    comment_text
+    )
+  VALUES (
+    COALESCE(NEW.date,now()),
+    'IS',
+    getItemSiteId(NEW.site,NEW.item_number),
+    COALESCE(NEW.username,getEffectiveXtUser()),
+    getCmntTypeId(NEW.type),
+    NEW.text);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.itemsitecomment DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.itemsitecomment DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/itemsource.sql b/foundation-database/api/views/itemsource.sql
new file mode 100644 (file)
index 0000000..d695048
--- /dev/null
@@ -0,0 +1,120 @@
+-- Item Source
+
+SELECT dropIfExists('VIEW', 'itemsource', 'api');
+
+CREATE VIEW api.itemsource AS
+  SELECT item.item_number::VARCHAR AS item_number,
+       vendinfo.vend_number::VARCHAR AS vendor, 
+       itemsrc.itemsrc_vend_item_number AS vendor_item_number, 
+       itemsrc.itemsrc_active AS active,
+       itemsrc.itemsrc_default AS itemsrc_default,
+       itemsrc.itemsrc_vend_uom AS vendor_uom, 
+       itemsrc.itemsrc_invvendoruomratio AS inventory_vendor_uom_ratio, 
+       itemsrc.itemsrc_minordqty AS minimum_order, 
+       itemsrc.itemsrc_multordqty AS order_multiple,  
+       itemsrc.itemsrc_ranking AS vendor_ranking, 
+       itemsrc.itemsrc_leadtime AS lead_time,
+       itemsrc.itemsrc_comments AS notes, 
+       itemsrc.itemsrc_vend_item_descrip AS vendor_description,
+       itemsrc.itemsrc_manuf_name AS manufacturer_name,
+       itemsrc.itemsrc_manuf_item_number AS manufacturer_item_number,
+       itemsrc.itemsrc_manuf_item_descrip AS manufacturer_description,
+       itemsrc.itemsrc_upccode AS bar_code,
+       contrct.contrct_number AS contract_number,
+       itemsrc.itemsrc_effective AS effective_date,
+       itemsrc.itemsrc_expires AS expires_date
+   FROM itemsrc
+   LEFT JOIN item ON itemsrc.itemsrc_item_id = item.item_id
+   LEFT JOIN vendinfo ON itemsrc.itemsrc_vend_id = vendinfo.vend_id
+   LEFT JOIN contrct ON itemsrc.itemsrc_contrct_id = contrct.contrct_id
+  ORDER BY item.item_number::VARCHAR(100), vendinfo.vend_number::VARCHAR(100);
+        
+GRANT ALL ON TABLE api.itemsource TO xtrole;
+COMMENT ON VIEW api.itemsource IS 'Item Source';
+
+-- Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.itemsource DO INSTEAD
+    
+  INSERT INTO itemsrc (
+    itemsrc_item_id, 
+    itemsrc_vend_id, 
+    itemsrc_vend_item_number, 
+    itemsrc_vend_item_descrip, 
+    itemsrc_comments, 
+    itemsrc_vend_uom, 
+    itemsrc_invvendoruomratio, 
+    itemsrc_minordqty, 
+    itemsrc_multordqty, 
+    itemsrc_leadtime, 
+    itemsrc_ranking, 
+    itemsrc_active,
+    itemsrc_default,
+    itemsrc_manuf_name,
+    itemsrc_manuf_item_number,
+    itemsrc_manuf_item_descrip,
+    itemsrc_upccode,
+    itemsrc_contrct_id,
+    itemsrc_effective,
+    itemsrc_expires) 
+  VALUES (
+    getitemid(NEW.item_number), 
+    getvendid(NEW.vendor), 
+    NEW.vendor_item_number, 
+    COALESCE(NEW.vendor_description, ''), 
+    COALESCE(NEW.notes, ''), 
+    NEW.vendor_uom, 
+    NEW.inventory_vendor_uom_ratio, 
+    NEW.minimum_order, 
+    NEW.order_multiple, 
+    NEW.lead_time, 
+    NEW.vendor_ranking, 
+    COALESCE(NEW.active, true),
+    COALESCE(NEW.itemsrc_default, true),
+    COALESCE(NEW.manufacturer_name,''),
+    COALESCE(NEW.manufacturer_item_number,''),
+    NEW.manufacturer_description,
+    NEW.bar_code,
+    getcontrctid(NEW.contract_number),
+    COALESCE(getcontrcteffective(NEW.contract_number), NEW.effective_date),
+    COALESCE(getcontrctexpires(NEW.contract_number), NEW.expires_date))
+;
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.itemsource DO INSTEAD
+    
+  UPDATE itemsrc SET 
+    itemsrc_vend_item_number = NEW.vendor_item_number, 
+    itemsrc_vend_item_descrip = NEW.vendor_description, 
+    itemsrc_comments = NEW.notes, 
+    itemsrc_vend_uom = NEW.vendor_uom, 
+    itemsrc_invvendoruomratio = NEW.inventory_vendor_uom_ratio, 
+    itemsrc_minordqty = NEW.minimum_order, 
+    itemsrc_multordqty = NEW.order_multiple, 
+    itemsrc_leadtime = NEW.lead_time, 
+    itemsrc_ranking = NEW.vendor_ranking, 
+    itemsrc_active = NEW.active,
+    itemsrc_default = NEW.itemsrc_default,
+    itemsrc_manuf_name = NEW.manufacturer_name,
+    itemsrc_manuf_item_number = NEW.manufacturer_item_number,
+    itemsrc_manuf_item_descrip = NEW.manufacturer_description,
+    itemsrc_upccode=NEW.bar_code,
+    itemsrc_contrct_id=getcontrctid(NEW.contract_number),
+    itemsrc_effective=COALESCE(getcontrcteffective(NEW.contract_number), NEW.effective_date),
+    itemsrc_expires=COALESCE(getcontrctexpires(NEW.contract_number), NEW.expires_date)
+  WHERE ((itemsrc.itemsrc_item_id = getitemid(old.item_number)) 
+  AND (itemsrc.itemsrc_vend_id = getvendid(old.vendor))
+  AND (itemsrc.itemsrc_vend_item_number=old.vendor_item_number)
+  AND (itemsrc.itemsrc_manuf_name=old.manufacturer_name)
+  AND (itemsrc.itemsrc_manuf_item_number=old.manufacturer_item_number));
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.itemsource DO INSTEAD
+    
+  DELETE FROM itemsrc
+  WHERE ((itemsrc.itemsrc_item_id = getitemid(old.item_number)) 
+  AND (itemsrc.itemsrc_vend_id = getvendid(old.vendor))
+  AND (itemsrc.itemsrc_vend_item_number=old.vendor_item_number)
+  AND (itemsrc.itemsrc_manuf_name=old.manufacturer_name)
+  AND (itemsrc.itemsrc_manuf_item_number=old.manufacturer_item_number));
diff --git a/foundation-database/api/views/itemsourceprice.sql b/foundation-database/api/views/itemsourceprice.sql
new file mode 100644 (file)
index 0000000..54978b2
--- /dev/null
@@ -0,0 +1,84 @@
+-- Item Source Price View
+
+SELECT dropIfExists('VIEW', 'itemsourceprice', 'api');
+
+CREATE VIEW api.itemsourceprice AS
+  SELECT item.item_number::VARCHAR AS item_number, 
+        vendinfo.vend_number::VARCHAR AS vendor, 
+         itemsrcp.itemsrcp_qtybreak AS qty_break,
+         CASE WHEN (itemsrcp.itemsrcp_type='N') THEN 'Nominal'
+              ELSE 'Discount'
+         END AS pricing_type,
+         CASE WHEN (itemsrcp.itemsrcp_warehous_id=-1) THEN 'All'
+              ELSE whsinfo.warehous_code
+         END AS pricing_site,
+         itemsrcp.itemsrcp_dropship AS dropship_only,
+         itemsrcp.itemsrcp_price AS price_per_unit,  
+         curr_symbol.curr_abbr AS currency,
+         (itemsrcp.itemsrcp_discntprcnt * 100.0) AS discount_percent,
+         itemsrcp.itemsrcp_fixedamtdiscount AS discount_fixed_amount
+   FROM itemsrcp
+   LEFT JOIN itemsrc ON itemsrc.itemsrc_id = itemsrcp.itemsrcp_itemsrc_id
+   LEFT JOIN item ON itemsrc.itemsrc_item_id = item.item_id
+   LEFT JOIN vendinfo ON itemsrc.itemsrc_vend_id = vendinfo.vend_id
+   LEFT JOIN curr_symbol ON itemsrcp.itemsrcp_curr_id = curr_symbol.curr_id
+   LEFT JOIN whsinfo ON itemsrcp.itemsrcp_warehous_id = whsinfo.warehous_id
+  ORDER BY item.item_number::VARCHAR(100), vendinfo.vend_number::VARCHAR(100);
+
+GRANT ALL ON TABLE api.itemsourceprice TO xtrole;
+COMMENT ON VIEW api.itemsourceprice IS 'Item Source Price';
+
+-- Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.itemsourceprice DO INSTEAD
+
+  INSERT INTO itemsrcp (
+    itemsrcp_itemsrc_id, 
+    itemsrcp_qtybreak, 
+    itemsrcp_price, 
+    itemsrcp_curr_id,
+    itemsrcp_updated,
+    itemsrcp_dropship,
+    itemsrcp_warehous_id,
+    itemsrcp_type,
+    itemsrcp_discntprcnt,
+    itemsrcp_fixedamtdiscount) 
+    VALUES(
+    getItemSrcId(new.item_number,new.vendor),
+    new.qty_break,
+    new.price_per_unit,
+    getCurrId(new.currency),
+    now(),
+    COALESCE(new.dropship_only, FALSE),
+    CASE WHEN (new.pricing_site='All') THEN -1
+         ELSE COALESCE(getWarehousId(new.pricing_site, 'ALL'), -1) END,
+    CASE WHEN (new.pricing_type='Discount') THEN 'D'
+         ELSE 'N' END,
+    (COALESCE(new.discount_percent, 0.0) / 100.0),
+    new.discount_fixed_amount);
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.itemsourceprice DO INSTEAD
+
+  UPDATE itemsrcp SET 
+    itemsrcp_qtybreak = new.qty_break, 
+    itemsrcp_price = new.price_per_unit,
+    itemsrcp_updated = now(), 
+    itemsrcp_curr_id = getcurrid(new.currency),
+    itemsrcp_dropship=COALESCE(new.dropship_only, FALSE),
+    itemsrcp_warehous_id=CASE WHEN (new.pricing_site='All') THEN -1
+                              ELSE COALESCE(getWarehousId(new.pricing_site, 'ALL'), -1) END,
+    itemsrcp_type=CASE WHEN (new.pricing_type='Discount') THEN 'D'
+                       ELSE 'N' END,
+    itemsrcp_discntprcnt=(COALESCE(new.discount_percent, 0.0) / 100.0),
+    itemsrcp_fixedamtdiscount=new.discount_fixed_amount
+  WHERE (itemsrcp_itemsrc_id=getItemSrcId(old.item_number,new.vendor)
+  AND (itemsrcp_qtybreak=old.qty_break));
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.itemsourceprice DO INSTEAD
+    
+  DELETE FROM itemsrcp
+  WHERE (itemsrcp_itemsrc_id=getItemSrcId(old.item_number,old.vendor)
+  AND (itemsrcp_qtybreak=old.qty_break));
diff --git a/foundation-database/api/views/itemsubstitute.sql b/foundation-database/api/views/itemsubstitute.sql
new file mode 100644 (file)
index 0000000..63fa0ad
--- /dev/null
@@ -0,0 +1,48 @@
+-- Item Substitute
+
+SELECT dropIfExists('VIEW', 'itemsubstitute', 'api');
+CREATE VIEW api.itemsubstitute
+AS 
+   SELECT 
+     p.item_number::varchar AS root_item_number,
+     s.item_number::varchar AS substitute_item_number,
+     itemsub_uomratio AS sub_parent_uom_ratio,
+     itemsub_rank AS ranking
+   FROM item p, item s, itemsub
+   WHERE ((p.item_id=itemsub_parent_item_id)
+   AND (s.item_id=itemsub_sub_item_id));
+
+GRANT ALL ON TABLE api.itemsubstitute TO xtrole;
+COMMENT ON VIEW api.itemsubstitute IS 'Item Substitute';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.itemsubstitute DO INSTEAD
+
+  INSERT INTO itemsub (
+    itemsub_parent_item_id,
+    itemsub_sub_item_id,
+    itemsub_uomratio,
+    itemsub_rank)
+  VALUES (
+    getItemId(NEW.root_item_number),
+    getItemId(NEW.substitute_item_number),
+    COALESCE(NEW.sub_parent_uom_ratio,1),
+    COALESCE(NEW.ranking,1));
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.itemsubstitute DO INSTEAD
+
+  UPDATE itemsub SET
+    itemsub_uomratio=NEW.sub_parent_uom_ratio,
+    itemsub_rank=NEW.ranking
+  WHERE  ((itemsub_parent_item_id=getItemId(OLD.root_item_number))
+  AND (itemsub_sub_item_id=getItemId(OLD.substitute_item_number)));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.itemsubstitute DO INSTEAD
+
+  DELETE FROM itemsub
+  WHERE  ((itemsub_parent_item_id=getItemId(OLD.root_item_number))
+  AND (itemsub_sub_item_id=getItemId(OLD.substitute_item_number)));
diff --git a/foundation-database/api/views/itemtaxtype.sql b/foundation-database/api/views/itemtaxtype.sql
new file mode 100644 (file)
index 0000000..60f881c
--- /dev/null
@@ -0,0 +1,71 @@
+-- Item Tax Type
+
+SELECT dropIfExists('VIEW', 'itemtaxtype', 'api');
+CREATE VIEW api.itemtaxtype
+AS 
+   SELECT 
+     item_number::varchar AS item_number,
+     CASE
+       WHEN (taxzone_id IS NULL) THEN
+         'Any'::varchar
+       ELSE
+         taxzone_code::varchar
+     END AS tax_zone,
+     taxtype_name AS tax_type
+   FROM item, itemtax
+     LEFT OUTER JOIN taxzone ON (itemtax_taxzone_id=taxzone_id),
+     taxtype
+   WHERE ((item_id=itemtax_item_id)
+   AND (itemtax_taxtype_id=taxtype_id));
+
+GRANT ALL ON TABLE api.itemtaxtype TO xtrole;
+COMMENT ON VIEW api.itemtaxtype IS 'Item Tax Type';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.itemtaxtype DO INSTEAD
+
+  INSERT INTO itemtax (
+    itemtax_item_id,
+    itemtax_taxzone_id,
+    itemtax_taxtype_id)
+  VALUES (
+    getItemId(NEW.item_number),
+    CASE
+      WHEN (NEW.tax_zone = 'Any') THEN
+        NULL
+      ELSE
+        getTaxZoneId(NEW.tax_zone)
+    END,
+    getTaxTypeId(NEW.tax_type));
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.itemtaxtype DO INSTEAD
+
+  UPDATE itemtax SET
+    itemtax_taxzone_id=
+    CASE
+      WHEN (NEW.tax_zone = 'Any') THEN
+        NULL
+      ELSE
+        getTaxZoneId(NEW.tax_zone)
+    END,
+    itemtax_taxtype_id=getTaxTypeId(NEW.tax_type)
+  WHERE  ((itemtax_item_id=getItemId(OLD.item_number))
+  AND (CASE WHEN (OLD.tax_zone = 'Any') THEN
+              itemtax_taxzone_id IS NULL
+            ELSE
+              itemtax_taxzone_id=getTaxZoneId(OLD.tax_zone) END)
+  AND (itemtax_taxtype_id=getTaxTypeId(OLD.tax_type)));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.itemtaxtype DO INSTEAD
+
+  DELETE FROM itemtax
+  WHERE  ((itemtax_item_id=getItemId(OLD.item_number))
+  AND (CASE WHEN (OLD.tax_zone = 'Any') THEN
+              itemtax_taxzone_id IS NULL
+            ELSE
+              itemtax_taxzone_id=getTaxZoneId(OLD.tax_zone) END)
+  AND (itemtax_taxtype_id=getTaxTypeId(OLD.tax_type)));
diff --git a/foundation-database/api/views/itemuomconversion.sql b/foundation-database/api/views/itemuomconversion.sql
new file mode 100644 (file)
index 0000000..d365327
--- /dev/null
@@ -0,0 +1,69 @@
+-- Item UOM Conversion
+
+SELECT dropIfExists('VIEW', 'itemuomconversion', 'api');
+CREATE VIEW api.itemuomconversion
+AS 
+   SELECT 
+     item_number::varchar AS item_number,
+     f.uom_name::varchar AS uom,
+     itemuomconv_from_value AS uom_value,
+     p.uom_name AS per_uom,
+     itemuomconv_to_value AS per_uom_value,
+     itemuomconv_fractional AS fractional,
+     fetchItemUomConvTypes(itemuomconv_id) AS selected_types
+   FROM item, itemuomconv, uom f, uom p
+   WHERE ((item_id=itemuomconv_item_id)
+   AND (itemuomconv_from_uom_id=f.uom_id)
+   AND (itemuomconv_to_uom_id=p.uom_id));
+
+GRANT ALL ON TABLE api.itemuomconversion TO xtrole;
+COMMENT ON VIEW api.itemuomconversion IS 'Item Unit of Measure Conversion';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.itemuomconversion DO INSTEAD
+
+  SELECT saveItemUomConv(
+    getItemId(NEW.item_number),
+    COALESCE(getUomId(NEW.uom),(
+      SELECT item_inv_uom_id
+      FROM item
+      WHERE (item_id=getItemId(NEW.item_number)))),
+    COALESCE(NEW.uom_value,1),
+    COALESCE(getUomId(NEW.per_uom),(
+      SELECT item_inv_uom_id
+      FROM item
+      WHERE (item_id=getItemId(NEW.item_number)))),
+    COALESCE(NEW.per_uom_value,1),
+    COALESCE(NEW.fractional,false),
+    getUomTypeId(NEW.selected_types));
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.itemuomconversion DO INSTEAD
+
+  SELECT saveItemUomConv(
+    getItemId(NEW.item_number),
+    COALESCE(getUomId(NEW.uom),(
+      SELECT item_inv_uom_id
+      FROM item
+      WHERE (item_id=getItemId(NEW.item_number)))),
+    COALESCE(NEW.uom_value,1),
+    COALESCE(getUomId(NEW.per_uom),(
+      SELECT item_inv_uom_id
+      FROM item
+      WHERE (item_id=getItemId(NEW.item_number)))),
+    COALESCE(NEW.per_uom_value,1),
+    COALESCE(NEW.fractional,false),
+    getUomTypeId(NEW.selected_types));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.itemuomconversion DO INSTEAD
+
+  SELECT deleteitemuomconv(itemuomconv_id)
+  FROM itemuomconv
+  WHERE ((itemuomconv_item_id=getItemId(OLD.item_number))
+  AND (((itemuomconv_from_uom_id=getUomId(OLD.uom))
+  AND (itemuomconv_to_uom_id=getUomId(OLD.per_uom)))
+  OR ((itemuomconv_from_uom_id=getUomId(OLD.per_uom))
+  AND (itemuomconv_to_uom_id=getUomId(OLD.uom)))));
diff --git a/foundation-database/api/views/journalentry.sql b/foundation-database/api/views/journalentry.sql
new file mode 100644 (file)
index 0000000..c0cfea4
--- /dev/null
@@ -0,0 +1,51 @@
+-- Simple Journal Entry
+SELECT dropIfExists('VIEW', 'journalentry', 'api');
+CREATE VIEW api.journalentry AS 
+   SELECT  
+     curr_abbr AS currency,
+     c.gltrans_amount AS amount,
+     c.gltrans_date as dist_date,
+     c.gltrans_docnumber as doc_number,
+     formatglaccount(da.accnt_id) AS debit,
+     formatglaccount(ca.accnt_id) AS credit,
+     c.gltrans_notes AS notes
+   FROM gltrans d, gltrans c, accnt da, accnt ca, curr_symbol
+   WHERE ((d.gltrans_sequence=c.gltrans_sequence)
+   AND (d.gltrans_accnt_id=da.accnt_id)
+   AND (c.gltrans_accnt_id=ca.accnt_id)
+   AND (d.gltrans_amount < 0)
+   AND (c.gltrans_amount > 0)
+   AND (d.gltrans_doctype='JE')
+   AND (c.gltrans_doctype='JE')
+   AND (curr_id=basecurrid()))
+   ORDER BY d.gltrans_date DESC;
+
+GRANT ALL ON TABLE api.journalentry TO xtrole;
+COMMENT ON VIEW api.journalentry IS 'Journal Entry';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.journalentry DO INSTEAD
+
+SELECT insertGLTransaction( 
+     'G/L'::text,
+     'JE'::text, 
+     NEW.doc_number, 
+     NEW.notes,
+     getGlAccntId(NEW.credit),
+     getGlAccntId(NEW.debit),
+     -1,
+     currtobase(getCurrId(NEW.currency),NEW.amount,NEW.dist_date),
+     NEW.dist_date 
+     );
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.journalentry DO INSTEAD
+
+  NOTHING;
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.journalentry DO INSTEAD
+
+  NOTHING;
diff --git a/foundation-database/api/views/location.sql b/foundation-database/api/views/location.sql
new file mode 100644 (file)
index 0000000..151a2d2
--- /dev/null
@@ -0,0 +1,70 @@
+-- Location View
+
+SELECT dropIfExists('VIEW', 'location', 'api');
+CREATE OR REPLACE VIEW api.location AS
+  SELECT
+    warehous_code::VARCHAR AS site,
+    location_aisle::VARCHAR AS aisle,
+    location_rack::VARCHAR AS rack,
+    location_bin::VARCHAR AS bin,
+    location_name::VARCHAR AS location,
+    whsezone_name AS zone,
+    location_netable AS netable,
+    location_restrict AS restricted,
+    location_descrip AS description
+    FROM location
+       LEFT OUTER JOIN whsinfo ON (warehous_id=location_warehous_id)
+       LEFT OUTER JOIN whsezone ON (whsezone_id=location_whsezone_id);
+
+GRANT ALL ON TABLE api.location TO xtrole;
+COMMENT ON VIEW api.location IS 'Location';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.location DO INSTEAD
+
+  INSERT INTO location (
+    location_warehous_id,
+    location_name,
+    location_descrip,
+    location_restrict,
+    location_netable,
+    location_whsezone_id,
+    location_aisle,
+    location_rack,
+    location_bin
+    )
+  VALUES (
+    getWarehousId(NEW.site, 'ACTIVE'),
+    COALESCE(NEW.location,''),
+    COALESCE(NEW.description, ''),
+    COALESCE(NEW.restricted, false),
+    COALESCE(NEW.netable, true),
+    getWhseZoneId(NEW.site, NEW.zone),
+    COALESCE(NEW.aisle, ''),
+    COALESCE(NEW.rack, ''),
+    COALESCE(NEW.bin, '')
+    );
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.location DO INSTEAD
+
+  UPDATE location SET
+    location_name=NEW.location,
+    location_descrip=NEW.description,
+    location_restrict=NEW.restricted,
+    location_netable=NEW.netable,
+    location_whsezone_id=getWhseZoneId(NEW.site, NEW.zone),
+    location_aisle=NEW.aisle,
+    location_rack=NEW.rack,
+    location_bin=NEW.bin
+  WHERE ( (location_warehous_id=getWarehousId(OLD.site, 'ACTIVE')) AND
+          (location_name=OLD.location) );
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.location DO INSTEAD
+
+  DELETE FROM location
+  WHERE ( (location_warehous_id=getWarehousId(OLD.site, 'ACTIVE')) AND
+          (location_name=OLD.location) );
diff --git a/foundation-database/api/views/misccounttag.sql b/foundation-database/api/views/misccounttag.sql
new file mode 100644 (file)
index 0000000..6415ffd
--- /dev/null
@@ -0,0 +1,39 @@
+-- Simple Journal Entry
+SELECT dropifexists('view','misccounttag','api');
+CREATE VIEW api.misccounttag
+AS 
+  SELECT
+    'This view is for inserts only'::text as site,
+    'This view is for inserts only'::text as item_number,
+    0::numeric as quantity,
+    'This view is for inserts only'::text as comment;
+
+GRANT ALL ON TABLE api.misccounttag TO xtrole;
+COMMENT ON VIEW api.misccounttag IS 'Miscellaneous Count Tag';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.misccounttag DO INSTEAD
+
+SELECT postMiscCount( 
+  getItemsiteId(
+  COALESCE(NEW.site,
+               (SELECT warehous_code
+                FROM usrpref,whsinfo
+                WHERE (usrpref_username=getEffectiveXtUser())
+                AND (usrpref_name='PreferredWarehouse')
+                AND (warehous_id=CAST(usrpref_value AS INTEGER)))), NEW.item_number),
+  NEW.quantity,
+  NEW.comment
+     );
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.misccounttag DO INSTEAD
+
+  NOTHING;
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.misccounttag DO INSTEAD
+
+  NOTHING;
diff --git a/foundation-database/api/views/physinvcount.sql b/foundation-database/api/views/physinvcount.sql
new file mode 100644 (file)
index 0000000..cad786f
--- /dev/null
@@ -0,0 +1,149 @@
+CREATE OR REPLACE VIEW api.physinvcount
+AS 
+  SELECT
+    warehous_code AS site,
+    item_number AS item_number,
+    invcnt_tagnumber AS tag_number,
+    cntslip_qty AS quantity,
+    formatLocationName(cntslip_location_id) AS location,
+    cntslip_lotserial AS lotserial,
+    cntslip_comments AS comment
+  FROM invcnt JOIN itemsite ON (itemsite_id=invcnt_itemsite_id)
+              JOIN whsinfo ON (warehous_id=itemsite_warehous_id)
+              JOIN item ON (item_id=itemsite_item_id)
+              LEFT OUTER JOIN cntslip ON (cntslip_cnttag_id=invcnt_id);
+
+GRANT ALL ON TABLE api.physinvcount TO xtrole;
+COMMENT ON VIEW api.physinvcount IS 'Physical Inventory Count Tag and Slip';
+
+CREATE OR REPLACE FUNCTION api.insertPhysInvCount(api.physinvcount) RETURNS boolean AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  pNEW ALIAS FOR $1;
+  _itemid INTEGER;
+  _type TEXT;
+  _siteid INTEGER;
+  _itemsiteid INTEGER;
+  _controlmethod TEXT;
+  _loccntrl BOOLEAN;
+  _locationid INTEGER;
+  _lsid INTEGER;
+  _invcntid INTEGER;
+  _cntslipid INTEGER;
+  _result INTEGER;
+
+BEGIN
+
+  -- Check Item
+  SELECT item_id, item_type INTO _itemid, _type
+  FROM item
+  WHERE (item_number=UPPER(pNEW.item_number));
+  IF (NOT FOUND OR _type IN ('F', 'R', 'L','J')) THEN
+    SELECT item_id, item_type INTO _itemid, _type
+    FROM item
+    WHERE (item_upccode=pNEW.item_number);
+    IF (NOT FOUND OR _type IN ('F', 'R', 'L','J')) THEN
+      RAISE EXCEPTION 'Function insertPhysInvCount failed because Item % not found or invalid type', pNEW.item_number;
+    END IF;
+  END IF;
+
+  -- Check Site
+  SELECT warehous_id INTO _siteid
+  FROM whsinfo
+  WHERE (warehous_code=COALESCE(pNEW.site, (SELECT warehous_code
+                                            FROM usrpref,whsinfo
+                                            WHERE (usrpref_username=getEffectiveXtUser())
+                                              AND (usrpref_name='PreferredWarehouse')
+                                              AND (warehous_id=CAST(usrpref_value AS INTEGER)))));
+  IF (NOT FOUND) THEN
+    RAISE EXCEPTION 'Function insertPhysInvCount failed because Site % not found', pNEW.site;
+  END IF;
+
+  -- Check Itemsite
+  SELECT itemsite_id, itemsite_controlmethod, itemsite_loccntrl INTO _itemsiteid, _controlmethod, _loccntrl
+  FROM itemsite
+  WHERE (itemsite_item_id=_itemid)
+    AND (itemsite_warehous_id=_siteid);
+  IF (NOT FOUND) THEN
+    RAISE EXCEPTION 'Function insertPhysInvCount failed because Itemsite %, % not found', pNEW.site, pNEW.item_number;
+  END IF;
+  IF (_controlmethod = 'N') THEN
+    RAISE EXCEPTION 'Function insertPhysInvCount failed because Itemsite %, % not inventory control method', pNEW.site, pNEW.item_number;
+  END IF;
+  IF (_controlmethod IN ('L', 'S') AND COALESCE(pNEW.lotserial, '') = '') THEN
+    RAISE EXCEPTION 'Function insertPhysInvCount failed because Itemsite %, % lot/serial controlled and lotserial not provided', pNEW.site, pNEW.item_number;
+  END IF;
+  IF (_controlmethod = 'S') THEN
+    -- Check for unique serial id
+    SELECT ls_id INTO _lsid
+    FROM ls
+    WHERE (ls_number=pNEW.lotserial);
+    IF (FOUND) THEN
+      RAISE EXCEPTION 'Function insertPhysInvCount failed because Serial %, %, % not unique', pNEW.site, pNEW.item_number, pNEW.lotserial;
+    END IF;
+  END IF;
+  IF (_loccntrl) THEN
+    IF (pNEW.location IS NULL) THEN
+      RAISE EXCEPTION 'Function insertPhysInvCount failed because Itemsite %, % multi location and location not provided', pNEW.site, pNEW.item_number;
+    ELSE
+      -- Check Location
+      SELECT location_id INTO _locationid
+      FROM location
+      WHERE (location_id=getLocationId(pNEW.site, pNEW.location));
+      IF (NOT FOUND) THEN
+        RAISE EXCEPTION 'Function insertPhysInvCount failed because Location %, % not found', pNEW.site, pNEW.location;
+      END IF;
+    END IF;
+  END IF;
+
+  -- Create Count Tag
+  SELECT CreateCountTag(_itemsiteid, pNEW.comment, FALSE, FALSE) INTO _invcntid;
+  IF (_invcntid <= 0) THEN
+    RAISE EXCEPTION 'Function insertPhysInvCount failed because CreateCountTag failed for Itemsite %, %', pNEW.site, pNEW.item_number;
+  END IF;
+
+  -- Create Count Slip
+  INSERT INTO cntslip
+  ( cntslip_cnttag_id,
+    cntslip_username, cntslip_entered, cntslip_posted,
+    cntslip_number, cntslip_qty,
+    cntslip_location_id, cntslip_lotserial,
+    cntslip_lotserial_expiration,
+    cntslip_lotserial_warrpurc,
+    cntslip_comments )
+  VALUES
+  ( _invcntid,
+    getEffectiveXtUser(), CURRENT_TIMESTAMP, FALSE,
+    'N/A', pNEW.quantity,
+    COALESCE(_locationid, -1), pNEW.lotserial,
+    NULL,
+    NULL,
+    pNEW.comment )
+  RETURNING cntslip_id INTO _cntslipid;
+
+  -- Post Count Slip
+  SELECT postCountSlip(_cntslipid) INTO _result;
+  IF (_result < 0) THEN
+    RAISE EXCEPTION 'Function insertPhysInvCount failed because postCountSlip failed for Itemsite %, %, %', pNEW.site, pNEW.item_number, _result;
+  END IF;
+
+  RETURN TRUE;
+END;
+$$ LANGUAGE 'plpgsql';
+
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.physinvcount DO INSTEAD  SELECT api.insertphysinvcount(new.*) AS insertphysinvcount;
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.physinvcount DO INSTEAD
+
+  NOTHING;
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.physinvcount DO INSTEAD
+
+  NOTHING;
diff --git a/foundation-database/api/views/pricingschedule.sql b/foundation-database/api/views/pricingschedule.sql
new file mode 100644 (file)
index 0000000..4c5d3f2
--- /dev/null
@@ -0,0 +1,81 @@
+-- Pricing Schedule
+
+SELECT dropIfExists('VIEW', 'pricingschedule', 'api');
+CREATE OR REPLACE VIEW api.pricingschedule 
+AS 
+  SELECT 
+    ipshead_name::VARCHAR AS name, 
+    ipshead_descrip AS description, 
+    formatdate(ipshead_effective, 'Always') AS effective, 
+    formatdate(ipshead_expires, 'Never') AS expires,
+    curr_abbr AS currency
+  FROM ipshead, curr_symbol
+  WHERE (curr_id=ipshead_curr_id);
+
+GRANT ALL ON TABLE api.pricingschedule TO xtrole;
+COMMENT ON VIEW api.pricingschedule IS 'Pricing Schedule';
+
+-- Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+  ON INSERT TO api.pricingschedule DO INSTEAD  
+  INSERT INTO ipshead (
+    ipshead_id, 
+    ipshead_name, 
+    ipshead_descrip, 
+    ipshead_effective, 
+    ipshead_expires,
+    ipshead_curr_id, 
+    ipshead_updated) 
+  VALUES (
+    nextval('ipshead_ipshead_id_seq'), 
+    new.name, 
+    new.description, 
+    CASE
+      WHEN (new.effective = 'Always') THEN 
+        CAST('1970-01-01' AS date)
+      ELSE CAST(COALESCE(new.effective,'1970-01-01') AS date)
+    END, 
+    CASE
+      WHEN (new.expires = 'Never') THEN 
+        CAST('2100-01-01' AS date)
+      ELSE CAST(COALESCE(new.expires,'2100-01-01') AS date)
+    END, 
+    COALESCE(getCurrId(new.currency),basecurrid()),
+    now());
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+  ON UPDATE TO api.pricingschedule DO INSTEAD  
+
+  UPDATE ipshead SET 
+    ipshead_descrip = new.description, 
+    ipshead_effective = 
+    CASE
+      WHEN new.effective = 'Always' THEN 
+        CAST('1970-01-01' AS date)
+      ELSE 
+        CAST(new.effective AS date)
+    END, 
+    ipshead_expires = 
+    CASE
+      WHEN new.expires = 'Never' THEN
+        CAST('2100-01-01' AS date)
+      ELSE 
+        CAST(new.expires AS date)
+    END, 
+    ipshead_updated = now(),
+    ipshead_curr_id=
+    CASE
+      WHEN (SELECT (COUNT(ipsitem_id) =0)
+            FROM ipsiteminfo
+            WHERE (ipsitem_ipshead_id=getIpsHeadId(old.name))) THEN
+         COALESCE(getCurrId(new.currency),basecurrid())
+      ELSE
+        getCurrId(old.currency)
+     END       
+WHERE ipshead_name = old.name;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.pricingschedule DO INSTEAD  
+
+  DELETE FROM ipshead WHERE (old.name = ipshead_name);
diff --git a/foundation-database/api/views/pricingscheduleassign.sql b/foundation-database/api/views/pricingscheduleassign.sql
new file mode 100644 (file)
index 0000000..9c63c58
--- /dev/null
@@ -0,0 +1,139 @@
+-- Pricing Schedule Assignemnts
+
+SELECT dropIfExists('VIEW', 'pricingscheduleassign', 'api');
+CREATE OR REPLACE VIEW api.pricingscheduleassign 
+AS 
+  SELECT 
+    COALESCE(cust_number,'Any')::VARCHAR AS customer_number,
+    COALESCE(shipto_num, 'Any')::VARCHAR AS customer_shipto,
+    COALESCE(ipsass_shipto_pattern,'N/A')::VARCHAR AS customer_shipto_pattern,
+    COALESCE(custtype_code,'N/A')::VARCHAR AS customer_type,
+    COALESCE(ipsass_custtype_pattern,'N/A')::VARCHAR AS customer_type_pattern,
+    ipshead_name::VARCHAR AS pricing_schedule
+  FROM ipshead JOIN ipsass ON (ipshead_id=ipsass_ipshead_id)
+    LEFT OUTER JOIN custinfo ON (ipsass_cust_id=cust_id)
+    LEFT OUTER JOIN custtype ON (ipsass_custtype_id=custtype_id)
+    LEFT OUTER JOIN shiptoinfo ON (ipsass_shipto_id=shipto_id)
+  ORDER BY customer_number, customer_shipto, customer_type, customer_type_pattern, pricing_schedule;
+    
+    
+
+GRANT ALL ON TABLE api.pricingscheduleassign TO xtrole;
+COMMENT ON VIEW api.pricingscheduleassign IS 'Pricing Schedule Assignments';
+
+-- Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+  ON INSERT TO api.pricingscheduleassign DO INSTEAD  
+  
+  INSERT INTO ipsass (
+    ipsass_ipshead_id, 
+    ipsass_cust_id,
+    ipsass_custtype_id,
+    ipsass_custtype_pattern,
+    ipsass_shipto_id,
+    ipsass_shipto_pattern) 
+  VALUES (
+    getIpsheadId(new.pricing_schedule),
+    CASE
+      WHEN (new.customer_number='Any') THEN
+        -1
+      ELSE
+        getCustId(new.customer_number)
+    END,
+    CASE
+      WHEN (new.customer_type='N/A') THEN
+        -1
+      ELSE
+        getCusttypeId(new.customer_type)
+    END,
+    new.customer_type_pattern,
+    CASE
+      WHEN (new.customer_number='Any' OR new.customer_shipto='Any') THEN
+        -1
+      ELSE
+        getShiptoId(new.customer_number,new.customer_shipto)
+    END,
+    new.customer_shipto_pattern);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+  ON UPDATE TO api.pricingscheduleassign DO INSTEAD  
+
+  UPDATE ipsass SET
+    ipsass_ipshead_id=getIpsheadId(new.pricing_schedule),
+    ipsass_cust_id=      
+    CASE
+      WHEN (new.customer_number='Any') THEN
+        -1
+      ELSE
+        getCustId(new.customer_number)
+    END,
+    ipsass_custtype_id=
+    CASE
+      WHEN (new.customer_type='N/A') THEN
+        -1
+      ELSE
+        getCusttypeId(new.customer_type)
+    END,
+    ipsass_custtype_pattern=new.customer_type_pattern,
+    ipsass_shipto_id=
+    CASE
+      WHEN (new.customer_number='Any' OR new.customer_shipto='Any') THEN
+        -1
+      ELSE
+        getShiptoId(new.customer_number,new.customer_shipto)
+    END,
+    ipsass_shipto_pattern=new.customer_shipto_pattern
+  WHERE ((ipsass_ipshead_id=getIpsheadId(old.pricing_schedule))
+    AND (ipsass_cust_id=
+      CASE
+        WHEN (old.customer_number='Any') THEN
+          -1
+        ELSE
+          getCustId(old.customer_number)
+      END)
+    AND (ipsass_custtype_id=
+      CASE
+        WHEN (old.customer_type='N/A') THEN
+          -1
+        ELSE
+          getCusttypeId(old.customer_type)
+      END)
+    AND (ipsass_custtype_pattern=old.customer_type_pattern)
+    AND (ipsass_shipto_id=
+      CASE
+        WHEN (old.customer_shipto='Any') THEN
+          -1
+        ELSE
+          getShiptoId(old.customer_number,old.customer_shipto)
+      END)
+    AND (ipsass_shipto_pattern=old.customer_shipto_pattern));
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.pricingscheduleassign DO INSTEAD  
+
+  DELETE FROM ipsass
+  WHERE ((ipsass_ipshead_id=getIpsheadId(old.pricing_schedule))
+    AND (ipsass_cust_id=
+      CASE
+        WHEN (old.customer_number='Any') THEN
+          -1
+        ELSE
+          getCustId(old.customer_number)
+      END)
+    AND (ipsass_custtype_id=
+      CASE
+        WHEN (old.customer_type='N/A') THEN
+          -1
+        ELSE
+          getCusttypeId(old.customer_type)
+      END)
+    AND (ipsass_custtype_pattern=old.customer_type_pattern)
+    AND (ipsass_shipto_id=
+      CASE
+        WHEN (old.customer_shipto='Any') THEN
+          -1
+        ELSE
+          getShiptoId(old.customer_number,old.customer_shipto)
+      END)
+    AND (ipsass_shipto_pattern=old.customer_shipto_pattern));
diff --git a/foundation-database/api/views/pricingscheduleitem.sql b/foundation-database/api/views/pricingscheduleitem.sql
new file mode 100644 (file)
index 0000000..4153ed3
--- /dev/null
@@ -0,0 +1,117 @@
+-- Pricing Schedule Item
+
+SELECT dropIfExists('VIEW', 'pricingscheduleitem', 'api');
+CREATE OR REPLACE VIEW api.pricingscheduleitem AS 
+ SELECT 
+   ipshead_name::VARCHAR AS pricing_schedule,
+   CASE WHEN (COALESCE(ipsitem_item_id, -1) > 0) THEN 'Item'::VARCHAR
+        ELSE 'Product Category'::VARCHAR
+   END AS type,
+   COALESCE(item_number, '')::VARCHAR AS item_number,
+   COALESCE(prodcat_code, '')::VARCHAR AS product_category,
+   ipsitem_qtybreak AS qty_break, 
+   qtyuom.uom_name::VARCHAR AS qty_uom, 
+   priceuom.uom_name::VARCHAR AS price_uom,
+   ipsitem_price AS price,
+   ipsitem_discntprcnt AS percent,
+   ipsitem_fixedamtdiscount AS fixedamt,
+   CASE WHEN (ipsitem_type='N') THEN 'Nominal'::VARCHAR
+        WHEN (ipsitem_type='D') THEN 'Discount'::VARCHAR
+        WHEN (ipsitem_type='M') THEN 'Markup'::VARCHAR
+   END AS pricing_type 
+ FROM ipsiteminfo
+   JOIN ipshead ON (ipsitem_ipshead_id = ipshead_id)
+   LEFT OUTER JOIN item ON (ipsitem_item_id = item_id)
+   LEFT OUTER JOIN prodcat ON (ipsitem_prodcat_id = prodcat_id)
+   LEFT OUTER JOIN uom qtyuom ON (ipsitem_qty_uom_id = qtyuom.uom_id)
+   LEFT OUTER JOIN uom priceuom ON (ipsitem_price_uom_id = priceuom.uom_id);
+
+GRANT ALL ON TABLE api.pricingscheduleitem TO xtrole;
+COMMENT ON VIEW api.pricingscheduleitem IS 'Pricing Schedule Item';
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.pricingscheduleitem DO INSTEAD  
+    
+ SELECT
+   CASE 
+     WHEN (NEW.type = 'Item') THEN
+       saveIpsitem(NULL,
+                   getIpsheadId(NEW.pricing_schedule),
+                   getItemId(NEW.item_number),
+                   COALESCE(NEW.qty_break,0),
+                   COALESCE(NEW.price,0),
+                   getUomId(NEW.qty_uom),
+                   getUomId(NEW.price_uom),
+                   NEW.percent,
+                   NEW.fixedamt,
+                   CASE NEW.pricing_type WHEN 'Nominal' THEN 'N'
+                                         WHEN 'Discount' THEN 'D'
+                                         WHEN 'Markup' THEN 'M'
+                                         ELSE '?' END)
+     WHEN (NEW.type = 'Product Category') THEN
+     saveIpsProdcat(NULL,
+                    getIpsheadId(NEW.pricing_schedule),
+                    getProdcatId(NEW.product_category),
+                    NEW.qty_break,
+                    NEW.percent,
+                    NEW.fixedamt,
+                    CASE NEW.pricing_type WHEN 'Nominal' THEN 'N'
+                                          WHEN 'Discount' THEN 'D'
+                                          WHEN 'Markup' THEN 'M'
+                                          ELSE '?' END)
+   END;
+          
+CREATE OR REPLACE RULE "_UPDATE" AS
+  ON UPDATE TO api.pricingscheduleitem DO INSTEAD  
+
+ SELECT
+   CASE 
+     WHEN (OLD.type = 'Item') THEN
+       saveIpsitem(getIpsitemId(OLD.pricing_schedule,
+                                OLD.item_number,
+                                OLD.qty_break,
+                                OLD.qty_uom,
+                                OLD.price_uom),
+                   getIpsheadId(NEW.pricing_schedule),
+                   getItemId(NEW.item_number),
+                   NEW.qty_break,
+                   NEW.price,
+                   getUomId(NEW.qty_uom),
+                   getUomId(NEW.price_uom),
+                   NEW.percent,
+                   NEW.fixedamt,
+                   CASE NEW.pricing_type WHEN 'Nominal' THEN 'N'
+                                         WHEN 'Discount' THEN 'D'
+                                         WHEN 'Markup' THEN 'M'
+                                         ELSE '?' END)
+     WHEN (OLD.type = 'Product Category') THEN
+       saveIpsProdcat(getIpsProdcatId(OLD.pricing_schedule,
+                                      OLD.product_category,
+                                      OLD.qty_break),
+                      getIpsheadId(NEW.pricing_schedule),
+                      getProdCatId(NEW.product_category),
+                      NEW.qty_break,
+                      NEW.percent,
+                      NEW.fixedamt,
+                      CASE NEW.pricing_type WHEN 'Nominal' THEN 'N'
+                                            WHEN 'Discount' THEN 'D'
+                                            WHEN 'Markup' THEN 'M'
+                                            ELSE '?' END)
+   END AS result;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+  ON DELETE TO api.pricingscheduleitem DO INSTEAD  
+
+ SELECT
+   CASE 
+     WHEN (OLD.type = 'Item') THEN
+       deleteIpsitem(getIpsitemId(OLD.pricing_schedule,
+                                  OLD.item_number,
+                                  OLD.qty_break,
+                                  OLD.qty_uom,
+                                  OLD.price_uom))
+     WHEN (OLD.type = 'Product Category') THEN
+       deleteIpsProdcat(getIpsProdcatId(OLD.pricing_schedule,
+                                        OLD.product_category,
+                                        OLD.qty_break))
+   END AS result;
diff --git a/foundation-database/api/views/pricingscheduleitemchar.sql b/foundation-database/api/views/pricingscheduleitemchar.sql
new file mode 100644 (file)
index 0000000..023cc39
--- /dev/null
@@ -0,0 +1,58 @@
+-- Pricing Schedule Item Characteristic
+
+SELECT dropIfExists('VIEW', 'pricingscheduleitemchar', 'api');
+CREATE VIEW api.pricingscheduleitemchar
+AS 
+   SELECT 
+     ipshead_name::VARCHAR AS pricing_schedule,
+     item_number::VARCHAR AS item_number,
+     ipsitem_qtybreak AS qty_break,
+     qtyuom.uom_name::VARCHAR AS qty_uom,
+     priceuom.uom_name::VARCHAR AS price_uom,
+     char_name::VARCHAR AS characteristic,
+     ipsitemchar_value::VARCHAR AS value,
+     ipsitemchar_price AS price
+   FROM ipshead, ipsiteminfo, ipsitemchar, item, char, uom qtyuom, uom priceuom
+   WHERE ((ipshead_id=ipsitem_ipshead_id)
+     AND (ipsitem_id=ipsitemchar_ipsitem_id)
+     AND (ipsitem_item_id=item_id)
+     AND (ipsitem_qty_uom_id=qtyuom.uom_id)
+     AND (ipsitem_price_uom_id=priceuom.uom_id)
+     AND (ipsitemchar_char_id=char_id));
+
+GRANT ALL ON TABLE api.pricingscheduleitemchar TO xtrole;
+COMMENT ON VIEW api.pricingscheduleitemchar IS 'Pricing Schedule Item Characteristics';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.pricingscheduleitemchar DO INSTEAD
+
+  INSERT INTO ipsitemchar (
+    ipsitemchar_ipsitem_id,
+    ipsitemchar_char_id,
+    ipsitemchar_value,
+    ipsitemchar_price
+    )
+  VALUES (
+    getIpsitemId(NEW.pricing_schedule,NEW.item_number,NEW.qty_break,NEW.qty_uom,NEW.price_uom),
+    getCharId(NEW.characteristic,'I'),
+    NEW.value,
+    COALESCE(NEW.price,0));
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.pricingscheduleitemchar DO INSTEAD
+
+  UPDATE ipsitemchar SET
+    ipsitemchar_price=NEW.price
+  WHERE ((ipsitemchar_ipsitem_id=getIpsitemId(OLD.pricing_schedule,OLD.item_number,OLD.qty_break,OLD.qty_uom,OLD.price_uom))
+  AND (ipsitemchar_char_id=getCharId(OLD.characteristic,'I'))
+  AND (ipsitemchar_value=OLD.value));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.pricingscheduleitemchar DO INSTEAD
+
+  DELETE FROM ipsitemchar
+  WHERE ((ipsitemchar_ipsitem_id=getIpsitemId(OLD.pricing_schedule,OLD.item_number,OLD.qty_break,OLD.qty_uom,OLD.price_uom))
+  AND (ipsitemchar_char_id=getCharId(OLD.characteristic,'I'))
+  AND (ipsitemchar_value=OLD.value));
diff --git a/foundation-database/api/views/project.sql b/foundation-database/api/views/project.sql
new file mode 100644 (file)
index 0000000..32712bd
--- /dev/null
@@ -0,0 +1,105 @@
+-- Project
+SELECT dropIfExists('VIEW', 'project', 'api');
+CREATE VIEW api.project
+AS
+   SELECT 
+     prj_number AS number,
+     prj_name AS name,
+     prj_descrip AS description,
+     prj_owner_username AS owner,
+     prj_username AS assigned_to,
+     prj_so AS sales_orders,
+     prj_wo AS work_orders,
+     prj_po AS purchase_orders,
+     CASE 
+       WHEN (prj_status = 'P') THEN
+         'Concept'
+       WHEN (prj_status = 'O') THEN
+         'In-Process'
+       WHEN (prj_status = 'C') THEN
+         'Closed'
+       ELSE
+         'Error'
+     END AS status,
+     prj_due_date AS due,
+     prj_assigned_date AS assigned,
+     prj_start_date AS started,
+     prj_completed_date AS completed
+   FROM prj;
+
+GRANT ALL ON TABLE api.project TO xtrole;
+COMMENT ON VIEW api.project IS 'Project';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.project DO INSTEAD
+
+  INSERT INTO prj (
+    prj_number,
+    prj_name,
+    prj_descrip,
+    prj_owner_username,
+    prj_username,
+    prj_so,
+    prj_wo,
+    prj_po,
+    prj_status,
+    prj_due_date,
+    prj_assigned_date,
+    prj_start_date,
+    prj_completed_date
+    )
+  VALUES (
+    NEW.number,
+    COALESCE(NEW.name,''),
+    COALESCE(NEW.description,''),
+    COALESCE(NEW.owner,getEffectiveXtUser()),
+    COALESCE(NEW.assigned_to,getEffectiveXtUser()),
+    COALESCE(NEW.sales_orders,true),
+    COALESCE(NEW.work_orders,true),
+    COALESCE(NEW.purchase_orders,true),
+    CASE 
+      WHEN (NEW.status='In-Process') THEN
+        'O'
+      WHEN (NEW.status='Completed') THEN
+        'C'
+      ELSE
+        'P'
+    END,
+    NEW.due,
+    NEW.assigned,
+    NEW.started,
+    NEW.completed
+    );
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.project DO INSTEAD
+
+  UPDATE prj SET
+    prj_name=NEW.name,
+    prj_descrip=NEW.description,
+    prj_owner_username=NEW.owner,
+    prj_username=NEW.assigned_to,
+    prj_so=NEW.sales_orders,
+    prj_wo=NEW.work_orders,
+    prj_po=NEW.purchase_orders,
+    prj_status=
+    CASE 
+      WHEN (NEW.status='In-Process') THEN
+        'O'
+      WHEN (NEW.status='Completed') THEN
+        'C'
+      ELSE
+        'P'
+    END,
+    prj_due_date=NEW.due,
+    prj_assigned_date=NEW.assigned,
+    prj_start_date=NEW.started,
+    prj_completed_date=NEW.completed
+  WHERE (prj_number=OLD.number);
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.project DO INSTEAD
+
+  SELECT deleteproject (getPrjId(OLD.number));
diff --git a/foundation-database/api/views/projectcomment.sql b/foundation-database/api/views/projectcomment.sql
new file mode 100644 (file)
index 0000000..6d57a05
--- /dev/null
@@ -0,0 +1,45 @@
+-- Project Comment
+
+SELECT dropIfExists('VIEW', 'projectcomment', 'api');
+CREATE VIEW api.projectcomment
+AS 
+   SELECT 
+     prj_number::varchar AS project_number,
+     cmnttype_name AS type,
+     comment_date AS date,
+     comment_user AS username,
+     comment_text AS text
+   FROM prj, cmnttype, comment
+   WHERE ((comment_source='J')
+   AND (comment_source_id=prj_id)
+   AND (comment_cmnttype_id=cmnttype_id));
+
+GRANT ALL ON TABLE api.projectcomment TO xtrole;
+COMMENT ON VIEW api.projectcomment IS 'Project Comment';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.projectcomment DO INSTEAD
+
+  INSERT INTO comment (
+    comment_date,
+    comment_source,
+    comment_source_id,
+    comment_user,
+    comment_cmnttype_id,
+    comment_text
+    )
+  VALUES (
+    COALESCE(NEW.date,now()),
+    'J',
+    getPrjId(NEW.project_number),
+    COALESCE(NEW.username,getEffectiveXtUser()),
+    getCmntTypeId(NEW.type),
+    NEW.text);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.projectcomment DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.projectcomment DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/prospect.sql b/foundation-database/api/views/prospect.sql
new file mode 100644 (file)
index 0000000..769c337
--- /dev/null
@@ -0,0 +1,116 @@
+
+  SELECT dropIfExists('VIEW', 'prospect', 'api');
+  CREATE OR REPLACE VIEW api.prospect AS
+  SELECT 
+    prospect_number::VARCHAR AS prospect_number,
+    prospect_name AS prospect_name,
+    prospect_active AS active,
+    salesrep_number AS sales_rep,
+    warehous_code AS site_code,
+    taxzone_code AS default_tax_zone,
+    prospect_comments AS notes,
+
+    cntct_number AS contact_number,
+    cntct_honorific AS contact_honorific,
+    cntct_first_name AS contact_first,
+    cntct_middle AS contact_middle,
+    cntct_last_name AS contact_last,
+    cntct_suffix AS contact_suffix,
+    cntct_title AS contact_job_title,
+    cntct_phone AS contact_voice,
+    cntct_phone2 AS contact_alternate,
+    cntct_fax AS contact_fax,
+    cntct_email AS contact_email,
+    cntct_webaddr AS contact_web,
+    (''::TEXT) AS contact_change,
+    addr_number AS contact_address_number,
+    addr_line1 AS contact_address1,
+    addr_line2 AS contact_address2,
+    addr_line3 AS contact_address3,
+    addr_city AS contact_city,
+    addr_state AS contact_state,
+    addr_postalcode AS contact_postalcode,
+    addr_country AS contact_country,
+    (''::TEXT) AS contact_address_change
+  FROM
+    prospect
+      LEFT OUTER JOIN cntct ON (prospect_cntct_id=cntct_id)
+      LEFT OUTER JOIN addr ON (cntct_addr_id=addr_id)
+      LEFT OUTER JOIN taxzone ON (prospect_taxzone_id=taxzone_id)
+      LEFT OUTER JOIN salesrep ON (prospect_salesrep_id=salesrep_id)
+      LEFT OUTER JOIN whsinfo ON (prospect_warehous_id=warehous_id);
+
+GRANT ALL ON TABLE api.prospect TO xtrole;
+COMMENT ON VIEW api.prospect IS 'Prospect';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.prospect DO INSTEAD
+
+INSERT INTO prospect
+       (
+        prospect_number,
+        prospect_name,
+        prospect_active,
+        prospect_cntct_id,
+        prospect_taxzone_id,
+        prospect_salesrep_id,
+        prospect_warehous_id,
+       prospect_comments)
+        VALUES (
+        UPPER(NEW.prospect_number),
+        COALESCE(NEW.prospect_name,''),
+       COALESCE(NEW.active,true),
+        saveCntct(
+          getCntctId(NEW.contact_number),
+          NEW.contact_number,
+          saveAddr(
+            getAddrId(NEW.contact_address_number),
+            NEW.contact_address_number,
+            NEW.contact_address1,
+            NEW.contact_address2,
+            NEW.contact_address3,
+            NEW.contact_city,
+            NEW.contact_state,
+            NEW.contact_postalcode,
+            NEW.contact_country,
+            NEW.contact_address_change),
+          NEW.contact_honorific,
+          NEW.contact_first,
+          NEW.contact_middle,
+          NEW.contact_last,
+          NEW.contact_suffix,
+          NEW.contact_voice,
+          NEW.contact_alternate,
+          NEW.contact_fax,
+          NEW.contact_email,
+          NEW.contact_web,
+          NEW.contact_job_title,
+          NEW.contact_change
+          ),
+        getTaxZoneId(NEW.default_tax_zone),
+        getSalesRepId(NEW.sales_rep),
+        getWarehousId(NEW.site_code,'ACTIVE'),
+        COALESCE(NEW.notes,''));
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.prospect DO INSTEAD
+
+UPDATE prospect SET
+        prospect_number=UPPER(NEW.prospect_number),
+        prospect_name=NEW.prospect_name,
+       prospect_active=NEW.active,
+        prospect_cntct_id=getCntctId(NEW.contact_number),
+        prospect_taxzone_id=getTaxZoneId(NEW.default_tax_zone),
+        prospect_salesrep_id=getSalesRepId(NEW.sales_rep),
+        prospect_warehous_id=getWarehousId(NEW.site_code,'ACTIVE'),
+       prospect_comments=NEW.notes
+
+        WHERE prospect_id=getProspectId(OLD.prospect_number);
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.prospect DO INSTEAD
+    DELETE FROM public.prospect WHERE (prospect_number=OLD.prospect_number);
+
diff --git a/foundation-database/api/views/purchaseline.sql b/foundation-database/api/views/purchaseline.sql
new file mode 100644 (file)
index 0000000..317053e
--- /dev/null
@@ -0,0 +1,129 @@
+  --Purchase Order Line Item View
+
+  SELECT dropIfExists('VIEW', 'purchaseline', 'api');
+  CREATE OR REPLACE VIEW api.purchaseline AS
+
+  SELECT
+    pohead_number::varchar AS order_number,
+    poitem_linenumber AS line_number,
+    item_number,
+    warehous_code AS site,
+    expcat_code AS expense_category,
+    poitem_qty_ordered AS qty_ordered,
+    poitem_unitprice AS unit_price,
+    poitem_freight AS freight,
+    poitem_duedate AS due_date,
+    prj_number AS project_number,
+    poitem_vend_item_number AS vend_item_number,
+    poitem_vend_item_descrip AS vendor_description,
+    poitem_manuf_name AS manufacturer_name,
+    poitem_manuf_item_number AS manufacturer_item_number,
+    poitem_manuf_item_descrip AS manufacturer_description,
+    poitem_comments AS notes,
+    formatRevNumber('BOM',poitem_bom_rev_id) AS bill_of_materials_revision,
+    formatRevNumber('BOO',poitem_boo_rev_id) AS bill_of_operations_revision,
+    formatSoNumber(coitem_id) AS sales_order_number,
+    formatWoNumber(womatl_wo_id) AS work_order_number
+  FROM pohead
+    JOIN poitem ON (pohead_id=poitem_pohead_id)
+    LEFT OUTER JOIN prj ON (poitem_prj_id=prj_id)
+    LEFT OUTER JOIN expcat ON (poitem_expcat_id=expcat_id)
+    LEFT OUTER JOIN itemsite ON (poitem_itemsite_id=itemsite_id)
+    LEFT OUTER JOIN item ON (itemsite_item_id=item_id)
+    LEFT OUTER JOIN whsinfo ON (itemsite_warehous_id=warehous_id)
+    LEFT OUTER JOIN coitem ON (coitem_id=poitem_order_id AND poitem_order_type='S')
+    LEFT OUTER JOIN womatl ON (womatl_id=poitem_order_id AND poitem_order_type='W')
+  ORDER BY pohead_number,poitem_linenumber;
+--TODO add label to expense category
+GRANT ALL ON TABLE api.purchaseline TO xtrole;
+COMMENT ON VIEW api.purchaseline IS 'Purchase Order Line';
+
+  --Rules
+
+  CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.purchaseline DO INSTEAD
+
+  INSERT INTO poitem (
+    poitem_pohead_id,
+    poitem_linenumber,
+    poitem_duedate,
+    poitem_itemsite_id,
+    poitem_vend_item_descrip,
+    poitem_qty_ordered,
+    poitem_unitprice,
+    poitem_vend_item_number,
+    poitem_manuf_name,
+    poitem_manuf_item_number,
+    poitem_manuf_item_descrip,
+    poitem_comments,
+    poitem_expcat_id,
+    poitem_freight,
+    poitem_prj_id,
+    poitem_bom_rev_id,
+    poitem_boo_rev_id) 
+  VALUES (
+    getPoheadId(NEW.order_number),
+    NEW.line_number,
+    NEW.due_date,
+    getItemsiteId(COALESCE(NEW.site,
+     (SELECT warehous_code
+      FROM pohead JOIN whsinfo ON (warehous_id=pohead_warehous_id)
+      WHERE (pohead_id=getPoheadId(NEW.order_number))),
+     (SELECT warehous_code 
+      FROM whsinfo
+      WHERE (warehous_id=fetchPrefwarehousId())
+      )),NEW.item_number),
+    NEW.vendor_description,
+    NEW.qty_ordered,
+    NEW.unit_price,
+    NEW.vend_item_number,
+    NEW.manufacturer_name,
+    NEW.manufacturer_item_number,
+    NEW.manufacturer_description,
+    NEW.notes,
+    getExpcatId(NEW.expense_category),
+    NEW.freight,
+    getPrjId(NEW.project_number),
+    getRevId('BOM',NEW.item_number,NEW.bill_of_materials_revision),
+    getRevId('BOO',NEW.item_number,NEW.bill_of_operations_revision));
+
+CREATE OR REPLACE RULE "_INSERT_CHAR" AS
+  ON INSERT TO api.purchaseline DO INSTEAD
+    
+INSERT INTO charass (charass_target_type, charass_target_id, charass_char_id, charass_value)
+SELECT 'PI', poitem_id, char_id, charass_value
+FROM pohead, poitem, charass, char, itemsite, item
+  WHERE ((pohead_number=NEW.order_number)
+    AND (poitem_pohead_id=pohead_id)
+    AND (poitem_linenumber=NEW.line_number)
+    AND (itemsite_id=poitem_itemsite_id)
+    AND (itemsite_item_id=item_id)
+    AND (charass_target_type='I') 
+    AND (charass_target_id=item_id)
+    AND (charass_default)
+    AND (char_id=charass_char_id));
+  CREATE OR REPLACE RULE "_UPDATE" AS
+  ON UPDATE TO api.purchaseline DO INSTEAD
+
+  UPDATE poitem SET
+    poitem_duedate=NEW.due_date,
+    poitem_qty_ordered=NEW.qty_ordered,
+    poitem_unitprice=NEW.unit_price,
+    poitem_vend_item_number=NEW.vend_item_number,
+    poitem_vend_item_descrip=NEW.vendor_description,
+    poitem_manuf_name=NEW.manufacturer_name,
+    poitem_manuf_item_number=NEW.manufacturer_item_number,
+    poitem_manuf_item_descrip=NEW.manufacturer_description,
+    poitem_comments=NEW.notes,
+    poitem_freight=NEW.freight,
+    poitem_prj_id=getPrjId(NEW.project_number),
+    poitem_bom_rev_id=getRevId('BOM',OLD.item_number,NEW.bill_of_materials_revision),
+    poitem_boo_rev_id=getRevId('BOO',OLD.item_number,NEW.bill_of_operations_revision)
+  WHERE (poitem_id=getPoitemId(OLD.order_number::text,OLD.line_number));
+
+  CREATE OR REPLACE RULE "_DELETE" AS
+  ON DELETE TO api.purchaseline DO INSTEAD
+
+  DELETE FROM poitem
+  WHERE (poitem_id=getPoitemId(OLD.order_number::text,OLD.line_number));
diff --git a/foundation-database/api/views/purchaselinechar.sql b/foundation-database/api/views/purchaselinechar.sql
new file mode 100644 (file)
index 0000000..396ea24
--- /dev/null
@@ -0,0 +1,72 @@
+-- Purchase Order Line Characteristics
+SELECT dropifexists('VIEW','purchaselinechar','API');
+CREATE VIEW api.purchaselinechar
+AS 
+SELECT 
+  order_number::VARCHAR,
+  line_number,
+  characteristic,
+  COALESCE(pi.charass_value,i3.charass_value) AS value
+FROM
+  (SELECT DISTINCT 
+    char_id,
+    poitem_id,
+    poitem_itemsite_id,
+    pohead_number AS order_number, 
+    poitem_linenumber AS line_number,
+    char_name AS characteristic
+   FROM pohead, poitem, itemsite, item, charass, char
+   WHERE ( (pohead_id=poitem_pohead_id)
+   AND (poitem_itemsite_id=itemsite_id)
+   AND (itemsite_item_id=item_id)
+   AND (charass_char_id=char_id)
+   AND (charass_target_type='I')
+   AND (charass_target_id=item_id) ) ) AS data
+  LEFT OUTER JOIN charass  pi ON ((poitem_id=pi.charass_target_id)
+                              AND ('PI'=pi.charass_target_type)
+                              AND (pi.charass_char_id=char_id))
+  LEFT OUTER JOIN itemsite i1 ON (poitem_itemsite_id=i1.itemsite_id)
+  LEFT OUTER JOIN item     i2 ON (i1.itemsite_item_id=i2.item_id)
+  LEFT OUTER JOIN charass  i3 ON ((i2.item_id=i3.charass_target_id)
+                              AND ('I'=i3.charass_target_type)
+                              AND (i3.charass_char_id=char_id)
+                              AND (i3.charass_default))
+ORDER BY order_number,line_number, characteristic;
+
+GRANT ALL ON TABLE api.purchaselinechar TO xtrole;
+COMMENT ON VIEW api.purchaselinechar IS 'Purchase Order Line Item Characteristic';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.purchaselinechar DO INSTEAD
+
+SELECT DISTINCT updateCharAssignment('PI', poitem_id, charass_char_id, NEW.value)
+FROM pohead, poitem, itemsite, item, charass, char
+WHERE ((pohead_number=NEW.order_number)
+AND (pohead_id=poitem_pohead_id)
+AND (poitem_linenumber=NEW.line_number)
+AND (poitem_itemsite_id=itemsite_id)
+AND (item_id=itemsite_item_id)
+AND (charass_target_type='I')
+AND (charass_target_id=item_id)
+AND (char_id=charass_char_id)
+AND (char_name=NEW.characteristic));
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.purchaselinechar DO INSTEAD
+
+SELECT DISTINCT updateCharAssignment('PI', poitem_id, charass_char_id, NEW.value)
+FROM pohead, poitem, itemsite, item, charass, char
+WHERE ((pohead_number=OLD.order_number)
+AND (pohead_id=poitem_pohead_id)
+AND (poitem_linenumber=OLD.line_number)
+AND (poitem_itemsite_id=itemsite_id)
+AND (item_id=itemsite_item_id)
+AND (charass_target_type='I')
+AND (charass_target_id=item_id)
+AND (char_id=charass_char_id)
+AND (char_name=OLD.characteristic));
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.purchaselinechar DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/purchaselinecomment.sql b/foundation-database/api/views/purchaselinecomment.sql
new file mode 100644 (file)
index 0000000..308f11a
--- /dev/null
@@ -0,0 +1,51 @@
+-- Purchase Order Line Item Comment
+SELECT dropifexists('VIEW','purchaselinecomment','API');
+CREATE VIEW api.purchaselinecomment
+AS 
+   SELECT 
+     pohead_number::VARCHAR AS order_number,
+     poitem_linenumber AS line_number, 
+     cmnttype_name AS type,
+     comment_date AS date,
+     comment_user AS username,
+     comment_text AS text
+   FROM pohead, poitem, cmnttype, comment
+   WHERE ((pohead_id=poitem_pohead_id)
+   AND (comment_source='PI')
+   AND (comment_source_id=poitem_id)
+   AND (comment_cmnttype_id=cmnttype_id))
+   ORDER BY pohead_number ASC, poitem_linenumber ASC, comment_date DESC;
+
+GRANT ALL ON TABLE api.purchaselinecomment TO xtrole;
+COMMENT ON VIEW api.purchaselinecomment IS 'Purchase Order Line Item Comment';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.purchaselinecomment DO INSTEAD
+
+  INSERT INTO comment (
+    comment_date,
+    comment_source,
+    comment_source_id,
+    comment_user,
+    comment_cmnttype_id,
+    comment_text
+    )
+  SELECT 
+    COALESCE(NEW.date,current_date),
+    'PI',
+    poitem_id,
+    COALESCE(NEW.username,getEffectiveXtUser()),
+    getCmntTypeId(NEW.type),
+    NEW.text
+  FROM poitem, pohead
+  WHERE ((pohead_number=NEW.order_number)
+  AND (poitem_pohead_id=pohead_id)
+  AND (poitem_linenumber=NEW.line_number));
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.purchaselinecomment DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.purchaselinecomment DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/purchaseorder.sql b/foundation-database/api/views/purchaseorder.sql
new file mode 100644 (file)
index 0000000..96d476e
--- /dev/null
@@ -0,0 +1,258 @@
+  --Purchase Order View
+
+  SELECT dropIfExists('VIEW', 'purchaseorder', 'api');
+  CREATE OR REPLACE VIEW api.purchaseorder AS
+
+  SELECT
+    pohead_number::varchar AS order_number,
+    pohead_orderdate AS order_date,
+    terms_code AS terms,
+    taxzone_code AS tax_zone,
+    warehous_code AS receiving_site,
+    pohead_agent_username AS purchasing_agent,
+    vend_number AS vendor_number,
+    COALESCE(vendaddr_code,'MAIN') AS alt_address,
+    pohead_fob AS fob,
+    pohead_shipvia AS ship_via,
+    curr_abbr AS currency,
+    (SELECT COALESCE(SUM(tax), 0.00) AS tax
+     FROM (SELECT ROUND(SUM(taxdetail_tax),2) AS tax
+           FROM tax
+            JOIN calculateTaxDetailSummary('PO', pohead_id, 'T') ON (taxdetail_tax_id=tax_id)
+           GROUP BY tax_id) AS data) AS tax,
+    pohead_freight AS freight,
+    pohead_comments AS notes,
+    pohead_dropship AS dropship,
+    vc.cntct_number AS vend_contact_number,
+    pohead_vend_cntct_honorific AS vend_cntct_honorific,
+    pohead_vend_cntct_first_name AS vend_cntct_first_name,
+    pohead_vend_cntct_middle AS vend_cntct_middle,
+    pohead_vend_cntct_last_name AS vend_cntct_last_name,
+    pohead_vend_cntct_suffix AS vend_cntct_suffix,
+    pohead_vend_cntct_phone AS vend_cntct_phone,
+    pohead_vend_cntct_title AS vend_cntct_title,
+    pohead_vend_cntct_fax AS vend_cntct_fax,
+    pohead_vend_cntct_email AS vend_cntct_email,
+    pohead_vendaddress1 AS vendaddress1,
+    pohead_vendaddress2 AS vendaddress2,
+    pohead_vendaddress3 AS vendaddress3,
+    pohead_vendcity AS vendcity,
+    pohead_vendstate AS vendstate,
+    pohead_vendzipcode AS vendzipcode,
+    pohead_vendcountry AS vendcountry,
+    sc.cntct_number AS shipto_contact_number,
+    pohead_shipto_cntct_honorific AS shipto_cntct_honorific,
+    pohead_shipto_cntct_first_name AS shipto_cntct_first_name,
+    pohead_shipto_cntct_middle AS shipto_cntct_middle,
+    pohead_shipto_cntct_last_name AS shipto_cntct_last_name,
+    pohead_shipto_cntct_suffix AS shipto_cntct_suffix,
+    pohead_shipto_cntct_phone AS shipto_cntct_phone,
+    pohead_shipto_cntct_title AS shipto_cntct_title,
+    pohead_shipto_cntct_fax AS shipto_cntct_fax,
+    pohead_shipto_cntct_email AS shipto_cntct_email,
+    addr_number AS shiptoaddress_number,
+    pohead_shiptoaddress1 AS shiptoaddress1,
+    pohead_shiptoaddress2 AS shiptoaddress2,
+    pohead_shiptoaddress3 AS shiptoaddress3,
+    pohead_shiptocity AS shiptocity,
+    pohead_shiptostate AS shiptostate,
+    pohead_shiptozipcode AS shiptozipcode,
+    pohead_shiptocountry AS shiptocountry,
+    cohead_number AS sales_order_number
+  FROM pohead
+    LEFT OUTER JOIN cntct vc ON (pohead_vend_cntct_id=vc.cntct_id)
+    LEFT OUTER JOIN cntct sc ON (pohead_shipto_cntct_id=sc.cntct_id)
+    LEFT OUTER JOIN addr     ON (pohead_shiptoaddress_id=addr_id)
+    LEFT OUTER JOIN terms ON (pohead_terms_id=terms_id)
+    LEFT OUTER JOIN taxzone ON (pohead_taxzone_id=taxzone_id)
+    LEFT OUTER JOIN whsinfo ON (pohead_warehous_id=warehous_id)
+    LEFT OUTER JOIN vendaddrinfo ua ON (pohead_vendaddr_id=vendaddr_id)
+    LEFT OUTER JOIN cohead ON (pohead_cohead_id=cohead_id)
+    JOIN vendinfo ON (pohead_vend_id=vend_id)
+    JOIN curr_symbol ON (pohead_curr_id=curr_id)
+  ORDER BY pohead_number;
+
+GRANT ALL ON TABLE api.purchaseorder TO xtrole;
+COMMENT ON VIEW api.purchaseorder IS 'Purchase Order';
+
+  --Rules
+
+  CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.purchaseorder DO INSTEAD
+
+  INSERT INTO pohead (
+    pohead_number,
+    pohead_orderdate,
+    pohead_status,
+    pohead_terms_id,
+    pohead_taxzone_id,
+    pohead_warehous_id,
+    pohead_agent_username,
+    pohead_vend_id,
+    pohead_vendaddr_id,
+    pohead_fob,
+    pohead_shipvia,
+    pohead_curr_id,
+    pohead_freight,
+    pohead_comments,
+    pohead_dropship,
+    pohead_vend_cntct_id,
+    pohead_vend_cntct_honorific,
+    pohead_vend_cntct_first_name,
+    pohead_vend_cntct_middle,
+    pohead_vend_cntct_last_name,
+    pohead_vend_cntct_suffix,
+    pohead_vend_cntct_phone,
+    pohead_vend_cntct_title,
+    pohead_vend_cntct_fax,
+    pohead_vend_cntct_email,
+    pohead_vendaddress1,
+    pohead_vendaddress2,
+    pohead_vendaddress3,
+    pohead_vendcity,
+    pohead_vendstate,
+    pohead_vendzipcode,
+    pohead_vendcountry,
+    pohead_shipto_cntct_id,
+    pohead_shipto_cntct_honorific,
+    pohead_shipto_cntct_first_name,
+    pohead_shipto_cntct_middle,
+    pohead_shipto_cntct_last_name,
+    pohead_shipto_cntct_suffix,
+    pohead_shipto_cntct_phone,
+    pohead_shipto_cntct_title,
+    pohead_shipto_cntct_fax,
+    pohead_shipto_cntct_email,
+    pohead_shiptoaddress_id,
+    pohead_shiptoaddress1,
+    pohead_shiptoaddress2,
+    pohead_shiptoaddress3,
+    pohead_shiptocity,
+    pohead_shiptostate,
+    pohead_shiptozipcode,
+    pohead_shiptocountry,
+    pohead_cohead_id
+    )
+  SELECT
+    NEW.order_number,
+    COALESCE(NEW.order_date,current_date),
+    'U',
+    COALESCE(getTermsId(NEW.terms),vend_terms_id),
+    COALESCE(getTaxzoneId(NEW.tax_zone),vend_taxzone_id),
+    COALESCE(getWarehousId(NEW.receiving_site,'ALL'),fetchPrefwarehousid()),
+    COALESCE(NEW.purchasing_agent,getEffectiveXtUser()),
+    getVendId(NEW.vendor_number),
+    CASE WHEN (NEW.alt_address='MAIN') THEN NULL
+      ELSE getVendAddrId(NEW.vendor_number, NEW.alt_address) END,
+    COALESCE(NEW.fob,
+      CASE WHEN (vend_fobsource='W') THEN (
+        SELECT warehous_fob
+        FROM whsinfo
+        WHERE (warehous_id=COALESCE(getWarehousId(NEW.receiving_site,'ALL'),fetchPrefWarehousId()))
+      )
+      ELSE vend_fob END),
+    COALESCE(NEW.ship_via,vend_shipvia),
+    COALESCE(getCurrId(NEW.currency),vend_curr_id),
+    COALESCE(NEW.freight,0),
+    NEW.notes,
+    COALESCE(NEW.dropship, FALSE),
+    getCntctId(NEW.vend_contact_number),
+    COALESCE(NEW.vend_cntct_honorific,''),
+    COALESCE(NEW.vend_cntct_first_name,''),
+    COALESCE(NEW.vend_cntct_middle,''),
+    COALESCE(NEW.vend_cntct_last_name,''),
+    COALESCE(NEW.vend_cntct_suffix,''),
+    COALESCE(NEW.vend_cntct_phone,''),
+    COALESCE(NEW.vend_cntct_title,''),
+    COALESCE(NEW.vend_cntct_fax,''),
+    COALESCE(NEW.vend_cntct_email,''),
+    COALESCE(NEW.vendaddress1,''),
+    COALESCE(NEW.vendaddress2,''),
+    COALESCE(NEW.vendaddress3,''),
+    COALESCE(NEW.vendcity,''),
+    COALESCE(NEW.vendstate,''),
+    COALESCE(NEW.vendzipcode,''),
+    COALESCE(NEW.vendcountry,''),
+    getCntctId(NEW.shipto_contact_number),
+    COALESCE(NEW.shipto_cntct_honorific,''),
+    COALESCE(NEW.shipto_cntct_first_name,''),
+    COALESCE(NEW.shipto_cntct_middle,''),
+    COALESCE(NEW.shipto_cntct_last_name,''),
+    COALESCE(NEW.shipto_cntct_suffix,''),
+    COALESCE(NEW.shipto_cntct_phone,''),
+    COALESCE(NEW.shipto_cntct_title,''),
+    COALESCE(NEW.shipto_cntct_fax,''),
+    COALESCE(NEW.shipto_cntct_email,''),
+    getAddrId(NEW.shiptoaddress_number),
+    COALESCE(NEW.shiptoaddress1,''),
+    COALESCE(NEW.shiptoaddress2,''),
+    COALESCE(NEW.shiptoaddress3,''),
+    COALESCE(NEW.shiptocity,''),
+    COALESCE(NEW.shiptostate,''),
+    COALESCE(NEW.shiptozipcode,''),
+    COALESCE(NEW.shiptocountry,''),
+    getCoheadId(NEW.sales_order_number)
+  FROM vendinfo
+  WHERE (vend_id=getVendId(NEW.vendor_number));
+  CREATE OR REPLACE RULE "_UPDATE" AS
+  ON UPDATE TO api.purchaseorder DO INSTEAD
+
+  UPDATE pohead SET
+    pohead_terms_id=getTermsId(NEW.terms),
+    pohead_taxzone_id=getTaxzoneId(NEW.tax_zone),
+    pohead_warehous_id=getWarehousId(NEW.receiving_site,'ALL'),
+    pohead_agent_username=NEW.purchasing_agent,
+    pohead_vendaddr_id=
+      CASE WHEN (NEW.alt_address='MAIN') THEN NULL
+      ELSE getVendAddrId(OLD.vendor_number, NEW.alt_address) END,
+    pohead_fob=NEW.fob,
+    pohead_shipvia=NEW.ship_via,
+    pohead_curr_id=getCurrId(NEW.currency),
+    pohead_freight=NEW.freight,
+    pohead_comments=NEW.notes,
+    pohead_dropship=NEW.dropship,
+    pohead_vend_cntct_id=getCntctId(NEW.vend_contact_number),
+    pohead_vend_cntct_honorific=NEW.vend_cntct_honorific,
+    pohead_vend_cntct_first_name=NEW.vend_cntct_first_name,
+    pohead_vend_cntct_middle=NEW.vend_cntct_middle,
+    pohead_vend_cntct_last_name=NEW.vend_cntct_last_name,
+    pohead_vend_cntct_suffix=NEW.vend_cntct_suffix,
+    pohead_vend_cntct_phone=NEW.vend_cntct_phone,
+    pohead_vend_cntct_title=NEW.vend_cntct_title,
+    pohead_vend_cntct_fax=NEW.vend_cntct_fax,
+    pohead_vend_cntct_email=NEW.vend_cntct_email,
+    pohead_vendaddress1=NEW.vendaddress1,
+    pohead_vendaddress2=NEW.vendaddress2,
+    pohead_vendaddress3=NEW.vendaddress3,
+    pohead_vendcity=NEW.vendcity,
+    pohead_vendstate=NEW.vendstate,
+    pohead_vendzipcode=NEW.vendzipcode,
+    pohead_vendcountry=NEW.vendcountry,
+    pohead_shipto_cntct_id=getCntctId(NEW.shipto_contact_number),
+    pohead_shipto_cntct_honorific=NEW.shipto_cntct_honorific,
+    pohead_shipto_cntct_first_name=NEW.shipto_cntct_first_name,
+    pohead_shipto_cntct_middle=NEW.shipto_cntct_middle,
+    pohead_shipto_cntct_last_name=NEW.shipto_cntct_last_name,
+    pohead_shipto_cntct_suffix=NEW.shipto_cntct_suffix,
+    pohead_shipto_cntct_phone=NEW.shipto_cntct_phone,
+    pohead_shipto_cntct_title=NEW.shipto_cntct_title,
+    pohead_shipto_cntct_fax=NEW.shipto_cntct_fax,
+    pohead_shipto_cntct_email=NEW.shipto_cntct_email,
+    pohead_shiptoaddress_id=getAddrId(NEW.shiptoaddress_number),
+    pohead_shiptoaddress1=NEW.shiptoaddress1,
+    pohead_shiptoaddress2=NEW.shiptoaddress2,
+    pohead_shiptoaddress3=NEW.shiptoaddress3,
+    pohead_shiptocity=NEW.shiptocity,
+    pohead_shiptostate=NEW.shiptostate,
+    pohead_shiptozipcode=NEW.shiptozipcode,
+    pohead_shiptocountry=NEW.shiptocountry,
+    pohead_cohead_id=getCoheadId(NEW.sales_order_number)
+  WHERE (pohead_number=OLD.order_number);
+
+  CREATE OR REPLACE RULE "_DELETE" AS
+  ON DELETE TO api.purchaseorder DO INSTEAD
+
+  SELECT deletepo(pohead_id)
+  FROM pohead
+  WHERE (pohead_number=OLD.order_number);
diff --git a/foundation-database/api/views/purchaseordercomment.sql b/foundation-database/api/views/purchaseordercomment.sql
new file mode 100644 (file)
index 0000000..9ec66b2
--- /dev/null
@@ -0,0 +1,44 @@
+-- Purchase Order Comment
+SELECT dropifexists('VIEW', 'purchaseordercomment','API');
+CREATE VIEW api.purchaseordercomment
+AS 
+   SELECT 
+     pohead_number::VARCHAR AS order_number,
+     cmnttype_name AS type,
+     comment_date AS date,
+     comment_user AS username,
+     comment_text AS text
+   FROM pohead, cmnttype, comment
+   WHERE ((comment_source='P')
+   AND (comment_source_id=pohead_id)
+   AND (comment_cmnttype_id=cmnttype_id));
+
+GRANT ALL ON TABLE api.purchaseordercomment TO xtrole;
+COMMENT ON VIEW api.purchaseordercomment IS 'Purchase Order Comment';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.purchaseordercomment DO INSTEAD
+
+  INSERT INTO comment (
+    comment_date,
+    comment_source,
+    comment_source_id,
+    comment_user,
+    comment_cmnttype_id,
+    comment_text
+    )
+  VALUES (
+    COALESCE(NEW.date,current_date),
+    'P',
+    getPoheadId(NEW.order_number),
+    COALESCE(NEW.username,getEffectiveXtUser()),
+    getCmntTypeId(NEW.type),
+    NEW.text);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.purchaseordercomment DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.purchaseordercomment DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/quote.sql b/foundation-database/api/views/quote.sql
new file mode 100644 (file)
index 0000000..2624542
--- /dev/null
@@ -0,0 +1,234 @@
+-- Quote
+
+SELECT dropIfExists('VIEW', 'quote', 'api');
+CREATE VIEW api.quote
+AS
+   SELECT 
+     quhead_number::varchar AS quote_number,
+     warehous_code AS site,
+     quhead_quotedate AS quote_date,
+     quhead_packdate AS pack_date,
+     saletype_code AS sale_type,
+     salesrep_number AS sales_rep,
+     quhead_commission AS commission,
+     taxzone_code AS tax_zone,
+     taxtype_name AS tax_type,
+     terms_code AS terms,
+     prj_number AS project_number,
+     COALESCE(cust_number,prospect_number) AS customer_number,
+     quhead_billtoname AS billto_name,
+     quhead_billtoaddress1 AS billto_address1,
+     quhead_billtoaddress2 AS billto_address2,
+     quhead_billtoaddress3 AS billto_address3,
+     quhead_billtocity AS billto_city,
+     quhead_billtostate AS billto_state,
+     quhead_billtozip AS billto_postal_code,
+     quhead_billtocountry AS billto_country,
+     shipto_num AS shipto_number,
+     quhead_shiptoname AS shipto_name,
+     quhead_shiptophone AS shipto_phone,
+     quhead_shiptoaddress1 AS shipto_address1,
+     quhead_shiptoaddress2 AS shipto_address2,
+     quhead_shiptoaddress3 AS shipto_address3,
+     quhead_shiptocity AS shipto_city,
+     quhead_shiptostate AS shipto_state,
+     quhead_shiptozipcode AS shipto_postal_code,
+     quhead_shiptocountry AS shipto_country,
+     shipzone_name AS shipto_shipzone,
+     quhead_custponumber AS cust_po_number,
+     quhead_fob AS fob,
+     quhead_shipvia AS ship_via,
+     curr_abbr AS currency,
+     quhead_misc_descrip AS misc_charge_description,
+     CASE
+       WHEN (quhead_misc_accnt_id IS NULL) THEN
+         NULL
+       ELSE
+         formatglaccount(quhead_misc_accnt_id) 
+     END AS misc_account_number,
+     quhead_misc AS misc_charge,
+     quhead_freight AS freight,
+     quhead_ordercomments AS order_notes,
+     quhead_shipcomments AS shipping_notes,
+     false AS add_to_packing_list_batch,
+     quhead_expire AS expire_date,
+     CASE
+       WHEN quhead_status='C' THEN
+         'Converted'
+       ELSE
+         'Open'
+     END AS status
+   FROM curr_symbol,quhead
+     LEFT OUTER JOIN whsinfo ON (quhead_warehous_id=warehous_id)
+     LEFT OUTER JOIN prj ON (quhead_prj_id=prj_id)
+     LEFT OUTER JOIN shiptoinfo ON (quhead_shipto_id=shipto_id)
+     LEFT OUTER JOIN taxzone ON (quhead_taxzone_id=taxzone_id)
+     LEFT OUTER JOIN taxtype ON (quhead_taxtype_id=taxtype_id)
+     LEFT OUTER JOIN custinfo ON (quhead_cust_id=cust_id)
+     LEFT OUTER JOIN prospect ON (quhead_cust_id=prospect_id)
+     LEFT OUTER JOIN salesrep ON (quhead_salesrep_id=salesrep_id)
+     LEFT OUTER JOIN terms ON (quhead_terms_id=terms_id)
+     LEFT OUTER JOIN saletype ON (quhead_saletype_id=saletype_id)
+     LEFT OUTER JOIN shipzone ON (quhead_shipzone_id=shipzone_id)
+   WHERE (quhead_curr_id=curr_id);
+
+GRANT ALL ON TABLE api.quote TO xtrole;
+COMMENT ON VIEW api.quote IS 'Quote';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.quote DO INSTEAD
+
+  INSERT INTO quhead (
+    quhead_number,
+    quhead_cust_id,
+    quhead_custponumber,
+    quhead_quotedate,
+    quhead_warehous_id,
+    quhead_shipto_id,
+    quhead_shiptoname,
+    quhead_shiptoaddress1,
+    quhead_shiptoaddress2,
+    quhead_shiptoaddress3,
+    quhead_salesrep_id,
+    quhead_terms_id,
+    quhead_fob,
+    quhead_shipvia,
+    quhead_shiptocity,
+    quhead_shiptostate,
+    quhead_shiptozipcode,
+    quhead_freight,
+    quhead_misc,
+    quhead_ordercomments,
+    quhead_shipcomments,
+    quhead_shiptophone,
+    quhead_billtoname,
+    quhead_billtoaddress1,
+    quhead_billtoaddress2,
+    quhead_billtoaddress3,
+    quhead_billtocity,
+    quhead_billtostate,
+    quhead_billtozip,
+    quhead_misc_accnt_id,
+    quhead_misc_descrip,
+    quhead_commission,
+    quhead_packdate,
+    quhead_prj_id,
+    quhead_billtocountry,
+    quhead_shiptocountry,
+    quhead_curr_id,
+    quhead_taxzone_id,
+    quhead_taxtype_id,
+    quhead_imported,
+    quhead_expire,
+    quhead_status,
+    quhead_saletype_id,
+    quhead_shipzone_id
+    )
+  VALUES (
+    NEW.quote_number,
+    getCustId(NEW.customer_number,true),
+    NEW.cust_po_number,
+    NEW.quote_date,
+    getWarehousId(NEW.site,'SHIPPING'),
+    getShiptoId(NEW.customer_number,NEW.shipto_number),
+    NEW.shipto_name,
+    NEW.shipto_address1,
+    NEW.shipto_address2,
+    NEW.shipto_address3,
+    getSalesRepId(NEW.sales_rep),
+    getTermsId(NEW.terms),
+    NEW.fob,
+    NEW.ship_via,
+    NEW.shipto_city,
+    NEW.shipto_state,
+    NEW.shipto_postal_code,
+    NEW.freight,
+    NEW.misc_charge,
+    NEW.order_notes,
+    NEW.shipping_notes,
+    NEW.shipto_phone,
+    NEW.billto_name,
+    NEW.billto_address1,
+    NEW.billto_address2,
+    NEW.billto_address3,
+    NEW.billto_city,
+    NEW.billto_state,
+    NEW.billto_postal_code,
+    getGlAccntId(NEW.misc_account_number),
+    NEW.misc_charge_description,
+    NEW.commission,
+    NEW.pack_date,
+    getPrjId(NEW.project_number),
+    NEW.billto_country,
+    NEW.shipto_country,
+    getCurrId(NEW.currency),
+    getTaxZoneId(NEW.tax_zone),
+    getTaxTypeId(NEW.tax_type),
+    true,
+    NEW.expire_date,
+    CASE
+      WHEN NEW.status = 'Converted' THEN
+        'C'
+      ELSE
+        'O'
+    END,
+    getSaleTypeId(NEW.sale_type),
+    getShipZoneId(NEW.shipto_shipzone)
+);
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.quote DO INSTEAD
+
+  UPDATE quhead SET
+    quhead_number=OLD.quote_number,
+    quhead_cust_id=getCustId(NEW.customer_number,true),
+    quhead_custponumber=NEW.cust_po_number,
+    quhead_quotedate=NEW.quote_date,
+    quhead_warehous_id=getWarehousId(NEW.site,'SHIPPING'),
+    quhead_shipto_id=getShiptoId(NEW.customer_number,NEW.shipto_number),
+    quhead_shiptoname=NEW.shipto_name,
+    quhead_shiptoaddress1=NEW.shipto_address1,
+    quhead_shiptoaddress2=NEW.shipto_address2,
+    quhead_shiptoaddress3=NEW.shipto_address3,
+    quhead_salesrep_id=getSalesRepId(NEW.sales_rep),
+    quhead_terms_id=getTermsId(NEW.terms),
+    quhead_fob=NEW.fob,
+    quhead_shipvia=NEW.ship_via,
+    quhead_shiptocity=NEW.shipto_city,
+    quhead_shiptostate=NEW.shipto_state,
+    quhead_shiptozipcode=NEW.shipto_postal_code,
+    quhead_freight=NEW.freight,
+    quhead_misc=NEW.misc_charge,
+    quhead_ordercomments=NEW.order_notes,
+    quhead_shipcomments=NEW.shipping_notes,
+    quhead_shiptophone=NEW.shipto_phone,
+    quhead_billtoname=NEW.billto_name,
+    quhead_billtoaddress1=NEW.billto_address1,
+    quhead_billtoaddress2=NEW.billto_address2,
+    quhead_billtoaddress3=NEW.billto_address3,
+    quhead_billtocity=NEW.billto_city,
+    quhead_billtostate=NEW.billto_state,
+    quhead_billtozip=NEW.billto_postal_code,
+    quhead_misc_accnt_id=getGlAccntId(NEW.misc_account_number),
+    quhead_misc_descrip=NEW.misc_charge_description,
+    quhead_commission=NEW.commission,
+    quhead_packdate=NEW.pack_date,
+    quhead_prj_id=getPrjId(NEW.project_number),
+    quhead_billtocountry=NEW.billto_country,
+    quhead_shiptocountry=NEW.shipto_country,
+    quhead_curr_id=getCurrId(NEW.currency),
+    quhead_taxzone_id=getTaxZoneId(NEW.tax_zone),
+    quhead_taxtype_id=getTaxTypeId(NEW.tax_type),
+    quhead_expire=NEW.expire_date,
+    quhead_saletype_id=getSaleTypeId(NEW.sale_type),
+    quhead_shipzone_id=getShipZoneId(NEW.shipto_shipzone)
+  WHERE (quhead_number=OLD.quote_number);
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.quote DO INSTEAD
+
+  SELECT deletequote(quhead_id,OLD.quote_number)
+  FROM quhead
+  WHERE (quhead_number=OLD.quote_number);
diff --git a/foundation-database/api/views/quotecomment.sql b/foundation-database/api/views/quotecomment.sql
new file mode 100644 (file)
index 0000000..08c3a1b
--- /dev/null
@@ -0,0 +1,45 @@
+-- Quote Comment
+
+SELECT dropIfExists('VIEW', 'quotecomment', 'api');
+CREATE VIEW api.quotecomment
+AS 
+   SELECT 
+     quhead_number AS quote_number,
+     cmnttype_name AS type,
+     comment_date AS date,
+     comment_user AS username,
+     comment_text AS text
+   FROM quhead, cmnttype, comment
+   WHERE ((comment_source='Q')
+   AND (comment_source_id=quhead_id)
+   AND (comment_cmnttype_id=cmnttype_id));
+
+GRANT ALL ON TABLE api.quotecomment TO xtrole;
+COMMENT ON VIEW api.quotecomment IS 'Quote Comment';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.quotecomment DO INSTEAD
+
+  INSERT INTO comment (
+    comment_date,
+    comment_source,
+    comment_source_id,
+    comment_user,
+    comment_cmnttype_id,
+    comment_text
+    )
+  VALUES (
+    COALESCE(NEW.date,current_date),
+    'Q',
+    getQuoteId(NEW.quote_number),
+    COALESCE(NEW.username,getEffectiveXtUser()),
+    getCmntTypeId(NEW.type),
+    NEW.text);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.quotecomment DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.quotecomment DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/quoteline.sql b/foundation-database/api/views/quoteline.sql
new file mode 100644 (file)
index 0000000..4e244ed
--- /dev/null
@@ -0,0 +1,143 @@
+-- Quote Line
+
+SELECT dropIfExists('VIEW', 'quoteline', 'api');
+CREATE VIEW api.quoteline
+AS 
+  SELECT 
+     quhead_number AS quote_number,
+     quitem_linenumber AS line_number,
+     l.item_number AS item_number,
+     quitem_custpn AS customer_pn,
+     i.warehous_code AS sold_from_site,
+     quitem_qtyord AS qty_ordered,
+     q.uom_name AS qty_uom,
+     quitem_price AS net_unit_price,
+     p.uom_name AS price_uom,
+     quitem_scheddate AS scheduled_date,
+     COALESCE((
+       SELECT taxtype_name
+       FROM taxtype
+       WHERE (taxtype_id=getItemTaxType(l.item_id, quhead_taxzone_id))),'None') AS tax_type,
+     CASE
+       WHEN quitem_price = 0 THEN
+         '100'
+       WHEN quitem_custprice = 0 THEN
+         'N/A'
+       ELSE
+         CAST(ROUND(((1 - quitem_price / quitem_custprice) * 100),4) AS text)
+     END AS discount_pct_from_list,
+     quitem_createorder AS create_order,
+     s.warehous_code AS supplying_site,
+     quitem_prcost AS overwrite_po_price,
+     quitem_memo AS notes
+  FROM quhead, uom q, uom p, quitem
+    LEFT OUTER JOIN whsinfo s ON (quitem_order_warehous_id=s.warehous_id),
+  itemsite il, item l, whsinfo i
+  WHERE ((quhead_id=quitem_quhead_id)
+  AND (quitem_itemsite_id=il.itemsite_id)
+  AND (il.itemsite_item_id=l.item_id)
+  AND (il.itemsite_warehous_id=i.warehous_id)
+  AND (quitem_qty_uom_id=q.uom_id)
+  AND (quitem_price_uom_id=p.uom_id))
+ORDER BY quhead_number,quitem_linenumber;
+    
+
+GRANT ALL ON TABLE api.quoteline TO xtrole;
+COMMENT ON VIEW api.quoteline IS 'Quote Line Item';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.quoteline DO INSTEAD
+
+  INSERT INTO quitem (
+    quitem_quhead_id,
+    quitem_linenumber,
+    quitem_itemsite_id,
+    quitem_scheddate,
+    quitem_qtyord,
+    quitem_unitcost,
+    quitem_price,
+    quitem_custprice,
+    quitem_memo,
+    quitem_imported,
+    quitem_custpn,
+    quitem_createorder,
+    quitem_order_warehous_id,
+    quitem_item_id,
+    quitem_prcost,
+    quitem_taxtype_id,
+    quitem_qty_uom_id,
+    quitem_qty_invuomratio,
+    quitem_price_uom_id,
+    quitem_price_invuomratio)
+  SELECT
+    getQuoteId(NEW.quote_number),
+    COALESCE(NEW.line_number,(
+      SELECT (COALESCE(MAX(quitem_linenumber), 0) + 1)
+              FROM quitem
+              WHERE (quitem_quhead_id=getQuoteId(NEW.quote_number)))),
+    itemsite_id,
+    COALESCE(NEW.scheduled_date,(
+      SELECT MIN(quitem_scheddate)
+      FROM quitem
+      WHERE (quitem_quhead_id=getQuoteId(NEW.quote_number)))),
+    NEW.qty_ordered,
+    stdCost(item_id),
+    COALESCE(NEW.net_unit_price,itemPrice(getItemId(NEW.item_number),quhead_cust_id,
+             quhead_shipto_id,NEW.qty_ordered,quhead_curr_id,quhead_quotedate)),
+    itemPrice(getItemId(NEW.item_number),quhead_cust_id,
+             quhead_shipto_id,NEW.qty_ordered,quhead_curr_id,quhead_quotedate),
+    COALESCE(NEW.notes,''),
+    true,
+    NEW.customer_pn,
+    COALESCE(NEW.create_order,false),
+    COALESCE(getWarehousId(NEW.supplying_site,'SHIPPING'),itemsite_warehous_id),
+    getItemId(NEW.item_number),
+    COALESCE(NEW.overwrite_po_price,0),
+    COALESCE(getTaxTypeId(NEW.tax_type), getItemTaxType(itemsite_item_id, quhead_taxzone_id)),
+    COALESCE(getUomId(NEW.qty_uom),item_inv_uom_id),
+    itemuomtouomratio(item_id,COALESCE(getUomId(NEW.qty_uom),item_inv_uom_id),item_inv_uom_id),
+    COALESCE(getUomId(NEW.price_uom),item_price_uom_id),
+    itemuomtouomratio(item_id,COALESCE(getUomId(NEW.price_uom),item_price_uom_id),item_price_uom_id)
+  FROM quhead, itemsite, item, whsinfo
+  WHERE ((quhead_number=NEW.quote_number)
+  AND (itemsite_warehous_id=warehous_id
+  AND (itemsite_item_id=item_id)
+  AND (itemsite_active)
+  AND (item_number=NEW.item_number)
+  AND (warehous_active)
+  AND (warehous_shipping)
+  AND (warehous_code=COALESCE(NEW.sold_from_site,(
+                                SELECT warehous_code
+                                FROM usrpref,whsinfo
+                                WHERE ((usrpref_username=getEffectiveXtUser())
+                                AND (usrpref_name='PreferredWarehouse')
+                                AND (warehous_id=CAST(usrpref_value AS INTEGER))))))));
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.quoteline DO INSTEAD
+
+  UPDATE quitem SET
+    quitem_scheddate=NEW.scheduled_date,
+    quitem_qtyord=NEW.qty_ordered,
+    quitem_qty_uom_id=getUomId(NEW.qty_uom),
+    quitem_qty_invuomratio=itemuomtouomratio(item_id,COALESCE(getUomId(NEW.qty_uom),item_inv_uom_id),item_inv_uom_id),
+    quitem_price=NEW.net_unit_price,
+    quitem_price_uom_id=getUomId(NEW.price_uom),
+    quitem_price_invuomratio=itemuomtouomratio(item_id,COALESCE(getUomId(NEW.price_uom),item_inv_uom_id),item_inv_uom_id),
+    quitem_memo=NEW.notes,
+    quitem_createorder=NEW.create_order,
+    quitem_order_warehous_id=getWarehousId(NEW.supplying_site,'SHIPPING'),
+    quitem_prcost=NEW.overwrite_po_price,
+    quitem_taxtype_id=getTaxTypeId(NEW.tax_type)
+   FROM item
+   WHERE ((quitem_quhead_id=getQuoteId(OLD.quote_number))
+   AND (quitem_linenumber=OLD.line_number));
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.quoteline DO INSTEAD
+
+  DELETE FROM quitem
+  WHERE ((quitem_quhead_id=getQuoteId(OLD.quote_number))
+  AND (quitem_linenumber=OLD.line_number));
diff --git a/foundation-database/api/views/quotelinechar.sql b/foundation-database/api/views/quotelinechar.sql
new file mode 100644 (file)
index 0000000..fe20dae
--- /dev/null
@@ -0,0 +1,66 @@
+-- Quote Line Characteristics
+
+SELECT dropIfExists('VIEW', 'quotelinechar', 'api');
+CREATE VIEW api.quotelinechar
+AS 
+SELECT DISTINCT quhead_number AS quote_number, 
+  quitem_linenumber AS line_number,
+  char_name AS characteristic,
+  COALESCE((
+    SELECT b.charass_value 
+    FROM charass b 
+    WHERE ((b.charass_target_type='QI') 
+    AND (b.charass_target_id=quitem_id) 
+    AND (b.charass_char_id=char_id))), (
+    SELECT c.charass_value 
+    FROM charass c 
+    WHERE ((c.charass_target_type='I') 
+    AND (c.charass_target_id=item_id) 
+    AND (c.charass_default) 
+    AND (c.charass_char_id=char_id)) LIMIT 1)) AS value
+FROM quhead, quitem, itemsite, item, charass a, char
+WHERE ( (quhead_id=quitem_quhead_id)
+AND (quitem_itemsite_id=itemsite_id)
+AND (itemsite_item_id=item_id)
+AND (a.charass_char_id=char_id)
+AND (a.charass_target_type='I')
+AND (a.charass_target_id=item_id) ) 
+ORDER BY quhead_number,quitem_linenumber, char_name;
+
+GRANT ALL ON TABLE api.quotelinechar TO xtrole;
+COMMENT ON VIEW api.quotelinechar IS 'Quote Line Item Characteristics';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.quotelinechar DO INSTEAD
+
+SELECT DISTINCT updateCharAssignment('QI', quitem_id, charass_char_id, NEW.value)
+FROM quhead, quitem, itemsite, item, charass, char
+WHERE ((quhead_number=NEW.quote_number)
+AND (quhead_id=quitem_quhead_id)
+AND (quitem_linenumber=NEW.line_number)
+AND (quitem_itemsite_id=itemsite_id)
+AND (item_id=itemsite_item_id)
+AND (charass_target_type='I')
+AND (charass_target_id=item_id)
+AND (char_id=charass_char_id)
+AND (char_name=NEW.characteristic));
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.quotelinechar DO INSTEAD
+
+SELECT DISTINCT updateCharAssignment('QI', quitem_id, charass_char_id, NEW.value)
+FROM quhead, quitem, itemsite, item, charass, char
+WHERE ((quhead_number=OLD.quote_number)
+AND (quhead_id=quitem_quhead_id)
+AND (quitem_linenumber=OLD.line_number)
+AND (quitem_itemsite_id=itemsite_id)
+AND (item_id=itemsite_item_id)
+AND (charass_target_type='I')
+AND (charass_target_id=item_id)
+AND (char_id=charass_char_id)
+AND (char_name=OLD.characteristic));
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.quotelinechar DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/quotelinecomment.sql b/foundation-database/api/views/quotelinecomment.sql
new file mode 100644 (file)
index 0000000..67c86a5
--- /dev/null
@@ -0,0 +1,48 @@
+-- Quote Line Item Comment
+
+SELECT dropIfExists('VIEW', 'quotelinecomment', 'api');
+CREATE VIEW api.quotelinecomment
+AS 
+   SELECT 
+     quhead_number AS quote_number,
+     quitem_linenumber AS line_number,
+     cmnttype_name AS type,
+     comment_date AS date,
+     comment_user AS username,
+     comment_text AS text
+   FROM quhead, quitem, cmnttype, comment
+   WHERE ((quhead_id=quitem_quhead_id)
+   AND (comment_source='QI')
+   AND (comment_source_id=quitem_id)
+   AND (comment_cmnttype_id=cmnttype_id))
+   ORDER BY quhead_number ASC, quitem_linenumber ASC, comment_date DESC;
+
+GRANT ALL ON TABLE api.quotelinecomment TO xtrole;
+COMMENT ON VIEW api.quotelinecomment IS 'Quote Line Item Comment';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.quotelinecomment DO INSTEAD
+
+  INSERT INTO comment (
+    comment_date,
+    comment_source,
+    comment_source_id,
+    comment_user,
+    comment_cmnttype_id,
+    comment_text
+    )
+  VALUES (
+    COALESCE(NEW.date,current_date),
+    'QI',
+    getQuoteLineItemId(NEW.quote_number,NEW.line_number),
+    COALESCE(NEW.username,getEffectiveXtUser()),
+    getCmntTypeId(NEW.type),
+    NEW.text);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.quotelinecomment DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.quotelinecomment DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/salescredit.sql b/foundation-database/api/views/salescredit.sql
new file mode 100644 (file)
index 0000000..15f35b0
--- /dev/null
@@ -0,0 +1,21 @@
+SELECT dropIfExists('VIEW', 'salescredit', 'api');
+
+CREATE OR REPLACE VIEW api.salescredit AS 
+ SELECT custinfo.cust_number AS customer_number, aropen.aropen_docnumber AS cm_number, cohead.cohead_number AS so_number,
+        aropenalloc.aropenalloc_amount::numeric(16,4) AS amount, curr.curr_abbr AS currency
+   FROM aropenalloc
+   LEFT JOIN aropen ON aropen.aropen_id = aropenalloc.aropenalloc_aropen_id
+   LEFT JOIN custinfo ON custinfo.cust_id = aropen.aropen_cust_id
+   LEFT JOIN cohead ON aropenalloc.aropenalloc_doctype='S' AND cohead.cohead_id = aropenalloc.aropenalloc_doc_id
+   LEFT JOIN curr_symbol curr ON curr.curr_id = aropenalloc.aropenalloc_curr_id
+ WHERE (aropenalloc_doctype='S');
+
+GRANT ALL ON TABLE api.salescredit TO xtrole;
+COMMENT ON VIEW api.salescredit IS 'Payments (credit memos) pre-applied to sales orders';
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.salescredit DO INSTEAD
+    INSERT INTO aropenalloc VALUES ( 
+    getaropenid( new.customer_number, 'C', new.cm_number ),
+    'S', getcoheadid(new.so_number),
+    new.amount, getcurrid(new.currency) );
diff --git a/foundation-database/api/views/saleshistory.sql b/foundation-database/api/views/saleshistory.sql
new file mode 100644 (file)
index 0000000..60b5dc5
--- /dev/null
@@ -0,0 +1,200 @@
+  --Sales History View
+
+  SELECT dropIfExists('VIEW', 'saleshistory', 'api');
+  CREATE OR REPLACE VIEW api.saleshistory AS
+
+  SELECT
+    cust_number AS customer_number,
+    item_number,
+    warehous_code AS site_code,
+    cohist_shipdate AS ship_date,
+    cohist_shipvia AS ship_via,
+    cohist_ordernumber AS order_number,
+    cohist_ponumber AS purchase_order_number,
+    cohist_orderdate AS order_date,
+    cohist_invcnumber AS invoice_number,
+    cohist_invcdate AS invoice_date,
+    cohist_qtyshipped AS quantity_shipped,
+    cohist_unitprice AS unit_price,
+    shipto_num AS shipto_number,
+    salesrep_number AS sales_rep,
+    cohist_duedate AS due_date,
+    cohist_promisedate AS promise_date,
+    cohist_imported AS imported,
+    cohist_billtoname AS billto_name,
+    cohist_billtoaddress1 AS billto_address1,
+    cohist_billtoaddress2 AS billto_address2,
+    cohist_billtoaddress3 AS billto_address3,
+    cohist_billtocity AS billto_city,
+    cohist_billtostate AS billto_state,
+    cohist_billtozip AS billto_zip,
+    cohist_shiptoname AS shipto_name,
+    cohist_shiptoaddress1 AS shipto_address1,
+    cohist_shiptoaddress2 AS shipto_address2,
+    cohist_shiptoaddress3 AS shipto_address3,
+    cohist_shiptocity AS shipto_city,
+    cohist_shiptostate AS shipto_state,
+    cohist_shiptozip AS shipto_zip,
+    cohist_commission AS commission,
+    cohist_commissionpaid AS commission_paid,
+    cohist_unitcost AS unit_cost,
+    CASE
+      WHEN cohist_misc_type IS NULL THEN
+        ''
+      WHEN cohist_misc_type = 'M' THEN
+        'Misc. Charge'
+      WHEN cohist_misc_type = 'F' THEN
+        'Freight'
+      ELSE
+        'Unknown'
+     END AS misc_type,
+    cohist_misc_descrip AS misc_description,
+    CASE
+      WHEN cohist_misc_id IS NULL THEN
+        ''
+      WHEN cohist_misc_type = 'M' THEN
+        formatglaccount(cohist_misc_id)
+      ELSE
+        'Unknown'
+    END AS misc_info,
+    taxzone_code AS tax_zone,
+    taxtype_name AS tax_type,
+    CASE
+      WHEN cohist_doctype = 'I' THEN
+        'Invoice'
+      WHEN cohist_doctype = 'C' THEN
+        'Credit Memo'
+      ELSE
+        'Unknown'
+    END AS document_type,
+    curr_abbr AS currency,
+    cohist_sequence AS gl_sequence,
+    (SELECT SUM(taxhist_tax)
+     FROM cohisttax
+     WHERE (taxhist_parent_id=cohist_id)) AS tax
+  FROM cohist
+    LEFT OUTER JOIN custinfo ON (cohist_cust_id=cust_id)
+    LEFT OUTER JOIN shiptoinfo ON (cohist_shipto_id=shipto_id)
+    LEFT OUTER JOIN taxzone ON (cohist_taxzone_id=taxzone_id)
+    LEFT OUTER JOIN taxtype ON (cohist_taxtype_id=taxtype_id)
+    LEFT OUTER JOIN salesrep ON (cohist_salesrep_id=salesrep_id)
+    LEFT OUTER JOIN itemsite ON (cohist_itemsite_id=itemsite_id)
+    LEFT OUTER JOIN item ON (itemsite_item_id=item_id)
+    LEFT OUTER JOIN whsinfo ON (itemsite_warehous_id=warehous_id)
+    LEFT OUTER JOIN curr_symbol ON (cohist_curr_id=curr_id);
+
+GRANT ALL ON TABLE api.saleshistory TO xtrole;
+COMMENT ON VIEW api.saleshistory IS 'Sales History';
+
+  --Rules
+
+  CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.saleshistory DO INSTEAD
+
+  INSERT INTO cohist (
+    cohist_cust_id,
+    cohist_itemsite_id,
+    cohist_shipdate,
+    cohist_shipvia,
+    cohist_ordernumber,
+    cohist_orderdate,
+    cohist_invcnumber,
+    cohist_invcdate,
+    cohist_qtyshipped,
+    cohist_unitprice,
+    cohist_shipto_id,
+    cohist_salesrep_id,
+    cohist_duedate,
+    cohist_imported,
+    cohist_billtoname,
+    cohist_billtoaddress1,
+    cohist_billtoaddress2,
+    cohist_billtoaddress3,
+    cohist_billtocity,
+    cohist_billtostate,
+    cohist_billtozip,
+    cohist_shiptoname,
+    cohist_shiptoaddress1,
+    cohist_shiptoaddress2,
+    cohist_shiptoaddress3,
+    cohist_shiptocity,
+    cohist_shiptostate,
+    cohist_shiptozip,
+    cohist_commission,
+    cohist_commissionpaid,
+    cohist_unitcost,
+    cohist_misc_type,
+    cohist_misc_descrip,
+    cohist_misc_id,
+    cohist_doctype,
+    cohist_promisedate,
+    cohist_ponumber,
+    cohist_curr_id,
+    cohist_sequence,
+    cohist_taxzone_id,
+    cohist_taxtype_id )
+  VALUES (
+    getCustId(NEW.customer_number),
+    getItemsiteId(NEW.site_code,NEW.item_number),
+    NEW.ship_date,
+    NEW.ship_via,
+    NEW.order_number,
+    NEW.order_date,
+    NEW.invoice_number,
+    NEW.invoice_date,
+    NEW.quantity_shipped,
+    COALESCE(NEW.unit_price,0),
+    getShiptoId(NEW.customer_number,NEW.shipto_number),
+    getSalesRepId(NEW.sales_rep),
+    NEW.due_date,
+    TRUE,
+    NEW.billto_name,
+    NEW.billto_address1,
+    NEW.billto_address2,
+    NEW.billto_address3,
+    NEW.billto_city,
+    NEW.billto_state,
+    NEW.billto_zip,
+    NEW.shipto_name,
+    NEW.shipto_address1,
+    NEW.shipto_address2,
+    NEW.shipto_address3,
+    NEW.shipto_city,
+    NEW.shipto_state,
+    NEW.shipto_zip,
+    COALESCE(NEW.commission,0),
+    COALESCE(NEW.commission_paid,false),
+    COALESCE(NEW.unit_cost,0),
+    CASE
+      WHEN NEW.misc_type = 'Misc. Charge' THEN
+        'M'
+      WHEN NEW.misc_type = 'Freight' THEN
+        'F'
+    END,
+    NEW.misc_description,
+    CASE
+      WHEN NEW.misc_type = 'Misc. Charge' THEN
+        getGlAccntId(NEW.misc_info)
+    END,
+    CASE
+      WHEN NEW.document_type = 'Invoice' THEN
+        'I'
+      WHEN NEW.document_type = 'Credit Memo' THEN
+        'C'
+    END,
+    NEW.promise_date,
+    NEW.purchase_order_number,
+    COALESCE(getCurrId(NEW.currency),basecurrid()),
+    NEW.gl_sequence,
+    getTaxzoneId(NEW.tax_zone),
+    getTaxtypeId(NEW.tax_type) );
+  CREATE OR REPLACE RULE "_UPDATE" AS
+  ON UPDATE TO api.saleshistory DO INSTEAD
+
+  NOTHING;
+
+  CREATE OR REPLACE RULE "_DELETE" AS
+  ON DELETE TO api.saleshistory DO INSTEAD
+
+  NOTHING;
diff --git a/foundation-database/api/views/salesline.sql b/foundation-database/api/views/salesline.sql
new file mode 100644 (file)
index 0000000..d36e571
--- /dev/null
@@ -0,0 +1,119 @@
+-- Sales Order Line
+CREATE OR REPLACE VIEW api.salesline
+AS 
+  SELECT 
+     cohead_number::VARCHAR AS order_number,
+     formatsolinenumber(coitem_id)::VARCHAR AS line_number,
+     l.item_number AS item_number,
+     coitem_custpn AS customer_pn,
+     s.item_number AS substitute_for,
+     warehous_code AS sold_from_site,
+     coitem_status AS status,
+     coitem_qtyord AS qty_ordered,
+     q.uom_name AS qty_uom,
+     coitem_price AS net_unit_price,
+     p.uom_name AS price_uom,
+     coitem_scheddate AS scheduled_date,
+     coitem_promdate AS promise_date,
+     coitem_warranty AS warranty,
+     COALESCE((
+       SELECT taxtype_name
+       FROM taxtype
+       WHERE (taxtype_id=getItemTaxType(l.item_id, cohead_taxzone_id))),'None') AS tax_type,
+     CASE
+       WHEN coitem_price = 0 THEN
+         '100'
+       WHEN coitem_custprice = 0 THEN
+         'N/A'
+       ELSE
+         CAST(ROUND(((1 - coitem_price / coitem_custprice) * 100),4) AS text)
+     END AS discount_pct_from_list,
+     CASE
+       WHEN (coitem_order_id = -1) THEN
+         false
+       ELSE
+         true
+     END AS create_order,
+     CASE
+       WHEN (coitem_order_id = -1) THEN
+         ''
+       ELSE
+         (pohead_number || '-' || poitem_linenumber)
+     END AS create_po,
+     coitem_prcost AS overwrite_po_price,
+     coitem_memo AS notes,
+     CASE WHEN (coitem_cos_accnt_id IS NOT NULL) THEN formatglaccount(coitem_cos_accnt_id) 
+          ELSE NULL::text
+     END AS alternate_cos_account,
+     CASE WHEN (coitem_rev_accnt_id IS NOT NULL) THEN formatglaccount(coitem_rev_accnt_id)
+          ELSE NULL::text
+     END AS alternate_rev_account
+  FROM cohead, coitem
+    LEFT OUTER JOIN itemsite isb ON (coitem_substitute_item_id=isb.itemsite_id)
+    LEFT OUTER JOIN item s ON (isb.itemsite_item_id=s.item_id)
+    LEFT OUTER JOIN (poitem JOIN pohead ON (poitem_pohead_id=pohead_id))
+      ON (poitem_id=coitem_order_id),
+  itemsite il, item l, whsinfo, uom q, uom p
+  WHERE ((cohead_id=coitem_cohead_id)
+  AND (coitem_itemsite_id=il.itemsite_id)
+  AND (il.itemsite_item_id=l.item_id)
+  AND (il.itemsite_warehous_id=warehous_id)
+  AND (coitem_qty_uom_id=q.uom_id)
+  AND (coitem_price_uom_id=p.uom_id))
+ORDER BY cohead_number,coitem_linenumber,coitem_subnumber;
+    
+GRANT ALL ON TABLE api.salesline TO xtrole;
+COMMENT ON VIEW api.salesline IS 'Sales Order Line Item';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.salesline DO INSTEAD  SELECT insertsalesline(new.*) AS insertsalesline;
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.salesline DO INSTEAD
+
+  UPDATE coitem SET
+    coitem_status=NEW.status,
+    coitem_scheddate=NEW.scheduled_date,
+    coitem_promdate=NEW.promise_date,
+    coitem_qtyord=NEW.qty_ordered,
+    coitem_qty_uom_id=getUomId(NEW.qty_uom),
+    coitem_qty_invuomratio=itemuomtouomratio(item_id,getUomId(NEW.qty_uom),item_inv_uom_id),
+    coitem_price=NEW.net_unit_price,
+    coitem_price_uom_id=getUomId(NEW.price_uom),
+    coitem_price_invuomratio=itemuomtouomratio(item_id,getUomId(NEW.price_uom),item_price_uom_id),
+    coitem_memo=NEW.notes,
+    coitem_order_type=
+    CASE
+      WHEN (NOT OLD.create_order AND NEW.create_order  AND (item_type = 'M')) THEN
+        'W'
+      WHEN (NOT OLD.create_order AND NEW.create_order AND (item_type = 'P') AND (itemsite_createsopo)) THEN
+        'P' 
+      WHEN (NOT OLD.create_order AND NEW.create_order AND (item_type = 'P')) THEN
+        'R'     
+    END,
+    coitem_substitute_item_id = getitemid(NEW.substitute_for),
+    coitem_prcost=NEW.overwrite_po_price,
+    coitem_taxtype_id=
+    CASE
+      WHEN (NEW.tax_type='None') THEN
+        NULL
+      ELSE getTaxTypeId(NEW.tax_type)
+    END,
+    coitem_warranty=NEW.warranty,
+    coitem_cos_accnt_id=getGlAccntId(NEW.alternate_cos_account),
+    coitem_rev_accnt_id=getGlAccntId(NEW.alternate_rev_account)
+   FROM item JOIN itemsite ON (item_id=itemsite_item_id)
+   WHERE ((item_number=OLD.item_number)
+   AND (coitem_cohead_id=getCoheadId(OLD.order_number))
+   AND (coitem_id=getCoitemId(OLD.order_number,OLD.line_number))
+   AND (coitem_subnumber=0));
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.salesline DO INSTEAD
+
+  DELETE FROM coitem
+  WHERE ((coitem_cohead_id=getCoheadId(OLD.order_number))
+  AND (coitem_linenumber::varchar=OLD.line_number)
+  AND (coitem_subnumber=0));
diff --git a/foundation-database/api/views/saleslinechar.sql b/foundation-database/api/views/saleslinechar.sql
new file mode 100644 (file)
index 0000000..524e606
--- /dev/null
@@ -0,0 +1,86 @@
+-- Sales Order Line Characteristics
+SELECT dropIfExists('VIEW', 'saleslinechar', 'api');
+CREATE VIEW api.saleslinechar
+AS 
+SELECT 
+  order_number::VARCHAR,
+  line_number,
+  characteristic,
+  COALESCE(si.charass_value,i3.charass_value) AS value,
+  COALESCE(si.charass_price,itemcharprice(data.item_id,char_id,COALESCE(si.charass_value,i3.charass_value),cohead_cust_id,cohead_shipto_id,coitem_qtyord,cohead_curr_id,cohead_orderdate),0)::numeric(16,4) AS price
+FROM
+  (SELECT DISTINCT 
+    cohead_cust_id,
+    cohead_shipto_id,
+    cohead_curr_id,
+    cohead_orderdate,
+    coitem_id,
+    coitem_itemsite_id,
+    coitem_qtyord,
+    char_id,
+    item_id,
+    cohead_number AS order_number, 
+    CASE 
+      WHEN (coitem_subnumber=0) THEN
+        coitem_linenumber::VARCHAR
+      ELSE 
+        coitem_linenumber::VARCHAR || '.'::VARCHAR || coitem_subnumber::VARCHAR
+    END AS line_number,
+    char_name AS characteristic
+   FROM cohead, coitem, itemsite, item, charass, char
+   WHERE ( (cohead_id=coitem_cohead_id)
+   AND (coitem_itemsite_id=itemsite_id)
+   AND (itemsite_item_id=item_id)
+   AND (charass_char_id=char_id)
+   AND (charass_target_type='I')
+   AND (charass_target_id=item_id) ) ) AS data
+  LEFT OUTER JOIN charass  si ON ((coitem_id=si.charass_target_id)
+                              AND ('SI'=si.charass_target_type)
+                              AND (si.charass_char_id=char_id))
+  LEFT OUTER JOIN itemsite i1 ON (coitem_itemsite_id=i1.itemsite_id)
+  LEFT OUTER JOIN item     i2 ON (i1.itemsite_item_id=i2.item_id)
+  LEFT OUTER JOIN charass  i3 ON ((i2.item_id=i3.charass_target_id)
+                              AND ('I'=i3.charass_target_type)
+                              AND (i3.charass_char_id=char_id)
+                              AND (i3.charass_default))
+ORDER BY order_number,line_number, characteristic;
+
+GRANT ALL ON TABLE api.saleslinechar TO xtrole;
+COMMENT ON VIEW api.saleslinechar IS 'Sales Order Line Item Characteristic';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.saleslinechar DO INSTEAD
+
+SELECT DISTINCT updateCharAssignment('SI', coitem_id, charass_char_id, NEW.value, 
+itemcharprice(item_id,char_id,NEW.value,cohead_cust_id,cohead_shipto_id,coitem_qtyord,cohead_curr_id,cohead_orderdate))
+FROM cohead, coitem, itemsite, item, charass, char
+WHERE ((cohead_number=NEW.order_number)
+AND (cohead_id=coitem_cohead_id)
+AND (coitem_id=getCoitemId(NEW.order_number,NEW.line_number))
+AND (coitem_itemsite_id=itemsite_id)
+AND (item_id=itemsite_item_id)
+AND (charass_target_type='I')
+AND (charass_target_id=item_id)
+AND (char_id=charass_char_id)
+AND (char_name=NEW.characteristic));
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.saleslinechar DO INSTEAD
+
+SELECT DISTINCT updateCharAssignment('SI', coitem_id, charass_char_id, NEW.value, 
+itemcharprice(item_id,char_id,NEW.value,cohead_cust_id,cohead_shipto_id,coitem_qtyord,cohead_curr_id,cohead_orderdate))
+FROM cohead, coitem, itemsite, item, charass, char
+WHERE ((cohead_number=OLD.order_number)
+AND (cohead_id=coitem_cohead_id)
+AND (coitem_id=getCoitemId(OLD.order_number,OLD.line_number))
+AND (coitem_itemsite_id=itemsite_id)
+AND (item_id=itemsite_item_id)
+AND (charass_target_type='I')
+AND (charass_target_id=item_id)
+AND (char_id=charass_char_id)
+AND (char_name=OLD.characteristic));
+
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.saleslinechar DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/saleslinecomment.sql b/foundation-database/api/views/saleslinecomment.sql
new file mode 100644 (file)
index 0000000..9231944
--- /dev/null
@@ -0,0 +1,52 @@
+-- Sales Order Line Item Comment
+SELECT dropIfExists('VIEW', 'saleslinecomment', 'api');
+CREATE VIEW api.saleslinecomment
+AS 
+   SELECT 
+     cohead_number::VARCHAR AS order_number,
+     CASE 
+       WHEN (coitem_subnumber=0) THEN
+         coitem_linenumber::VARCHAR
+       ELSE 
+         coitem_linenumber::VARCHAR || '.'::VARCHAR || coitem_subnumber::VARCHAR
+     END AS line_number,
+     cmnttype_name AS type,
+     comment_date AS date,
+     comment_user AS username,
+     comment_text AS text
+   FROM cohead, coitem, cmnttype, comment
+   WHERE ((cohead_id=coitem_cohead_id)
+   AND (comment_source='SI')
+   AND (comment_source_id=coitem_id)
+   AND (comment_cmnttype_id=cmnttype_id))
+   ORDER BY cohead_number ASC, coitem_linenumber ASC, comment_date DESC;
+
+GRANT ALL ON TABLE api.saleslinecomment TO xtrole;
+COMMENT ON VIEW api.saleslinecomment IS 'Sales Order Line Item Comment';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.saleslinecomment DO INSTEAD
+
+  INSERT INTO comment (
+    comment_date,
+    comment_source,
+    comment_source_id,
+    comment_user,
+    comment_cmnttype_id,
+    comment_text
+    )
+  VALUES (
+    COALESCE(NEW.date,current_date),
+    'SI',
+    getCoitemId(NEW.order_number,NEW.line_number),
+    COALESCE(NEW.username,getEffectiveXtUser()),
+    getCmntTypeId(NEW.type),
+    NEW.text);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.saleslinecomment DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.saleslinecomment DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/salesorder.sql b/foundation-database/api/views/salesorder.sql
new file mode 100644 (file)
index 0000000..d300a9b
--- /dev/null
@@ -0,0 +1,369 @@
+-- SalesOrder
+SELECT dropIfExists('VIEW', 'salesorder', 'api');
+
+CREATE VIEW api.salesorder
+AS
+   SELECT 
+     cohead_number::varchar AS order_number,
+     warehous_code AS site,
+     cohead_orderdate AS order_date,
+     cohead_packdate AS pack_date,
+     saletype_code AS sale_type,
+     salesrep_number AS sales_rep,
+     cohead_commission AS commission,
+     COALESCE(taxzone_code,'None') AS tax_zone,
+     terms_code AS terms,
+     prj_number AS project_number,
+     cust_number AS customer_number,
+     bc.cntct_number AS billto_contact_number,
+     cohead_billto_cntct_honorific AS billto_contact_name,
+     cohead_billto_cntct_first_name AS billto_contact_first,
+     cohead_billto_cntct_middle AS billto_contact_middle,
+     cohead_billto_cntct_last_name AS billto_contact_last,
+     cohead_billto_cntct_suffix AS billto_contact_suffix,
+     cohead_billto_cntct_phone AS billto_contact_phone,
+     cohead_billto_cntct_title AS billto_contact_title,
+     cohead_billto_cntct_fax AS billto_contct_fax,
+     cohead_billto_cntct_email AS billto_contact_email,
+     cohead_billtoname AS billto_name,
+     cohead_billtoaddress1 AS billto_address1,
+     cohead_billtoaddress2 AS billto_address2,
+     cohead_billtoaddress3 AS billto_address3,
+     cohead_billtocity AS billto_city,
+     cohead_billtostate AS billto_state,
+     cohead_billtozipcode AS billto_postal_code,
+     cohead_billtocountry AS billto_country,
+     shipto_num AS shipto_number,
+     sc.cntct_number AS shipto_contact_number,
+     cohead_shipto_cntct_honorific AS shipto_contact_honorific,
+     cohead_shipto_cntct_first_name AS shipto_contact_first,
+     cohead_shipto_cntct_middle AS shipto_contact_middle,
+     cohead_shipto_cntct_last_name AS shipto_contact_last,
+     cohead_shipto_cntct_suffix AS shipto_contact_suffix,
+     cohead_shipto_cntct_phone AS shipto_contact_phone,
+     cohead_shipto_cntct_title AS shipto_contact_title,
+     cohead_shipto_cntct_fax AS shipto_contact_fax,
+     cohead_shipto_cntct_email AS shipto_contact_email,
+     cohead_shiptoname AS shipto_name,
+     cohead_shiptophone AS shipto_phone,
+     cohead_shiptoaddress1 AS shipto_address1,
+     cohead_shiptoaddress2 AS shipto_address2,
+     cohead_shiptoaddress3 AS shipto_address3,
+     cohead_shiptocity AS shipto_city,
+     cohead_shiptostate AS shipto_state,
+     cohead_shiptozipcode AS shipto_postal_code,
+     cohead_shiptocountry AS shipto_country,
+     shipzone_name AS shipto_shipzone,
+     cohead_custponumber AS cust_po_number,
+     cohead_fob AS fob,
+     cohead_shipvia AS ship_via,
+     CASE
+       WHEN cohead_holdtype = 'N' THEN
+         'None'
+       WHEN cohead_holdtype = 'C' THEN
+         'Credit'
+       WHEN cohead_holdtype = 'S' THEN
+         'Shipping'
+       WHEN cohead_holdtype = 'P' THEN
+         'Packing'
+       WHEN cohead_holdtype = 'R' THEN
+         'Return'
+       ELSE
+         'Error'
+     END AS hold_type,
+     shipchrg_name AS shipping_chgs,
+     shipform_name AS shipping_form,
+     cohead_shipcomplete AS ship_complete,
+     curr_abbr AS currency,
+     cohead_misc_descrip AS misc_charge_description,
+     CASE
+       WHEN (cohead_misc_accnt_id IS NULL) THEN
+         NULL
+       ELSE
+         formatglaccount(cohead_misc_accnt_id) 
+     END AS misc_account_number,
+     cohead_misc AS misc_charge,
+     cohead_freight AS freight,
+     cohead_calcfreight AS calculate_freight,
+     cohead_ordercomments AS order_notes,
+     cohead_shipcomments AS shipping_notes,
+     false AS add_to_packing_list_batch
+   FROM cohead
+     LEFT OUTER JOIN cntct bc ON (cohead_billto_cntct_id=bc.cntct_id)
+     LEFT OUTER JOIN cntct sc ON (cohead_shipto_cntct_id=sc.cntct_id)
+     LEFT OUTER JOIN whsinfo ON (cohead_warehous_id=warehous_id)
+     LEFT OUTER JOIN prj ON (cohead_prj_id=prj_id)
+     LEFT OUTER JOIN shiptoinfo ON (cohead_shipto_id=shipto_id)
+     LEFT OUTER JOIN shipchrg ON (cohead_shipchrg_id=shipchrg_id)
+     LEFT OUTER JOIN taxzone ON (cohead_taxzone_id=taxzone_id)
+     LEFT OUTER JOIN saletype ON (cohead_saletype_id=saletype_id)
+     LEFT OUTER JOIN shipzone ON (cohead_shipzone_id=shipzone_id),
+     custinfo,shipform,salesrep,terms,curr_symbol
+   WHERE ((cohead_cust_id=cust_id)
+   AND (cohead_shipform_id=shipform_id)
+   AND (cohead_salesrep_id=salesrep_id)
+   AND (cohead_terms_id=terms_id)
+   AND (cohead_curr_id=curr_id));
+
+GRANT ALL ON TABLE api.salesorder TO xtrole;
+COMMENT ON VIEW api.salesorder IS 'Sales Order';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.salesorder DO INSTEAD
+
+  INSERT INTO cohead (
+    cohead_number,
+    cohead_cust_id,
+    cohead_custponumber,
+    cohead_orderdate,
+    cohead_warehous_id,
+    cohead_shipto_id,
+    cohead_shiptoname,
+    cohead_shiptoaddress1,
+    cohead_shiptoaddress2,
+    cohead_shiptoaddress3,
+    cohead_salesrep_id,
+    cohead_terms_id,
+    cohead_fob,
+    cohead_shipvia,
+    cohead_shiptocity,
+    cohead_shiptostate,
+    cohead_shiptozipcode,
+    cohead_freight,
+    cohead_calcfreight,
+    cohead_misc,
+    cohead_imported,
+    cohead_ordercomments,
+    cohead_shipcomments,
+    cohead_shiptophone,
+    cohead_shipchrg_id,
+    cohead_shipform_id,
+    cohead_billtoname,
+    cohead_billtoaddress1,
+    cohead_billtoaddress2,
+    cohead_billtoaddress3,
+    cohead_billtocity,
+    cohead_billtostate,
+    cohead_billtozipcode,
+    cohead_misc_accnt_id,
+    cohead_misc_descrip,
+    cohead_commission,
+    cohead_holdtype,
+    cohead_packdate,
+    cohead_prj_id,
+    cohead_shipcomplete,
+    cohead_billtocountry,
+    cohead_shiptocountry,
+    cohead_curr_id,
+    cohead_taxzone_id,
+    cohead_shipto_cntct_id,
+    cohead_shipto_cntct_honorific,
+    cohead_shipto_cntct_first_name,
+    cohead_shipto_cntct_middle,
+    cohead_shipto_cntct_last_name,
+    cohead_shipto_cntct_suffix,
+    cohead_shipto_cntct_phone,
+    cohead_shipto_cntct_title,
+    cohead_shipto_cntct_fax,
+    cohead_shipto_cntct_email,
+    cohead_billto_cntct_id,
+    cohead_billto_cntct_honorific,
+    cohead_billto_cntct_first_name,
+    cohead_billto_cntct_middle,
+    cohead_billto_cntct_last_name,
+    cohead_billto_cntct_suffix,
+    cohead_billto_cntct_phone,
+    cohead_billto_cntct_title,
+    cohead_billto_cntct_fax,
+    cohead_billto_cntct_email,
+    cohead_saletype_id,
+    cohead_shipzone_id
+    )
+  SELECT
+    NEW.order_number,
+    getCustId(NEW.customer_number),
+    NEW.cust_po_number,
+    NEW.order_date,
+    getWarehousId(NEW.site,'SHIPPING'),
+    getShiptoId(NEW.customer_number,NEW.shipto_number),
+    NEW.shipto_name,
+    NEW.shipto_address1,
+    NEW.shipto_address2,
+    NEW.shipto_address3,
+    getSalesRepId(NEW.sales_rep),
+    getTermsId(NEW.terms),
+    NEW.fob,
+    NEW.ship_via,
+    NEW.shipto_city,
+    NEW.shipto_state,
+    NEW.shipto_postal_code,
+    CASE WHEN (COALESCE(NEW.calculate_freight, fetchMetricBool('CalculateFreight'))) THEN 0
+         ELSE
+           NEW.freight
+    END,
+    COALESCE(NEW.calculate_freight, fetchMetricBool('CalculateFreight')),
+    NEW.misc_charge,
+    true,
+    NEW.order_notes,
+    NEW.shipping_notes,
+    NEW.shipto_phone,
+    getShipChrgId(NEW.shipping_chgs),
+    getShipFormId(NEW.shipping_form),
+    NEW.billto_name,
+    NEW.billto_address1,
+    NEW.billto_address2,
+    NEW.billto_address3,
+    NEW.billto_city,
+    NEW.billto_state,
+    NEW.billto_postal_code,
+    getGlAccntId(NEW.misc_account_number),
+    NEW.misc_charge_description,
+    NEW.commission,
+    CASE
+      WHEN NEW.hold_type = 'Credit' THEN
+        'C'
+      WHEN NEW.hold_type = 'Shipping' THEN
+        'S'
+      WHEN NEW.hold_type = 'Packing' THEN
+        'P'
+      ELSE
+        'N'
+    END,
+    NEW.pack_date,
+    getPrjId(NEW.project_number),
+    NEW.ship_complete,
+    NEW.billto_country,
+    NEW.shipto_country,
+    getCurrId(NEW.currency),
+    CASE 
+      WHEN NEW.tax_zone = 'None' THEN
+        -1
+      ELSE 
+        getTaxZoneId(NEW.tax_zone)
+    END,
+    getCntctId(NEW.shipto_contact_number),
+    NEW.shipto_contact_honorific,
+    NEW.shipto_contact_first,
+    NEW.shipto_contact_middle,
+    NEW.shipto_contact_last,
+    NEW.shipto_contact_suffix,
+    NEW.shipto_contact_phone,
+    NEW.shipto_contact_title,
+    NEW.shipto_contact_fax,
+    NEW.shipto_contact_email,
+    getCntctId(NEW.billto_contact_number),
+    NEW.billto_contact_name,
+    NEW.billto_contact_first,
+    NEW.billto_contact_middle,
+    NEW.billto_contact_last,
+    NEW.billto_contact_suffix,
+    NEW.billto_contact_phone,
+    NEW.billto_contact_title,
+    NEW.billto_contct_fax,
+    NEW.billto_contact_email,
+    getSaleTypeId(NEW.sale_type),
+    getShipZoneId(NEW.shipto_shipzone)
+   FROM custinfo
+   WHERE (cust_number=NEW.customer_number);
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.salesorder DO INSTEAD
+
+  UPDATE cohead SET
+    cohead_number=OLD.order_number,
+    cohead_cust_id=getCustId(NEW.customer_number),
+    cohead_custponumber=NEW.cust_po_number,
+    cohead_orderdate=NEW.order_date,
+    cohead_warehous_id=getWarehousId(NEW.site,'SHIPPING'),
+    cohead_shipto_id=getShiptoId(NEW.customer_number,NEW.shipto_number),
+    cohead_shiptoname=NEW.shipto_name,
+    cohead_shiptoaddress1=NEW.shipto_address1,
+    cohead_shiptoaddress2=NEW.shipto_address2,
+    cohead_shiptoaddress3=NEW.shipto_address3,
+    cohead_salesrep_id=getSalesRepId(NEW.sales_rep),
+    cohead_terms_id=getTermsId(NEW.terms),
+    cohead_fob=NEW.fob,
+    cohead_shipvia=NEW.ship_via,
+    cohead_shiptocity=NEW.shipto_city,
+    cohead_shiptostate=NEW.shipto_state,
+    cohead_shiptozipcode=NEW.shipto_postal_code,
+    cohead_freight=
+    CASE WHEN (NEW.calculate_freight) THEN
+           COALESCE((SELECT SUM(freightdata_total) FROM freightDetail('SO',
+                                                             getCoheadid(OLD.order_number),
+                                                             getCustId(NEW.customer_number),
+                                                             getShiptoId(NEW.customer_number,NEW.shipto_number),
+                                                             NEW.order_date,
+                                                             NEW.ship_via,
+                                                             getCurrId(NEW.currency))),0)
+         ELSE
+           NEW.freight
+    END,
+    cohead_calcfreight=NEW.calculate_freight,
+    cohead_misc=NEW.misc_charge,
+    cohead_ordercomments=NEW.order_notes,
+    cohead_shipcomments=NEW.shipping_notes,
+    cohead_shiptophone=NEW.shipto_phone,
+    cohead_shipchrg_id=getShipChrgId(NEW.shipping_chgs),
+    cohead_shipform_id=getShipFormId(NEW.shipping_form),
+    cohead_billtoname=NEW.billto_name,
+    cohead_billtoaddress1=NEW.billto_address1,
+    cohead_billtoaddress2=NEW.billto_address2,
+    cohead_billtoaddress3=NEW.billto_address3,
+    cohead_billtocity=NEW.billto_city,
+    cohead_billtostate=NEW.billto_state,
+    cohead_billtozipcode=NEW.billto_postal_code,
+    cohead_misc_accnt_id=getGlAccntId(NEW.misc_account_number),
+    cohead_misc_descrip=NEW.misc_charge_description,
+    cohead_commission=NEW.commission,
+    cohead_holdtype=
+    CASE
+      WHEN NEW.hold_type = 'Credit' THEN
+        'C'
+      WHEN NEW.hold_type = 'Shipping' THEN
+        'S'
+      WHEN NEW.hold_type = 'Packing' THEN
+        'P'
+      ELSE
+        'N'
+    END,
+    cohead_packdate=NEW.pack_date,
+    cohead_prj_id=getPrjId(NEW.project_number),
+    cohead_shipcomplete=NEW.ship_complete,
+    cohead_billtocountry=NEW.billto_country,
+    cohead_shiptocountry=NEW.shipto_country,
+    cohead_curr_id=getCurrId(NEW.currency),
+    cohead_taxzone_id=getTaxZoneId(NEW.tax_zone),
+    cohead_lastupdated=('now'::text)::timestamp(6) with time zone,
+    cohead_shipto_cntct_id = getCntctId(NEW.shipto_contact_number),
+    cohead_shipto_cntct_honorific = NEW.shipto_contact_honorific,
+    cohead_shipto_cntct_first_name = NEW.shipto_contact_first,
+    cohead_shipto_cntct_middle = NEW.shipto_contact_middle,
+    cohead_shipto_cntct_last_name = NEW.shipto_contact_last,
+    cohead_shipto_cntct_suffix = NEW.shipto_contact_suffix,
+    cohead_shipto_cntct_phone = NEW.shipto_contact_phone,
+    cohead_shipto_cntct_title = NEW.shipto_contact_title,
+    cohead_shipto_cntct_fax = NEW.shipto_contact_fax,
+    cohead_shipto_cntct_email = NEW.shipto_contact_email,
+    cohead_billto_cntct_id = getCntctId(NEW.billto_contact_number),
+    cohead_billto_cntct_honorific = NEW.billto_contact_name,
+    cohead_billto_cntct_first_name = NEW.billto_contact_first,
+    cohead_billto_cntct_middle = NEW.billto_contact_middle,
+    cohead_billto_cntct_last_name = NEW.billto_contact_last,
+    cohead_billto_cntct_suffix = NEW.billto_contact_suffix,
+    cohead_billto_cntct_phone = NEW.billto_contact_phone,
+    cohead_billto_cntct_title = NEW.billto_contact_title,
+    cohead_billto_cntct_fax = NEW.billto_contct_fax,
+    cohead_billto_cntct_email = NEW.billto_contact_email,
+    cohead_saletype_id=getSaleTypeId(NEW.sale_type),
+    cohead_shipzone_id=getShipZoneId(NEW.shipto_shipzone)
+  WHERE (cohead_number=OLD.order_number);
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.salesorder DO INSTEAD
+
+  SELECT deleteso(cohead_id,OLD.order_number)
+  FROM cohead
+  WHERE (cohead_number=OLD.order_number);
diff --git a/foundation-database/api/views/salesordercomment.sql b/foundation-database/api/views/salesordercomment.sql
new file mode 100644 (file)
index 0000000..a03ab35
--- /dev/null
@@ -0,0 +1,44 @@
+-- Sales Order Comment
+SELECT dropIfExists('VIEW', 'salesordercomment', 'api');
+CREATE VIEW api.salesordercomment
+AS 
+   SELECT 
+     cohead_number::VARCHAR AS order_number,
+     cmnttype_name AS type,
+     comment_date AS date,
+     comment_user AS username,
+     comment_text AS text
+   FROM cohead, cmnttype, comment
+   WHERE ((comment_source='S')
+   AND (comment_source_id=cohead_id)
+   AND (comment_cmnttype_id=cmnttype_id));
+
+GRANT ALL ON TABLE api.salesordercomment TO xtrole;
+COMMENT ON VIEW api.salesordercomment IS 'Sales Order Comment';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.salesordercomment DO INSTEAD
+
+  INSERT INTO comment (
+    comment_date,
+    comment_source,
+    comment_source_id,
+    comment_user,
+    comment_cmnttype_id,
+    comment_text
+    )
+  VALUES (
+    COALESCE(NEW.date,current_date),
+    'S',
+    getSalesOrderId(NEW.order_number),
+    COALESCE(NEW.username,getEffectiveXtUser()),
+    getCmntTypeId(NEW.type),
+    NEW.text);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.salesordercomment DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.salesordercomment DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/salesrep.sql b/foundation-database/api/views/salesrep.sql
new file mode 100644 (file)
index 0000000..d0772fe
--- /dev/null
@@ -0,0 +1,52 @@
+--Sales Rep View
+
+SELECT dropIfExists('VIEW', 'salesrep', 'api');
+CREATE OR REPLACE VIEW api.salesrep AS
+
+SELECT
+  salesrep_number::VARCHAR AS number,
+  salesrep_active AS active,
+  salesrep_name AS name,
+  salesrep_commission * 100 AS commission_percent,
+  emp_number AS employee
+FROM salesrep LEFT OUTER JOIN emp ON (emp_id=salesrep_emp_id)
+ORDER BY salesrep_number;
+
+GRANT ALL ON TABLE api.salesrep TO xtrole;
+COMMENT ON VIEW api.salesrep IS 'Sales Rep';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+  ON INSERT TO api.salesrep DO INSTEAD
+
+INSERT INTO salesrep (
+  salesrep_active,
+  salesrep_number,
+  salesrep_name,
+  salesrep_commission,
+  salesrep_method,
+  salesrep_emp_id )
+VALUES (
+  COALESCE(NEW.active, true),
+  COALESCE(NEW.number, ''),
+  COALESCE(NEW.name, ''),
+  COALESCE(NEW.commission_percent * .01, 0),
+  '',
+  getEmpId(NEW.employee) );
+CREATE OR REPLACE RULE "_UPDATE" AS
+ON UPDATE TO api.salesrep DO INSTEAD
+
+UPDATE salesrep SET
+  salesrep_active=NEW.active,
+  salesrep_number=NEW.number,
+  salesrep_name=NEW.name,
+  salesrep_commission=(NEW.commission_percent * .01),
+  salesrep_emp_id=getEmpId(NEW.employee)
+  WHERE (salesrep_number=OLD.number);
+
+CREATE OR REPLACE RULE "_DELETE" AS
+ON DELETE TO api.salesrep DO INSTEAD
+
+DELETE FROM salesrep WHERE (salesrep_number=OLD.number);
diff --git a/foundation-database/api/views/site.sql b/foundation-database/api/views/site.sql
new file mode 100644 (file)
index 0000000..7f7b270
--- /dev/null
@@ -0,0 +1,647 @@
+  --Site (aka Warehouse) View
+
+  SELECT dropIfExists('VIEW', 'site', 'api');
+  CREATE OR REPLACE VIEW api.site AS
+  SELECT 
+    warehous_code::VARCHAR AS code,
+    st.sitetype_name AS type,
+    warehous_active AS active,
+    warehous_descrip AS description,
+    m.addr_number AS address_number,
+    m.addr_line1 AS address1,
+    m.addr_line2 AS address2,
+    m.addr_line3 AS address3,
+    m.addr_city AS city,
+    m.addr_state AS state,
+    m.addr_postalcode AS postal_code,
+    m.addr_country AS country,
+    (''::TEXT) AS address_change,
+    c.cntct_number AS contact_number,
+    c.cntct_honorific AS honorific,
+    c.cntct_first_name AS first,
+    c.cntct_middle as middle,
+    c.cntct_last_name AS last,
+    c.cntct_suffix AS suffix,
+    c.cntct_title AS job_title,
+    c.cntct_phone AS phone,
+    c.cntct_fax AS fax,
+    c.cntct_email AS email,
+    (''::TEXT) AS contact_change,
+    formatGLAccount(a.accnt_id) AS post_unassigned_transactions_to,
+    a.accnt_descrip AS post_unassigned_transactions_to_description,
+    warehous_transit AS transit_type,
+    CASE
+      WHEN warehous_transit THEN
+        false
+      ELSE
+        true
+    END AS inventory_type,
+-- Inventory Sites Exclusive
+    CASE
+      WHEN warehous_transit THEN
+        ''
+      ELSE
+        warehous_bol_prefix
+    END AS next_bill_of_lading_prefix,
+    CASE
+      WHEN warehous_transit THEN
+        0
+      ELSE
+        warehous_bol_number
+    END AS next_bill_of_lading_number,
+    CASE
+      WHEN warehous_transit THEN
+        false
+      ELSE warehous_shipping
+    END AS shipping_site,
+    CASE
+      WHEN warehous_transit THEN
+        ''
+      ELSE
+        warehous_counttag_prefix
+    END AS next_count_tag_prefix,
+    CASE
+      WHEN warehous_transit THEN
+        0
+      ELSE
+        warehous_counttag_number
+    END AS next_count_tag_number,
+    CASE
+      WHEN warehous_transit THEN
+        false
+      ELSE warehous_useslips
+    END AS force_the_use_of_count_slips,
+    CASE
+      WHEN warehous_transit THEN
+        false
+      ELSE warehous_usezones
+    END AS force_the_use_of_zones,
+    CASE
+      WHEN warehous_transit THEN
+        0
+      ELSE
+        warehous_sequence
+    END AS scheduling_sequence,
+    CASE
+      WHEN warehous_transit THEN
+        0
+      ELSE
+        (warehous_shipping_commission * 100.0)
+    END AS shipping_commission,
+    CASE
+      WHEN warehous_transit THEN
+        ''
+      ELSE
+        t.taxzone_code
+    END AS tax_zone,
+    CASE
+      WHEN warehous_transit THEN
+        ''
+      ELSE
+        warehous_fob
+    END AS default_fob,
+-- Transit Sites Exclusive
+    CASE
+      WHEN warehous_transit THEN
+        s.shipvia_code
+      ELSE
+        ''
+    END AS default_ship_via,
+    CASE
+      WHEN warehous_transit THEN
+        f.shipform_name
+      ELSE
+        ''
+    END AS default_shipping_form,
+    CASE
+      WHEN warehous_transit THEN
+        cc.costcat_code
+      ELSE
+        ''
+    END AS default_cost_category,
+    CASE
+      WHEN warehous_transit THEN
+        warehous_shipcomments
+      ELSE
+        ''
+    END AS shipping_comments,
+-- Inventory Sites Exclusive
+    CASE
+      WHEN warehous_transit THEN
+        false
+      ELSE warehous_enforcearbl
+    END AS enforce_arbl_naming_convention,
+    CASE
+      WHEN warehous_transit THEN
+        0
+      WHEN warehous_enforcearbl THEN
+        warehous_aislesize
+      ELSE
+        0
+    END AS aisle_size,
+    CASE
+      WHEN warehous_transit THEN
+        false
+      WHEN (warehous_enforcearbl AND warehous_aislealpha) THEN
+        true
+      ELSE
+        false
+    END AS aisle_allow_alpha_characters,
+    CASE
+      WHEN warehous_transit THEN
+        0
+      WHEN warehous_enforcearbl THEN
+        warehous_racksize
+      ELSE
+        0
+    END AS rack_size,
+    CASE
+      WHEN warehous_transit THEN
+        false
+      WHEN (warehous_enforcearbl AND warehous_rackalpha) THEN
+        true
+      ELSE
+        false
+    END AS rack_allow_alpha_characters,
+    CASE
+      WHEN warehous_transit THEN
+        0
+      WHEN warehous_enforcearbl THEN
+        warehous_binsize
+      ELSE
+        0
+    END AS bin_size,
+    CASE
+      WHEN warehous_transit THEN
+        false
+      WHEN (warehous_enforcearbl AND warehous_binalpha) THEN
+        true
+      ELSE
+        false
+    END AS bin_allow_alpha_characters,
+    CASE
+      WHEN warehous_transit THEN
+        0
+      WHEN warehous_enforcearbl THEN
+        warehous_locationsize
+      ELSE
+        0
+    END AS location_size,
+    CASE
+      WHEN warehous_transit THEN
+        false
+      WHEN (warehous_enforcearbl AND warehous_locationalpha) THEN
+        true
+      ELSE
+        false
+    END AS location_allow_alpha_characters
+  FROM
+    whsinfo
+      LEFT OUTER JOIN addr m ON (warehous_addr_id=m.addr_id)
+      LEFT OUTER JOIN cntct c ON (warehous_cntct_id=c.cntct_id)
+      LEFT OUTER JOIN accnt a ON (warehous_default_accnt_id=a.accnt_id)
+      LEFT OUTER JOIN taxzone t ON (warehous_taxzone_id=t.taxzone_id)
+      LEFT OUTER JOIN shipvia s ON (warehous_shipvia_id=s.shipvia_id)
+      LEFT OUTER JOIN shipform f ON (warehous_shipform_id=f.shipform_id)
+      LEFT OUTER JOIN costcat cc ON (warehous_costcat_id=cc.costcat_id)
+      LEFT OUTER JOIN sitetype st ON (warehous_sitetype_id=st.sitetype_id)
+  ORDER BY warehous_code;
+
+GRANT ALL ON TABLE api.site TO xtrole;
+COMMENT ON VIEW api.site IS 'Site';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.site DO INSTEAD
+
+  INSERT INTO whsinfo (
+    warehous_code,
+    warehous_descrip,
+    warehous_fob,
+    warehous_active,
+    warehous_counttag_prefix,
+    warehous_counttag_number,
+    warehous_bol_prefix,
+    warehous_bol_number,
+    warehous_shipping,
+    warehous_useslips,
+    warehous_usezones,
+    warehous_aislesize,
+    warehous_aislealpha,
+    warehous_racksize,
+    warehous_rackalpha,
+    warehous_binsize,
+    warehous_binalpha,
+    warehous_locationsize,
+    warehous_locationalpha,
+    warehous_enforcearbl,
+    warehous_default_accnt_id,
+    warehous_shipping_commission,
+    warehous_cntct_id,
+    warehous_addr_id,
+    warehous_taxzone_id,
+    warehous_transit,
+    warehous_shipform_id,
+    warehous_shipvia_id,
+    warehous_shipcomments,
+    warehous_costcat_id,
+    warehous_sitetype_id,
+    warehous_sequence
+    )
+  VALUES (
+    COALESCE(NEW.code, ''),
+    COALESCE(NEW.description, ''),
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.default_fob, '')
+      ELSE
+        ''
+    END,
+    COALESCE(NEW.active,true),
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.next_count_tag_prefix, '')
+          ELSE
+        ''
+    END,
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.next_count_tag_number, 0)
+      ELSE
+        0
+    END,
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.next_bill_of_lading_prefix, '')
+      ELSE
+        ''
+    END,
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.next_bill_of_lading_number, 0)
+      ELSE
+        0
+    END,
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.shipping_site, false)
+      ELSE
+        false
+    END,
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.force_the_use_of_count_slips, false)
+      ELSE
+        false
+    END,
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.force_the_use_of_zones, false)
+      ELSE
+        false
+    END,
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.aisle_size, 0)
+      ELSE
+        0
+    END,
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.aisle_allow_alpha_characters, false)
+      ELSE
+        false
+    END,
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.rack_size, 0)
+      ELSE
+        0
+    END,
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.rack_allow_alpha_characters, false)
+      ELSE
+        false
+    END,
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.bin_size, 0)
+      ELSE
+        0
+    END,
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.bin_allow_alpha_characters, false)
+      ELSE
+        false
+    END,
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.location_size, 0)
+      ELSE
+        0
+    END,
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.location_allow_alpha_characters, false)
+      ELSE
+        false
+    END,
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.enforce_arbl_naming_convention, false)
+      ELSE
+        false
+    END,
+    COALESCE(getglaccntid(NEW.post_unassigned_transactions_to), -1),
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(NEW.shipping_commission * .01, 0)
+      ELSE
+        0
+    END,
+    saveCntct(
+      getCntctId(NEW.contact_number),
+      NEW.contact_number,
+      NULL,
+      NEW.honorific,
+      NEW.first,
+      NEW.middle,
+      NEW.last,
+      NEW.suffix,
+      NEW.phone,
+      NULL,
+      NEW.fax,
+      NEW.email,
+      NULL,
+      NEW.job_title,
+      NEW.contact_change),
+    saveAddr(
+      getAddrId(NEW.address_number),
+      NEW.address_number,
+      NEW.address1,
+      NEW.address2,
+      NEW.address3,
+      NEW.city,
+      NEW.state,
+      NEW.postal_code,
+      NEW.country,
+      NEW.address_change),
+    CASE
+      WHEN NEW.inventory_type THEN
+        COALESCE(getTaxZoneId(NEW.tax_zone), -1)
+      ELSE
+        NULL
+    END,
+    CASE
+      WHEN NEW.inventory_type THEN
+        false
+      WHEN NEW.transit_type THEN
+        true
+      ELSE
+        false
+    END,
+    CASE
+      WHEN NEW.transit_type THEN
+        COALESCE(getShipFormId(NEW.default_shipping_form), FetchMetricValue('DefaultShipFormId'))
+      ELSE
+        NULL
+    END,
+    CASE
+      WHEN NEW.transit_type THEN
+        COALESCE(getShipViaId(NEW.default_ship_via), FetchMetricValue('DefaultShipViaId'))
+      ELSE
+        NULL
+    END,
+    CASE
+      WHEN NEW.transit_type THEN
+        COALESCE(NEW.shipping_comments, '')
+      ELSE
+        ''
+    END,
+    CASE
+      WHEN NEW.transit_type THEN
+        COALESCE(getCostCatId(NEW.default_cost_category), -1)
+      ELSE
+        NULL
+    END,
+    COALESCE(getSiteTypeId(NEW.type), -1),
+    COALESCE(NEW.scheduling_sequence, 0)
+    );
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.site DO INSTEAD
+
+  UPDATE whsinfo SET
+    warehous_descrip=NEW.description,
+    warehous_fob=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.default_fob
+        ELSE
+          NULL
+      END,
+    warehous_active=NEW.active,
+    warehous_counttag_prefix=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.next_count_tag_prefix
+        ELSE
+          NULL
+        END,
+    warehous_counttag_number=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.next_count_tag_number
+        ELSE
+          NULL
+      END,
+    warehous_bol_prefix=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.next_bill_of_lading_prefix
+        ELSE
+          NULL
+      END,
+    warehous_bol_number=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.next_bill_of_lading_number
+        ELSE
+          NULL
+      END,
+    warehous_shipping=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.shipping_site
+        ELSE
+          NULL
+      END,
+    warehous_useslips=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.force_the_use_of_count_slips
+        ELSE
+          NULL
+      END,
+    warehous_usezones=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.force_the_use_of_zones
+        ELSE
+          NULL
+      END,
+    warehous_aislesize=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.aisle_size
+        ELSE
+          NULL
+      END,
+    warehous_aislealpha=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.aisle_allow_alpha_characters
+        ELSE
+          NULL
+      END,
+    warehous_racksize=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.rack_size
+        ELSE
+          NULL
+      END,
+    warehous_rackalpha=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.rack_allow_alpha_characters
+        ELSE
+          NULL
+      END,
+    warehous_binsize=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.bin_size
+        ELSE
+          NULL
+      END,
+    warehous_binalpha=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.bin_allow_alpha_characters
+        ELSE
+          NULL
+      END,
+    warehous_locationsize=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.location_size
+        ELSE
+          NULL
+      END,
+    warehous_locationalpha=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.location_allow_alpha_characters
+        ELSE
+          NULL
+      END,
+    warehous_enforcearbl=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.enforce_arbl_naming_convention
+        ELSE
+          NULL
+      END,
+    warehous_default_accnt_id=getglaccntid(NEW.post_unassigned_transactions_to),
+    warehous_shipping_commission=
+      CASE
+        WHEN NEW.inventory_type THEN
+          NEW.shipping_commission * .01
+        ELSE
+          NULL
+      END,
+    warehous_cntct_id=
+      saveCntct(
+        getCntctId(NEW.contact_number),
+        NEW.contact_number,
+        NULL,
+        NEW.honorific,
+        NEW.first,
+        NEW.middle,
+        NEW.last,
+        NEW.suffix,
+        NEW.phone,
+        NULL,
+        NEW.fax,
+        NEW.email,
+        NULL,
+        NEW.job_title,
+        NEW.contact_change),
+    warehous_addr_id=
+      saveAddr(
+        getAddrId(NEW.address_number),
+        NEW.address_number,
+        NEW.address1,
+        NEW.address2,
+        NEW.address3,
+        NEW.city,
+        NEW.state,
+        NEW.postal_code,
+        NEW.country,
+        NEW.address_change),
+    warehous_taxzone_id=
+      CASE
+        WHEN NEW.inventory_type THEN
+          getTaxZoneId(NEW.tax_zone)
+        ELSE
+          NULL
+      END,
+    warehous_transit=
+      CASE
+        WHEN NEW.inventory_type THEN
+          false
+        WHEN NEW.transit_type THEN
+          true
+        ELSE
+          NULL
+      END,
+    warehous_shipform_id=
+      CASE
+        WHEN NEW.transit_type THEN
+          getShipFormId(NEW.default_shipping_form)
+        ELSE
+          NULL
+      END,
+    warehous_shipvia_id=
+      CASE
+        WHEN NEW.transit_type THEN
+          getShipViaId(NEW.default_ship_via)
+        ELSE
+          NULL
+      END,
+    warehous_shipcomments=
+      CASE
+        WHEN NEW.transit_type THEN
+          NEW.shipping_comments
+        ELSE
+          NULL
+      END,
+    warehous_costcat_id=
+      CASE
+        WHEN NEW.transit_type THEN
+          getCostCatId(NEW.default_cost_category)
+        ELSE
+          NULL
+      END,
+    warehous_sitetype_id=getSiteTypeId(NEW.type),
+    warehous_sequence=NEW.scheduling_sequence
+
+  WHERE  (warehous_id=getWarehousId(OLD.code, 'ALL'));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.site DO NOTHING;
diff --git a/foundation-database/api/views/sitezone.sql b/foundation-database/api/views/sitezone.sql
new file mode 100644 (file)
index 0000000..21bbd4e
--- /dev/null
@@ -0,0 +1,44 @@
+-- Site Zone (aka Warehouse Zone) View
+
+SELECT dropIfExists('VIEW', 'sitezone', 'api');
+CREATE OR REPLACE VIEW api.sitezone AS
+  SELECT 
+    warehous_code::VARCHAR AS site,
+    whsezone_name::VARCHAR AS name,
+    whsezone_descrip AS description
+    FROM whsezone
+       LEFT OUTER JOIN whsinfo ON (warehous_id=whsezone_warehous_id);
+
+GRANT ALL ON TABLE api.sitezone TO xtrole;
+COMMENT ON VIEW api.sitezone IS 'Site Zone';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.sitezone DO INSTEAD
+
+  INSERT INTO whsezone (
+    whsezone_warehous_id,
+    whsezone_name,
+    whsezone_descrip
+    )
+  VALUES (
+    getWarehousId(NEW.site, 'ACTIVE'),
+    COALESCE(NEW.name,''),
+    COALESCE(NEW.description, '')
+    );
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.sitezone DO INSTEAD
+
+  UPDATE whsezone SET
+    whsezone_descrip=NEW.description
+  WHERE ( (whsezone_warehous_id=getWarehousId(OLD.site, 'ACTIVE')) AND
+          (whsezone_name=OLD.name) );
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.sitezone DO INSTEAD
+
+  DELETE FROM whsezone
+  WHERE ( (whsezone_warehous_id=getWarehousId(OLD.site, 'ACTIVE')) AND
+          (whsezone_name=OLD.name) );
diff --git a/foundation-database/api/views/task.sql b/foundation-database/api/views/task.sql
new file mode 100644 (file)
index 0000000..d34aac6
--- /dev/null
@@ -0,0 +1,116 @@
+-- Task
+SELECT dropIfExists('VIEW', 'task', 'api');
+CREATE VIEW api.task
+AS
+   SELECT 
+     prj_number AS project_number,
+     prjtask_number AS number,
+     CASE 
+       WHEN (prjtask_status = 'P') THEN
+         'Concept'
+       WHEN (prjtask_status = 'O') THEN
+         'In-Process'
+       WHEN (prjtask_status = 'C') THEN
+         'Closed'
+       ELSE
+         'Error'
+     END AS status,
+     prjtask_name AS name,
+     prjtask_descrip AS description,
+     prjtask_owner_username AS owner,
+     prjtask_username AS assigned_to,
+     prjtask_hours_budget AS hours_budgeted,
+     prjtask_hours_actual AS hours_actual,
+     prjtask_exp_budget AS expenses_budgeted,
+     prjtask_exp_actual AS expenses_actual,
+     prjtask_due_date AS due,
+     prjtask_assigned_date AS assigned,
+     prjtask_start_date AS started,
+     prjtask_completed_date AS completed
+   FROM prjtask
+    JOIN prj ON (prj_id=prjtask_prj_id);
+
+GRANT ALL ON TABLE api.task TO xtrole;
+COMMENT ON VIEW api.task IS 'Task';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.task DO INSTEAD
+
+  INSERT INTO prjtask (
+    prjtask_prj_id,
+    prjtask_number,
+    prjtask_name,
+    prjtask_descrip,
+    prjtask_owner_username,
+    prjtask_username,
+    prjtask_hours_budget,
+    prjtask_hours_actual,
+    prjtask_exp_budget,
+    prjtask_exp_actual,
+    prjtask_status,
+    prjtask_due_date,
+    prjtask_assigned_date,
+    prjtask_start_date,
+    prjtask_completed_date
+    )
+  VALUES (
+    getPrjId(NEW.project_number),
+    NEW.number,
+    COALESCE(NEW.name,''),
+    COALESCE(NEW.description,''),
+    COALESCE(NEW.owner,getEffectiveXtUser()),
+    COALESCE(NEW.assigned_to,getEffectiveXtUser()),
+    COALESCE(NEW.hours_budgeted,0),
+    COALESCE(NEW.hours_actual,0),
+    COALESCE(NEW.expenses_budgeted,0),
+    COALESCE(NEW.expenses_actual,0),
+    CASE 
+      WHEN (NEW.status='In-Process') THEN
+        'O'
+      WHEN (NEW.status='Completed') THEN
+        'C'
+      ELSE
+        'P'
+    END,
+    NEW.due,
+    NEW.assigned,
+    NEW.started,
+    NEW.completed
+    );
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.task DO INSTEAD
+
+  UPDATE prjtask SET
+    prjtask_name=NEW.name,
+    prjtask_descrip=NEW.description,
+    prjtask_owner_username=NEW.owner,
+    prjtask_username=NEW.assigned_to,
+    prjtask_hours_budget=NEW.hours_budgeted,
+    prjtask_hours_actual=NEW.hours_actual,
+    prjtask_exp_budget=NEW.expenses_budgeted,
+    prjtask_exp_actual=NEW.expenses_actual,
+    prjtask_status=
+    CASE 
+      WHEN (NEW.status='In-Process') THEN
+        'O'
+      WHEN (NEW.status='Completed') THEN
+        'C'
+      ELSE
+        'P'
+    END,
+    prjtask_due_date=NEW.due,
+    prjtask_assigned_date=NEW.assigned,
+    prjtask_start_date=NEW.started,
+    prjtask_completed_date=NEW.completed
+  WHERE ((prjtask_prj_id=getPrjId(OLD.project_number))
+   AND (prjtask_number=OLD.number));
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.task DO INSTEAD
+
+  DELETE FROM prjtask
+  WHERE ((prjtask_prj_id=getPrjId(OLD.project_number))
+   AND (prjtask_number=OLD.number));
diff --git a/foundation-database/api/views/taskcomment.sql b/foundation-database/api/views/taskcomment.sql
new file mode 100644 (file)
index 0000000..c50568f
--- /dev/null
@@ -0,0 +1,47 @@
+-- Task Comment
+
+SELECT dropIfExists('VIEW', 'taskcomment', 'api');
+CREATE VIEW api.taskcomment
+AS 
+   SELECT 
+     prj_number::varchar AS project_number,
+     prjtask_number::varchar AS task_number,
+     cmnttype_name AS type,
+     comment_date AS date,
+     comment_user AS username,
+     comment_text AS text
+   FROM prj, prjtask, cmnttype, comment
+   WHERE ((comment_source='TA')
+   AND (prj_id=prjtask_prj_id)
+   AND (comment_source_id=prjtask_id)
+   AND (comment_cmnttype_id=cmnttype_id));
+
+GRANT ALL ON TABLE api.taskcomment TO xtrole;
+COMMENT ON VIEW api.taskcomment IS 'Task Comment';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.taskcomment DO INSTEAD
+
+  INSERT INTO comment (
+    comment_date,
+    comment_source,
+    comment_source_id,
+    comment_user,
+    comment_cmnttype_id,
+    comment_text
+    )
+  VALUES (
+    COALESCE(NEW.date,now()),
+    'TA',
+    getPrjTaskId(NEW.project_number,NEW.task_number),
+    COALESCE(NEW.username,getEffectiveXtUser()),
+    getCmntTypeId(NEW.type),
+    NEW.text);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.taskcomment DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.taskcomment DO INSTEAD NOTHING;
diff --git a/foundation-database/api/views/todo.sql b/foundation-database/api/views/todo.sql
new file mode 100644 (file)
index 0000000..fb20b01
--- /dev/null
@@ -0,0 +1,142 @@
+-- To-Do List View
+
+SELECT dropIfExists('VIEW', 'todo', 'api');
+CREATE OR REPLACE VIEW api.todo AS
+  SELECT
+    todoitem_id AS task_number,
+    todoitem_owner_username AS owner,
+    todoitem_username AS assigned_to,
+    todoitem_name AS task_name,
+    incdtpriority_name AS priority,
+    incdt_number AS incident,
+    ophead_name AS opportunity,
+    crmacct_number AS account,
+    formatdate(todoitem_due_date) AS date_due,
+    formatdate(todoitem_assigned_date) AS date_assigned,
+    formatdate(todoitem_start_date) AS date_started,
+    formatdate(todoitem_completed_date) AS date_completed,
+    CASE
+      WHEN todoitem_status = 'P' THEN
+        'Pending Input'
+      WHEN todoitem_status = 'D' THEN
+        'Deferred'
+      ELSE
+        'Neither'
+    END AS status,
+    todoitem_active AS active,
+    todoitem_description AS description,
+    todoitem_notes AS notes
+    FROM todoitem
+       LEFT OUTER JOIN incdt ON (incdt_id=todoitem_incdt_id)
+       LEFT OUTER JOIN ophead ON (ophead_id=todoitem_ophead_id)
+       LEFT OUTER JOIN crmacct ON (crmacct_id=todoitem_crmacct_id)
+       LEFT OUTER JOIN incdtpriority ON (incdtpriority_id=todoitem_priority_id);
+
+GRANT ALL ON TABLE api.todo TO xtrole;
+COMMENT ON VIEW api.todo IS 'To-Do List';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.todo DO INSTEAD
+
+  SELECT createTodoItem(
+    NULL,
+    NEW.assigned_to,
+    COALESCE(NEW.task_name, ''),
+    COALESCE(NEW.description, ''),
+    getIncidentId(NEW.incident),
+    COALESCE(getIncdtCrmAcctId(NEW.incident), getCrmAcctId(NEW.account)),
+    getOpHeadId(NEW.opportunity),
+    CASE
+      WHEN (NEW.date_started > '') THEN
+        NEW.date_started::DATE
+      ELSE
+        NULL
+    END,
+    CASE
+      WHEN (NEW.date_due > '') THEN
+        NEW.date_due::DATE
+      ELSE
+        NULL
+    END,
+    CASE
+      WHEN NEW.status = 'Pending Input' THEN
+        'P'
+      WHEN NEW.status = 'Deferred' THEN
+        'D'
+      ELSE
+        'N'
+    END,
+    CASE
+      WHEN (NEW.date_assigned > '') THEN
+        NEW.date_assigned::DATE
+      ELSE
+        NULL
+    END,
+    CASE
+      WHEN (NEW.date_completed > '') THEN
+        NEW.date_completed::DATE
+      ELSE
+        NULL
+    END,
+    getIncdtPriorityId(NEW.priority),
+    COALESCE(NEW.notes, ''),
+    NEW.owner
+    );
+
+CREATE OR REPLACE RULE "_UPDATE" AS 
+    ON UPDATE TO api.todo DO INSTEAD
+
+  SELECT updateTodoItem(
+    OLD.task_number,
+    OLD.assigned_to,
+    NEW.task_name,
+    NEW.description,
+    getIncidentId(NEW.incident),
+    COALESCE(getIncdtCrmAcctId(NEW.incident), getCrmAcctId(NEW.account)),
+    getOpHeadId(NEW.opportunity),
+    CASE
+      WHEN (NEW.date_started > '') THEN
+        NEW.date_started::DATE
+      ELSE
+        NULL
+    END,
+    CASE
+      WHEN (NEW.date_due > '') THEN
+        NEW.date_due::DATE
+      ELSE
+        NULL
+    END,
+    CASE
+      WHEN NEW.status = 'Pending Input' THEN
+        'P'
+      WHEN NEW.status = 'Deferred' THEN
+        'D'
+      WHEN NEW.status = 'Neither' THEN
+        'N'
+      ELSE
+        NULL
+    END,
+    CASE
+      WHEN (NEW.date_assigned > '') THEN
+        NEW.date_assigned::DATE
+      ELSE
+        NULL
+    END,
+    CASE
+      WHEN (NEW.date_completed > '') THEN
+        NEW.date_completed::DATE
+      ELSE
+        NULL
+    END,
+    getIncdtPriorityId(NEW.priority),
+    NEW.notes,
+    NEW.active,
+    NEW.owner
+    );
+           
+CREATE OR REPLACE RULE "_DELETE" AS 
+    ON DELETE TO api.todo DO INSTEAD
+
+  SELECT deleteTodoItem(OLD.task_number);
diff --git a/foundation-database/api/views/vendor.sql b/foundation-database/api/views/vendor.sql
new file mode 100644 (file)
index 0000000..9397a5d
--- /dev/null
@@ -0,0 +1,311 @@
+
+SELECT dropIfExists('VIEW', 'vendor', 'api');
+CREATE OR REPLACE VIEW api.vendor AS
+SELECT 
+  vend_number::varchar AS vendor_number,
+  vendtype_code AS vendor_type,
+  vend_name AS vendor_name,
+  vend_active AS active,
+  vend_accntnum AS account_number,
+  addr_number AS address_number,
+  addr_line1 AS address1,
+  addr_line2 AS address2,
+  addr_line3 AS address3,
+  addr_city AS city,
+  addr_state AS state,
+  addr_postalcode AS postalcode,
+  addr_country AS country,
+  (''::TEXT) AS address_change,
+  terms_code AS default_terms,
+  vend_shipvia AS ship_via,
+  curr_abbr AS default_currency,
+  CASE 
+    WHEN vend_fobsource='W' THEN
+     'Receiving Site'
+    ELSE
+     vend_fob
+  END AS default_fob,
+  vend_po AS sells_purchase_order_items,
+  vend_restrictpurch AS may_only_sell_item_source,
+  vend_qualified AS qualified,
+  vend_match AS matching_vo_po_amounts,
+  vend_1099 AS receives_1099,
+  taxzone_code AS default_tax_zone,
+  CASE WHEN (accnt_id IS NULL) THEN 'N/A'
+       ELSE formatGLAccount(accnt_id)
+  END AS default_dist_gl_account,
+  CASE WHEN (expcat_id IS NULL) THEN 'N/A'
+       ELSE expcat_code
+  END AS default_dist_expense_category,
+  CASE WHEN (tax_id IS NULL) THEN 'N/A'
+       ELSE tax_code
+  END AS default_dist_tax_code,
+  c1.cntct_number AS contact1_number,
+  c1.cntct_honorific AS contact1_honorific,
+  c1.cntct_first_name AS contact1_first,
+  c1.cntct_middle AS contact1_middle,   
+  c1.cntct_last_name AS contact1_last,
+  c1.cntct_suffix AS contact1_suffix,
+  c1.cntct_title AS contact1_job_title,
+  c1.cntct_phone AS contact1_voice,
+  c1.cntct_phone2 AS contact1_alternate,
+  c1.cntct_fax AS contact1_fax,
+  c1.cntct_email AS contact1_email,
+  c1.cntct_webaddr AS contact1_web,
+  (''::TEXT) AS contact1_change,
+  c2.cntct_number AS contact2_number,
+  c2.cntct_honorific AS contact2_honorific,
+  c2.cntct_first_name AS contact2_first,
+  c2.cntct_middle AS contact2_middle,
+  c2.cntct_last_name AS contact2_last,
+  c2.cntct_suffix AS contact2_suffix,
+  c2.cntct_title AS contact2_job_title,
+  c2.cntct_phone AS contact2_voice,
+  c2.cntct_phone2 AS contact2_alternate,
+  c2.cntct_fax AS contact2_fax,
+  c2.cntct_email AS contact2_email,
+  c2.cntct_webaddr AS contact2_web,
+  (''::TEXT) AS contact2_change,
+  vend_comments AS notes,
+  vend_pocomments AS po_comments,
+  vend_emailpodelivery AS allow_email_po_delivery,
+  vend_ediemail AS po_edi_email,
+  vend_edicc AS po_edi_cc,
+  vend_edisubject AS po_edi_subject,
+  vend_edifilename AS po_edi_filename,
+  vend_ediemailbody AS po_edi_emailbody
+FROM
+  vendinfo
+    LEFT OUTER JOIN addr ON (vend_addr_id=addr_id)
+    LEFT OUTER JOIN cntct c1 ON (vend_cntct1_id=c1.cntct_id)
+    LEFT OUTER JOIN cntct c2 ON (vend_cntct2_id=c2.cntct_id)
+    LEFT OUTER JOIN taxzone ON (vend_taxzone_id=taxzone_id)
+    LEFT OUTER JOIN curr_symbol ON (vend_curr_id=curr_id)
+    LEFT OUTER JOIN terms ON (vend_terms_id=terms_id)
+    LEFT OUTER JOIN vendtype ON (vend_vendtype_id=vendtype_id)
+    LEFT OUTER JOIN accnt ON (vend_accnt_id=accnt_id)
+    LEFT OUTER JOIN expcat ON (vend_expcat_id=expcat_id)
+    LEFT OUTER JOIN tax ON (vend_tax_id=tax_id)
+ORDER BY vend_number;
+
+GRANT ALL ON TABLE api.vendor TO xtrole;
+COMMENT ON VIEW api.vendor IS 'vendor';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.vendor DO INSTEAD
+
+INSERT INTO vendinfo (
+  vend_name,
+  vend_lastpurchdate,
+  vend_active,
+  vend_po,
+  vend_comments,
+  vend_pocomments,
+  vend_number,
+  vend_1099,
+  vend_exported,
+  vend_fobsource,
+  vend_fob,
+  vend_terms_id,
+  vend_shipvia,
+  vend_vendtype_id,
+  vend_qualified,
+  vend_ediemail,
+  vend_ediemailbody,
+  vend_edisubject,
+  vend_edifilename,
+  vend_accntnum,
+  vend_emailpodelivery,
+  vend_restrictpurch,
+  vend_edicc,
+  vend_curr_id,
+  vend_cntct1_id,
+  vend_cntct2_id,
+  vend_addr_id,
+  vend_match,
+  vend_taxzone_id,
+  vend_ach_routingnumber,
+  vend_ach_accntnumber,
+  vend_accnt_id,
+  vend_expcat_id,
+  vend_tax_id )
+VALUES (
+  COALESCE(NEW.vendor_name, ''),
+  NULL,
+  COALESCE(NEW.active, true),
+  COALESCE(NEW.sells_purchase_order_items, false),
+  COALESCE(NEW.notes, ''),
+  COALESCE(NEW.po_comments, ''),
+  COALESCE(NEW.vendor_number, ''),
+  COALESCE(NEW.receives_1099, false),
+  false,
+  CASE 
+    WHEN NEW.default_fob='Receiving Site' THEN
+     'W'
+    ELSE
+     'V'
+  END,
+  CASE 
+    WHEN NEW.default_fob='Receiving Site' THEN
+     ''
+    ELSE
+     NEW.default_fob
+  END,
+  COALESCE(getTermsId(NEW.default_terms), FetchMetricValue('DefaultTerms')),
+  COALESCE(NEW.ship_via, FetchDefaultShipVia()),
+  getVendtypeId(NEW.vendor_type),
+  COALESCE(NEW.qualified, false),
+  COALESCE(NEW.po_edi_email, ''),
+  COALESCE(NEW.po_edi_emailbody, ''),
+  COALESCE(NEW.po_edi_subject, ''),
+  COALESCE(NEW.po_edi_filename, ''),
+  COALESCE(NEW.account_number, ''),
+  COALESCE(NEW.allow_email_po_delivery, false),
+  COALESCE(NEW.may_only_sell_item_source, false),
+  COALESCE(NEW.po_edi_cc, ''),
+  COALESCE(getCurrId(NEW.default_currency), basecurrid()),
+  saveCntct( getCntctId(NEW.contact1_number),
+             NEW.contact1_number,
+             NULL,
+             NEW.contact1_honorific,
+             NEW.contact1_first,
+             NEW.contact1_middle,
+             NEW.contact1_last,
+             NEW.contact1_suffix,
+             NEW.contact1_voice,
+             NEW.contact1_alternate,
+             NEW.contact1_fax,
+             NEW.contact1_email,
+             NEW.contact1_web,
+             NEW.contact1_job_title,
+             NEW.contact1_change ),
+  saveCntct( getCntctId(NEW.contact2_number),
+             NEW.contact2_number,
+             NULL,
+             NEW.contact2_honorific,
+             NEW.contact2_first,
+             NEW.contact2_middle,
+             NEW.contact2_last,
+             NEW.contact2_suffix,
+             NEW.contact2_voice,
+             NEW.contact2_alternate,
+             NEW.contact2_fax,
+             NEW.contact2_email,
+             NEW.contact2_web,
+             NEW.contact2_job_title,
+             NEW.contact2_change ),
+  saveAddr( getAddrId(NEW.address_number),
+            NEW.address_number,
+            NEW.address1,
+            NEW.address2,
+            NEW.address3,
+            NEW.city,
+            NEW.state,
+            NEW.postalcode,
+            NEW.country,
+            NEW.address_change ),
+  COALESCE(NEW.matching_vo_po_amounts, false),
+  getTaxZoneId(NEW.default_tax_zone),
+            '',
+            '',
+  COALESCE(getGLAccntId(NEW.default_dist_gl_account), -1),
+  COALESCE(getExpCatId(NEW.default_dist_expense_category), -1),
+  COALESCE(getTaxId(NEW.default_dist_tax_code), -1)
+);
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.vendor DO INSTEAD
+
+UPDATE vendinfo SET
+  vend_name=NEW.vendor_name,
+  vend_active=NEW.active,
+  vend_po=NEW.sells_purchase_order_items,
+  vend_comments=NEW.notes,
+  vend_pocomments=NEW.po_comments,
+  vend_1099=NEW.receives_1099,
+  vend_fobsource = CASE 
+                     WHEN NEW.default_fob IS NULL THEN
+                       NULL
+                     WHEN NEW.default_fob='Receiving Site' THEN
+                       'W'
+                     ELSE
+                       'V'
+                   END,
+  vend_fob       = CASE 
+                     WHEN NEW.default_fob IS NULL THEN
+                       NULL
+                     WHEN NEW.default_fob='Receiving Site' THEN
+                       ''
+                     ELSE
+                       NEW.default_fob
+                   END,
+  vend_terms_id=getTermsId(NEW.default_terms),
+  vend_shipvia=NEW.ship_via,
+  vend_vendtype_id=getVendtypeId(NEW.vendor_type),
+  vend_qualified=NEW.qualified,
+  vend_ediemail=NEW.po_edi_email,
+  vend_ediemailbody=NEW.po_edi_emailbody,
+  vend_edisubject=NEW.po_edi_subject,
+  vend_edifilename=NEW.po_edi_filename,
+  vend_accntnum=NEW.account_number,
+  vend_emailpodelivery=NEW.allow_email_po_delivery,
+  vend_restrictpurch=NEW.may_only_sell_item_source,
+  vend_edicc=NEW.po_edi_cc,
+  vend_curr_id=getCurrId(NEW.default_currency),
+  vend_cntct1_id=
+  saveCntct( getCntctId(NEW.contact1_number),
+             NEW.contact1_number,
+             NULL,
+             NEW.contact1_honorific,
+             NEW.contact1_first,
+             NEW.contact1_middle,
+             NEW.contact1_last,
+             NEW.contact1_suffix,
+             NEW.contact1_voice,
+             NEW.contact1_alternate,
+             NEW.contact1_fax,
+             NEW.contact1_email,
+             NEW.contact1_web,
+             NEW.contact1_job_title,
+             NEW.contact1_change ),
+  vend_cntct2_id=
+  saveCntct( getCntctId(NEW.contact2_number),
+             NEW.contact2_number,
+             NULL,
+             NEW.contact2_honorific,
+             NEW.contact2_first,
+             NEW.contact2_middle,
+             NEW.contact2_last,
+             NEW.contact2_suffix,
+             NEW.contact2_voice,
+             NEW.contact2_alternate,
+             NEW.contact2_fax,
+             NEW.contact2_email,
+             NEW.contact2_web,
+             NEW.contact2_job_title,
+             NEW.contact2_change ),
+  vend_addr_id=
+  saveAddr( getAddrId(NEW.address_number),
+            NEW.address_number,
+            NEW.address1,
+            NEW.address2,
+            NEW.address3,
+            NEW.city,
+            NEW.state,
+            NEW.postalcode,
+            NEW.country,
+            NEW.address_change ),
+  vend_match=NEW.matching_vo_po_amounts,
+  vend_taxzone_id=getTaxZoneId(NEW.default_tax_zone),
+  vend_accnt_id=COALESCE(getGLAccntId(NULLIF(NEW.default_dist_gl_account, 'N/A')), -1),
+  vend_expcat_id=COALESCE(getExpCatId(NULLIF(NEW.default_dist_expense_category, 'N/A')), -1),
+  vend_tax_id=COALESCE(getTaxId(NULLIF(NEW.default_dist_tax_code, 'N/A')), -1)
+WHERE vend_id=getVendId(OLD.vendor_number);
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.vendor DO INSTEAD
+    DELETE FROM public.vendinfo WHERE (vend_number=OLD.vendor_number);
+
diff --git a/foundation-database/api/views/vendoraddress.sql b/foundation-database/api/views/vendoraddress.sql
new file mode 100644 (file)
index 0000000..20e770f
--- /dev/null
@@ -0,0 +1,145 @@
+--Vendor Address View
+
+SELECT dropIfExists('VIEW', 'vendoraddress', 'api');
+CREATE OR REPLACE VIEW api.vendoraddress AS
+SELECT 
+  vend_number::VARCHAR AS vendor_number,
+  vend_name AS vendor_name,
+  vendaddr_code::VARCHAR AS vendor_address_number,
+  vendaddr_name AS vendor_address_name,
+  addr_number AS address_number,
+  addr_line1 AS address1,
+  addr_line2 AS address2,
+  addr_line3 AS address3,
+  addr_city AS city,
+  addr_state AS state,
+  addr_postalcode AS postalcode,
+  addr_country AS country,
+  (''::TEXT) AS address_change,
+  cntct_number AS contact_number,
+  cntct_honorific AS contact_honorific,
+  cntct_first_name AS contact_first,
+  cntct_middle AS contact_middle,   
+  cntct_last_name AS contact_last,
+  cntct_suffix AS contact_suffix,
+  cntct_title AS contact_job_title,
+  cntct_phone AS contact_voice,
+  cntct_phone2 AS contact_alternate,
+  cntct_fax AS contact_fax,
+  cntct_email AS contact_email,
+  cntct_webaddr AS contact_web,
+  (''::TEXT) AS contact_change,
+  vendaddr_comments AS notes
+FROM
+  vendaddrinfo
+    LEFT OUTER JOIN vendinfo ON (vend_id=vendaddr_vend_id)
+    LEFT OUTER JOIN addr ON (vendaddr_addr_id=addr_id)
+    LEFT OUTER JOIN cntct ON (vendaddr_cntct_id=cntct_id)
+ORDER BY vendaddr_code;
+
+GRANT ALL ON TABLE api.vendoraddress TO xtrole;
+COMMENT ON VIEW api.vendoraddress IS 'vendor address';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+    ON INSERT TO api.vendoraddress DO INSTEAD
+
+INSERT INTO vendaddrinfo (
+  vendaddr_vend_id,
+  vendaddr_code,
+  vendaddr_name,
+  vendaddr_comments,
+  vendaddr_cntct_id,
+  vendaddr_addr_id )
+VALUES (
+  getVendId(NEW.vendor_number),
+  COALESCE(NEW.vendor_address_number, ''),
+  COALESCE(NEW.vendor_address_name, ''),
+  COALESCE(NEW.notes, ''),
+  saveCntct( getCntctId(NEW.contact_number),
+             NEW.contact_number,
+             saveAddr( getAddrId(NEW.address_number),
+                       NEW.address_number,
+                       NEW.address1,
+                       NEW.address2,
+                       NEW.address3,
+                       NEW.city,
+                       NEW.state,
+                       NEW.postalcode,
+                       NEW.country,
+                       NEW.address_change ),
+             NEW.contact_honorific,
+             NEW.contact_first,
+             NEW.contact_middle,
+             NEW.contact_last,
+             NEW.contact_suffix,
+             NEW.contact_voice,
+             NEW.contact_alternate,
+             NEW.contact_fax,
+             NEW.contact_email,
+             NEW.contact_web,
+             NEW.contact_job_title,
+             NEW.contact_change ),
+  saveAddr( getAddrId(NEW.address_number),
+            NEW.address_number,
+            NEW.address1,
+            NEW.address2,
+            NEW.address3,
+            NEW.city,
+            NEW.state,
+            NEW.postalcode,
+            NEW.country,
+            NEW.address_change ) );
+
+CREATE OR REPLACE RULE "_UPDATE" AS
+    ON UPDATE TO api.vendoraddress DO INSTEAD
+
+UPDATE vendaddrinfo SET
+  vendaddr_vend_id=getVendId(NEW.vendor_number),
+  vendaddr_code=NEW.vendor_address_number,
+  vendaddr_name=NEW.vendor_address_name,
+  vendaddr_comments=NEW.notes,
+  vendaddr_cntct_id=
+    saveCntct( getCntctId(NEW.contact_number),
+               NEW.contact_number,
+               saveAddr( getAddrId(NEW.address_number),
+                         NEW.address_number,
+                         NEW.address1,
+                         NEW.address2,
+                         NEW.address3,
+                         NEW.city,
+                         NEW.state,
+                         NEW.postalcode,
+                         NEW.country,
+                         NEW.address_change ),
+               NEW.contact_honorific,
+               NEW.contact_first,
+               NEW.contact_middle,
+               NEW.contact_last,
+               NEW.contact_suffix,
+               NEW.contact_voice,
+               NEW.contact_alternate,
+               NEW.contact_fax,
+               NEW.contact_email,
+               NEW.contact_web,
+               NEW.contact_job_title,
+               NEW.contact_change ),
+  vendaddr_addr_id=
+    saveAddr( getAddrId(NEW.address_number),
+              NEW.address_number,
+              NEW.address1,
+              NEW.address2,
+              NEW.address3,
+              NEW.city,
+              NEW.state,
+              NEW.postalcode,
+              NEW.country,
+              NEW.address_change )
+WHERE vendaddr_id=getVendAddrId(OLD.vendor_number, OLD.vendor_address_number);
+
+CREATE OR REPLACE RULE "_DELETE" AS
+    ON DELETE TO api.vendoraddress DO INSTEAD
+
+SELECT deletevendoraddress(getVendAddrId(OLD.vendor_number, OLD.vendor_address_number));
diff --git a/foundation-database/api/views/vendortype.sql b/foundation-database/api/views/vendortype.sql
new file mode 100644 (file)
index 0000000..6603737
--- /dev/null
@@ -0,0 +1,38 @@
+--Vendor Type View
+
+SELECT dropIfExists('VIEW', 'vendortype', 'api');
+CREATE OR REPLACE VIEW api.vendortype AS
+
+SELECT
+  vendtype_code::VARCHAR AS code,
+  vendtype_descrip AS description
+FROM vendtype
+ORDER BY vendtype_code;
+
+GRANT ALL ON TABLE api.vendortype TO xtrole;
+COMMENT ON VIEW api.vendortype IS 'Vendor Type';
+
+--Rules
+
+CREATE OR REPLACE RULE "_INSERT" AS
+  ON INSERT TO api.vendortype DO INSTEAD
+
+INSERT INTO vendtype (
+  vendtype_code,
+  vendtype_descrip )
+VALUES (
+  NEW.code,
+  COALESCE(NEW.description,'') );
+CREATE OR REPLACE RULE "_UPDATE" AS
+ON UPDATE TO api.vendortype DO INSTEAD
+
+UPDATE vendtype SET
+  vendtype_code=NEW.code,
+  vendtype_descrip=NEW.description
+  WHERE (vendtype_code=OLD.code);
+
+CREATE OR REPLACE RULE "_DELETE" AS
+ON DELETE TO api.vendortype DO INSTEAD
+
+SELECT deleteVendorType(getVendTypeId(OLD.code));
index aeab924..296bf4b 100644 (file)
     "public/views/saleshistorymisc.sql",
     "public/views/url.sql",
     "public/views/usr.sql",
+
+    "public/indexes/evntlog.sql",
+    "public/indexes/invcitemtax.sql",
+    "public/indexes/shipitem.sql",
+
     "public/functions/acknowledgemessage.sql",
     "public/functions/actcost.sql",
     "public/functions/addrusecount.sql",
     "public/functions/woinvavail.sql",
     "public/functions/woinvavailmatl.sql",
     "public/functions/wostarted.sql",
+
+    "public/trigger_functions/accnt.sql",
+    "public/trigger_functions/addr.sql",
+    "public/trigger_functions/alarm.sql",
+    "public/trigger_functions/apapply.sql",
+    "public/trigger_functions/apopen.sql",
+    "public/trigger_functions/arapply.sql",
+    "public/trigger_functions/aropen.sql",
+    "public/trigger_functions/bomhead.sql",
+    "public/trigger_functions/bomitem.sql",
+    "public/trigger_functions/bomitemsub.sql",
+    "public/trigger_functions/cashrcpt.sql",
+    "public/trigger_functions/cashrcptitem.sql",
+    "public/trigger_functions/cashrcptmisc.sql",
+    "public/trigger_functions/ccard.sql",
+    "public/trigger_functions/char.sql",
+    "public/trigger_functions/charass.sql",
+    "public/trigger_functions/charopt.sql",
+    "public/trigger_functions/checkhead.sql",
+    "public/trigger_functions/cmhead.sql",
+    "public/trigger_functions/cmitem.sql",
+    "public/trigger_functions/cntct.sql",
+    "public/trigger_functions/cntslip.sql",
+    "public/trigger_functions/cobill.sql",
+    "public/trigger_functions/cobmisc.sql",
+    "public/trigger_functions/cohead.sql",
+    "public/trigger_functions/coitem.sql",
+    "public/trigger_functions/comment.sql",
+    "public/trigger_functions/company.sql",
+    "public/trigger_functions/contrct.sql",
+    "public/trigger_functions/crmacct.sql",
+    "public/trigger_functions/curr_rate.sql",
+    "public/trigger_functions/curr_symbol.sql",
+    "public/trigger_functions/cust.sql",
+    "public/trigger_functions/custtype.sql",
+    "public/trigger_functions/docass.sql",
+    "public/trigger_functions/emp.sql",
+    "public/trigger_functions/gltrans.sql",
+    "public/trigger_functions/grppriv.sql",
+    "public/trigger_functions/imageass.sql",
+    "public/trigger_functions/incdt.sql",
+    "public/trigger_functions/invchead.sql",
+    "public/trigger_functions/invcitem.sql",
+    "public/trigger_functions/invhist.sql",
+    "public/trigger_functions/ipsass.sql",
+    "public/trigger_functions/ipshead.sql",
+    "public/trigger_functions/ipsitemchar.sql",
+    "public/trigger_functions/ipsiteminfo.sql",
+    "public/trigger_functions/item.sql",
+    "public/trigger_functions/itemcost.sql",
+    "public/trigger_functions/itemsite.sql",
+    "public/trigger_functions/itemsrc.sql",
+    "public/trigger_functions/itemsrcp.sql",
+    "public/trigger_functions/itemsub.sql",
+    "public/trigger_functions/itemtax.sql",
+    "public/trigger_functions/itemuomconv.sql",
+    "public/trigger_functions/location.sql",
+    "public/trigger_functions/ophead.sql",
+    "public/trigger_functions/pack.sql",
+    "public/trigger_functions/period.sql",
+    "public/trigger_functions/pkghead.sql",
+    "public/trigger_functions/pkgitem.sql",
+    "public/trigger_functions/pkgcmd.sql",
+    "public/trigger_functions/pkgcmdarg.sql",
+    "public/trigger_functions/pkgimage.sql",
+    "public/trigger_functions/pkgmetasql.sql",
+    "public/trigger_functions/pkgpriv.sql",
+    "public/trigger_functions/pkgreport.sql",
+    "public/trigger_functions/pkgscript.sql",
+    "public/trigger_functions/pkguiform.sql",
+    "public/trigger_functions/pohead.sql",
+    "public/trigger_functions/poitem.sql",
+    "public/trigger_functions/pr.sql",
+    "public/trigger_functions/prj.sql",
+    "public/trigger_functions/prjtask.sql",
+    "public/trigger_functions/prospect.sql",
+    "public/trigger_functions/quhead.sql",
+    "public/trigger_functions/quitem.sql",
+    "public/trigger_functions/recur.sql",
+    "public/trigger_functions/report.sql",
+    "public/trigger_functions/salesrep.sql",
+    "public/trigger_functions/saletype.sql",
+    "public/trigger_functions/shipdata.sql",
+    "public/trigger_functions/shipdatasum.sql",
+    "public/trigger_functions/shipform.sql",
+    "public/trigger_functions/shiphead.sql",
+    "public/trigger_functions/shiptoinfo.sql",
+    "public/trigger_functions/shipvia.sql",
+    "public/trigger_functions/sltrans.sql",
+    "public/trigger_functions/taxauth.sql",
+    "public/trigger_functions/terms.sql",
+    "public/trigger_functions/todoitem.sql",
+    "public/trigger_functions/uomconv.sql",
+    "public/trigger_functions/usrpref.sql",
+    "public/trigger_functions/usrpriv.sql",
+    "public/trigger_functions/vend.sql",
+    "public/trigger_functions/vendaddr.sql",
+    "public/trigger_functions/vodist.sql",
+    "public/trigger_functions/vohead.sql",
+    "public/trigger_functions/voitem.sql",
+    "public/trigger_functions/whsezone.sql",
+    "public/trigger_functions/whsinfo.sql",
+    "public/trigger_functions/wo.sql",
+    "public/trigger_functions/womatl.sql",
+
+    "api/functions/getcustnumberfrominfo.sql",
+    "api/functions/insertsalesline.sql",
+
+    "api/views/account.sql",
+    "api/views/accountchar.sql",
+    "api/views/accountcomment.sql",
+    "api/views/accountfile.sql",
+    "api/views/accountimage.sql",
+    "api/views/address.sql",
+    "api/views/addresschar.sql",
+    "api/views/addresscomment.sql",
+    "api/views/apmemo.sql",
+    "api/views/armemo.sql",
+    "api/views/bom.sql",
+    "api/views/bomitem.sql",
+    "api/views/bomitemcomment.sql",
+    "api/views/bomitemsubstitute.sql",
+    "api/views/budget.sql",
+    "api/views/budgetentry.sql",
+    "api/views/cashreceipt.sql",
+    "api/views/cashreceiptapply.sql",
+    "api/views/cashreceiptapplymisc.sql",
+    "api/views/contact.sql",
+    "api/views/contactchar.sql",
+    "api/views/contactcomment.sql",
+    "api/views/creditmemo.sql",
+    "api/views/creditmemoline.sql",
+    "api/views/custchar.sql",
+    "api/views/custcomment.sql",
+    "api/views/custcreditcard.sql",
+    "api/views/customer.sql",
+    "api/views/customertaxreg.sql",
+    "api/views/customertype.sql",
+    "api/views/customertypechar.sql",
+    "api/views/custshipto.sql",
+    "api/views/custtax.sql",
+    "api/views/employee.sql",
+    "api/views/employeechar.sql",
+    "api/views/employeecomment.sql",
+    "api/views/extshipmaint.sql",
+    "api/views/freightpricingscheduleitem.sql",
+    "api/views/glaccount.sql",
+    "api/views/incident.sql",
+    "api/views/incidentchar.sql",
+    "api/views/incidentcomment.sql",
+    "api/views/incidentfile.sql",
+    "api/views/incidentimage.sql",
+    "api/views/invoice.sql",
+    "api/views/invoiceline.sql",
+    "api/views/item.sql",
+    "api/views/itemalias.sql",
+    "api/views/itemchar.sql",
+    "api/views/itemcomment.sql",
+    "api/views/itemcost.sql",
+    "api/views/itemfile.sql",
+    "api/views/itemimage.sql",
+    "api/views/itemsite.sql",
+    "api/views/itemsitecomment.sql",
+    "api/views/itemsource.sql",
+    "api/views/itemsourceprice.sql",
+    "api/views/itemsubstitute.sql",
+    "api/views/itemtaxtype.sql",
+    "api/views/itemuomconversion.sql",
+    "api/views/journalentry.sql",
+    "api/views/location.sql",
+    "api/views/misccounttag.sql",
+    "api/views/physinvcount.sql",
+    "api/views/pricingschedule.sql",
+    "api/views/pricingscheduleassign.sql",
+    "api/views/pricingscheduleitem.sql",
+    "api/views/pricingscheduleitemchar.sql",
+    "api/views/project.sql",
+    "api/views/projectcomment.sql",
+    "api/views/prospect.sql",
+    "api/views/purchaseline.sql",
+    "api/views/purchaselinechar.sql",
+    "api/views/purchaselinecomment.sql",
+    "api/views/purchaseorder.sql",
+    "api/views/purchaseordercomment.sql",
+    "api/views/quote.sql",
+    "api/views/quotecomment.sql",
+    "api/views/quoteline.sql",
+    "api/views/quotelinechar.sql",
+    "api/views/quotelinecomment.sql",
+    "api/views/salescredit.sql",
+    "api/views/saleshistory.sql",
+    "api/views/salesline.sql",
+    "api/views/saleslinechar.sql",
+    "api/views/saleslinecomment.sql",
+    "api/views/salesorder.sql",
+    "api/views/salesordercomment.sql",
+    "api/views/salesrep.sql",
+    "api/views/site.sql",
+    "api/views/sitezone.sql",
+    "api/views/task.sql",
+    "api/views/taskcomment.sql",
+    "api/views/todo.sql",
+    "api/views/vendor.sql",
+    "api/views/vendoraddress.sql",
+    "api/views/vendortype.sql",
+
     "public/tables/metasql/accountNumbers-detail.mql",
     "public/tables/metasql/addresses-detail.mql",
     "public/tables/metasql/allocations-detail.mql",
diff --git a/foundation-database/public/indexes/evntlog.sql b/foundation-database/public/indexes/evntlog.sql
new file mode 100644 (file)
index 0000000..b0422f2
--- /dev/null
@@ -0,0 +1,2 @@
+SELECT dropIfExists('index', 'evntlog_evntlog_username_idx');
+CREATE INDEX evntlog_evntlog_username_idx ON evntlog(evntlog_username);
diff --git a/foundation-database/public/indexes/invcitemtax.sql b/foundation-database/public/indexes/invcitemtax.sql
new file mode 100644 (file)
index 0000000..af601dc
--- /dev/null
@@ -0,0 +1,3 @@
+DROP INDEX IF EXISTS invcitemtax_taxhist_parent_id_idx;
+CREATE INDEX invcitemtax_taxhist_parent_id_idx ON invcitemtax (taxhist_parent_id);
+
diff --git a/foundation-database/public/indexes/shipitem.sql b/foundation-database/public/indexes/shipitem.sql
new file mode 100644 (file)
index 0000000..f378099
--- /dev/null
@@ -0,0 +1,6 @@
+DROP INDEX IF EXISTS shipitem_orderitem_id_idx;
+CREATE INDEX shipitem_orderitem_id_idx ON shipitem (shipitem_orderitem_id);
+
+DROP INDEX IF EXISTS shipitem_invcitem_id_idx;
+CREATE INDEX shipitem_invcitem_id_idx ON shipitem (shipitem_invcitem_id);
+
diff --git a/foundation-database/public/trigger_functions/accnt.sql b/foundation-database/public/trigger_functions/accnt.sql
new file mode 100644 (file)
index 0000000..11eea37
--- /dev/null
@@ -0,0 +1,255 @@
+CREATE OR REPLACE FUNCTION _accntTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  ffSub BOOLEAN;
+  ffProfit BOOLEAN;
+  result INTEGER;
+BEGIN
+  SELECT (metric_value='t')
+    INTO ffSub
+    FROM metric
+   WHERE(metric_name='GLFFSubaccounts')
+   LIMIT 1;
+  ffSub := COALESCE(ffSub, false);
+
+  SELECT (metric_value='t')
+    INTO ffProfit
+    FROM metric
+   WHERE(metric_name='GLFFProfitCenters')
+   LIMIT 1;
+  ffProfit := COALESCE(ffSub, false);
+
+  IF (NEW.accnt_sub IS NOT NULL AND ffSub = false) THEN
+    SELECT subaccnt_id
+      INTO result
+      FROM subaccnt
+     WHERE(subaccnt_number=NEW.accnt_sub)
+     LIMIT 1;
+    IF (NOT FOUND) THEN
+      RAISE EXCEPTION 'You must supply a valid Sub Account Number.';
+    END IF;
+  END IF;
+
+  IF (NEW.accnt_profit IS NOT NULL AND ffProfit = false) THEN
+    SELECT prftcntr_id
+      INTO result
+      FROM prftcntr
+     WHERE(prftcntr_number=NEW.accnt_profit)
+     LIMIT 1;
+    IF (NOT FOUND) THEN
+      RAISE EXCEPTION 'You must supply a valid Profit Center Number.';
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'UPDATE') THEN
+    IF ((NEW.accnt_type != OLD.accnt_type) AND
+        (SELECT (count(*) > 0) FROM gltrans WHERE (gltrans_accnt_id=NEW.accnt_id))) THEN
+      RAISE EXCEPTION 'You may not change the account type of an account that has transaction history';
+    END IF;
+  END IF;
+
+  NEW.accnt_name := formatGlAccount(NEW.accnt_company, NEW.accnt_profit, NEW.accnt_number, NEW.accnt_sub);
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'accntTrigger');
+CREATE TRIGGER accntTrigger BEFORE INSERT OR UPDATE ON accnt FOR EACH ROW EXECUTE PROCEDURE _accntTrigger();
+
+CREATE OR REPLACE FUNCTION _accntUniqueTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+BEGIN
+  -- This trigger is to protect against id collision on inherited tables since there is no way 
+  -- to enforce that with regular constraints.  It should be applied to accnt and any table that 
+  -- inherits accnt.
+  IF (SELECT (count(accnt_id) > 0) FROM accnt WHERE (accnt_id = NEW.accnt_id)) THEN
+    RAISE EXCEPTION 'Can not create record on account with duplicate key %.', NEW.accnt_id;
+  END IF;
+  
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'accntUniqueTrigger');
+CREATE TRIGGER accntUniqueTrigger BEFORE INSERT ON accnt FOR EACH ROW EXECUTE PROCEDURE _accntUniqueTrigger();
+
+CREATE OR REPLACE FUNCTION _accntDeleteTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _accntnum     TEXT := formatGLAccount(OLD.accnt_id);
+  _check INTEGER;
+BEGIN
+-- This trigger is to protect against accounts that are in use
+
+--  Check to see if the passed accnt is used in a Cost Category
+  SELECT costcat_id INTO _check
+  FROM costcat
+  WHERE ( (costcat_asset_accnt_id=OLD.accnt_id)
+     OR   (costcat_liability_accnt_id=OLD.accnt_id)
+     OR   (costcat_adjustment_accnt_id=OLD.accnt_id)
+     OR   (costcat_purchprice_accnt_id=OLD.accnt_id)
+     OR   (costcat_laboroverhead_accnt_id=OLD.accnt_id)
+     OR   (costcat_scrap_accnt_id=OLD.accnt_id)
+     OR   (costcat_invcost_accnt_id=OLD.accnt_id)
+     OR   (costcat_wip_accnt_id=OLD.accnt_id)
+     OR   (costcat_shipasset_accnt_id=OLD.accnt_id)
+     OR   (costcat_mfgscrap_accnt_id=OLD.accnt_id)
+     OR   (costcat_transform_accnt_id=OLD.accnt_id)
+     OR   (costcat_freight_accnt_id=OLD.accnt_id) )
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Can not delete, used in Cost Category';
+  END IF;
+
+--  Check to see if the passed accnt is used in a Sales Account Assignment
+  SELECT salesaccnt_id INTO _check
+  FROM salesaccnt
+  WHERE ( (salesaccnt_sales_accnt_id=OLD.accnt_id)
+     OR   (salesaccnt_credit_accnt_id=OLD.accnt_id)
+     OR   (salesaccnt_cos_accnt_id=OLD.accnt_id) )
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Can not delete, used in Sales Account Assignment';
+  END IF;
+
+--  Check to see if the passed accnt is used in a A/R Account Assignment
+  SELECT araccnt_id INTO _check
+  FROM araccnt
+  WHERE ( (araccnt_freight_accnt_id=OLD.accnt_id)
+     OR   (araccnt_ar_accnt_id=OLD.accnt_id)
+     OR   (araccnt_prepaid_accnt_id=OLD.accnt_id) )
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Can not delete, used in A/R Account Assignment';
+  END IF;
+
+--  Check to see if the passed accnt is used in a Warehouse
+  SELECT warehous_id INTO _check
+  FROM whsinfo
+  WHERE (warehous_default_accnt_id=OLD.accnt_id)
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Can not delete, used in Site';
+  END IF;
+
+--  Check to see if the passed accnt is used in a Bank Account
+  SELECT bankaccnt_id INTO _check
+  FROM bankaccnt
+  WHERE (bankaccnt_accnt_id=OLD.accnt_id)
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Can not delete, used in Bank Account';
+  END IF;
+
+--  Check to see if the passed accnt is used in an Expense Category
+  SELECT expcat_id INTO _check
+  FROM expcat
+  WHERE ( (expcat_exp_accnt_id=OLD.accnt_id)
+     OR   (expcat_liability_accnt_id=OLD.accnt_id)
+     OR   (expcat_purchprice_accnt_id=OLD.accnt_id)
+     OR   (expcat_freight_accnt_id=OLD.accnt_id) )
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Can not delete, used in Expense Category';
+  END IF;
+
+--  Check to see if the passed accnt is used in a Tax Code
+  SELECT tax_id INTO _check
+  FROM tax
+  WHERE (tax_sales_accnt_id=OLD.accnt_id)
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Can not delete, used in Tax Code';
+  END IF;
+
+--  Check to see if the passed accnt is used in a Standard Journal Item
+  SELECT stdjrnlitem_id INTO _check
+  FROM stdjrnlitem
+  WHERE (stdjrnlitem_accnt_id=OLD.accnt_id)
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Can not delete, used in Standard Journal Item';
+  END IF;
+
+--  Check to see if the passed accnt is used in a A/P Account Assignment
+  SELECT apaccnt_ap_accnt_id INTO _check
+  FROM apaccnt
+  WHERE ( (apaccnt_ap_accnt_id=OLD.accnt_id)
+     OR   (apaccnt_prepaid_accnt_id=OLD.accnt_id)
+     OR   (apaccnt_discount_accnt_id=OLD.accnt_id) )
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Can not delete, used in A/P Account Assignment';
+  END IF;
+
+--  Check to see if the passed accnt is used in an A/R Open Item record
+  SELECT aropen_accnt_id INTO _check
+    FROM aropen
+   WHERE (aropen_accnt_id=OLD.accnt_id)
+   LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Can not delete, used in A/R Open Item';
+  END IF;
+
+--  Check to see if the passed accnt has been used in the G/L
+  SELECT gltrans_accnt_id INTO _check
+  FROM gltrans
+  WHERE (gltrans_accnt_id=OLD.accnt_id)
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Can not delete, used in G/L Transaction';
+  END IF;
+
+  SELECT sltrans_accnt_id INTO _check
+  FROM sltrans
+  WHERE (sltrans_accnt_id=OLD.accnt_id)
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Can not delete, used in G/L Journal Transaction';
+  END IF;
+
+  SELECT glseries_accnt_id INTO _check
+  FROM glseries
+  WHERE (glseries_accnt_id=OLD.accnt_id)
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Can not delete, used in G/L Series';
+  END IF;
+
+  SELECT trialbal_accnt_id INTO _check
+  FROM trialbal
+  WHERE (trialbal_accnt_id=OLD.accnt_id)
+    AND (trialbal_beginning != 0 OR trialbal_ending != 0)
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Can not delete, used in Trial Balance';
+  END IF;
+
+  SELECT cashrcptmisc_accnt_id INTO _check
+  FROM cashrcptmisc
+  WHERE (cashrcptmisc_accnt_id=OLD.accnt_id)
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Can not delete, used in Cash Receipt Misc. Application';
+  END IF;
+
+  -- TODO: everything above here should be replaced by fkeys
+  IF (OLD.accnt_id = fetchMetricValue('DefaultAPAccount')) THEN
+    RAISE EXCEPTION 'Cannot delete the default A/P Account [xtuple: accnt, -1, %]',
+                    _accntnum;
+  ELSIF (OLD.accnt_id = fetchMetricValue('DefaultARAccount')) THEN
+    RAISE EXCEPTION 'Cannot delete the default A/R Account [xtuple: accnt, -2, %]',
+                    _accntnum;
+  END IF;
+
+  RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'accntDeleteTrigger');
+CREATE TRIGGER accntDeleteTrigger BEFORE DELETE ON accnt FOR EACH ROW EXECUTE PROCEDURE _accntDeleteTrigger();
diff --git a/foundation-database/public/trigger_functions/addr.sql b/foundation-database/public/trigger_functions/addr.sql
new file mode 100644 (file)
index 0000000..3a8fb0d
--- /dev/null
@@ -0,0 +1,47 @@
+CREATE OR REPLACE FUNCTION _addrtrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple.
+-- See www.xtuple.com/CPAL for the full text of the software license.
+  DECLARE
+    _uses      INTEGER := 0;
+
+  BEGIN
+
+    IF (TG_OP = 'INSERT') THEN
+      --- clear the number from the issue cache
+      PERFORM clearNumberIssue('AddressNumber', NEW.addr_number);
+    ELSE
+      SELECT count(*) INTO _uses
+      FROM cntct
+      WHERE ((cntct_addr_id=OLD.addr_id)
+        AND   cntct_active);
+    END IF;
+
+    IF (TG_OP = 'UPDATE') THEN
+      IF (OLD.addr_active AND NOT NEW.addr_active AND _uses > 0) THEN
+       RAISE EXCEPTION 'Cannot inactivate Address with Active Contacts (%)',
+                       _uses;
+      END IF;
+    ELSIF (TG_OP = 'DELETE') THEN
+      IF (_uses > 0) THEN
+       RAISE EXCEPTION 'Cannot Delete Address with Active Contacts (%)',
+                       _uses;
+      END IF;
+
+      UPDATE cntct SET cntct_addr_id = NULL
+      WHERE ((cntct_addr_id=OLD.addr_id)
+       AND  (NOT cntct_active));
+
+      RETURN OLD;
+    END IF;
+
+    RETURN NEW;
+  END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER addrtrigger ON addr;
+CREATE TRIGGER addrtrigger
+  BEFORE  INSERT OR
+         UPDATE OR DELETE
+  ON addr
+  FOR EACH ROW
+  EXECUTE PROCEDURE _addrtrigger();
diff --git a/foundation-database/public/trigger_functions/alarm.sql b/foundation-database/public/trigger_functions/alarm.sql
new file mode 100644 (file)
index 0000000..d61b2b4
--- /dev/null
@@ -0,0 +1,16 @@
+CREATE OR REPLACE FUNCTION _alarmbeforetrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple.
+-- See www.xtuple.com/CPAL for the full text of the software license.
+  BEGIN
+    PERFORM clearNumberIssue('AlarmNumber', NEW.alarm_number);
+
+    RETURN NEW;
+  END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'alarmbeforetrigger');
+CREATE TRIGGER alarmbeforetrigger
+  BEFORE  INSERT 
+  ON alarm
+  FOR EACH ROW
+  EXECUTE PROCEDURE _alarmbeforetrigger();
diff --git a/foundation-database/public/trigger_functions/apapply.sql b/foundation-database/public/trigger_functions/apapply.sql
new file mode 100644 (file)
index 0000000..f6d1f2d
--- /dev/null
@@ -0,0 +1,29 @@
+CREATE OR REPLACE FUNCTION _apapplyTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _tpaid NUMERIC;
+
+BEGIN
+
+-- get the exchange rate for the doc date
+  IF (TG_OP = 'INSERT') THEN
+    SELECT currtocurr(NEW.apapply_curr_id,apopen_curr_id,NEW.apapply_amount,NEW.apapply_postdate) 
+      INTO _tpaid
+    FROM apopen
+    WHERE ( apopen_id=NEW.apapply_target_apopen_id );
+    IF (FOUND) THEN
+      NEW.apapply_target_paid := _tpaid;
+    ELSE
+      RAISE EXCEPTION 'Error calculating paid amount on application';
+    END IF;
+  END IF;
+
+  RETURN NEW;
+
+END;
+
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropifexists('TRIGGER', 'apapplyTrigger');
+CREATE TRIGGER apapplyTrigger BEFORE INSERT OR UPDATE ON apapply FOR EACH ROW EXECUTE PROCEDURE _apapplyTrigger();
diff --git a/foundation-database/public/trigger_functions/apopen.sql b/foundation-database/public/trigger_functions/apopen.sql
new file mode 100644 (file)
index 0000000..bfc861d
--- /dev/null
@@ -0,0 +1,57 @@
+CREATE OR REPLACE FUNCTION _apopenTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _currrate NUMERIC;
+
+BEGIN
+
+-- get the base exchange rate for the doc date
+  IF (TG_OP = 'INSERT' AND NEW.apopen_curr_rate IS NULL) THEN
+    SELECT curr_rate INTO _currrate
+    FROM curr_rate
+    WHERE ( (NEW.apopen_curr_id=curr_id)
+    AND ( NEW.apopen_docdate BETWEEN curr_effective 
+                                 AND curr_expires) );
+    IF (FOUND) THEN
+      NEW.apopen_curr_rate := _currrate;
+    ELSE
+      RAISE EXCEPTION 'Currency exchange rate not found';
+    END IF;
+  END IF;
+
+  NEW.apopen_open := NEW.apopen_amount > NEW.apopen_paid;
+
+  IF (TG_OP = 'INSERT') THEN
+    IF (NEW.apopen_open=FALSE) THEN
+      NEW.apopen_status='C';
+    ELSE
+      NEW.apopen_status='O';
+    END IF;
+
+     --- clear the number from the issue cache
+    PERFORM clearNumberIssue('APMemoNumber', NEW.apopen_docnumber);
+  END IF;
+  
+  IF (TG_OP = 'UPDATE') THEN
+    IF ((OLD.apopen_open=TRUE) AND (NEW.apopen_open=FALSE)) THEN
+      NEW.apopen_status='C';
+      IF (NEW.apopen_closedate IS NULL) THEN
+        NEW.apopen_closedate=CURRENT_DATE;
+      END IF;
+    END IF;
+    
+    IF ((OLD.apopen_open=FALSE) AND (NEW.apopen_open=TRUE)) THEN
+      NEW.apopen_status='O';
+      NEW.apopen_closedate=NULL;
+    END IF;
+  END IF;
+
+  RETURN NEW;
+
+END;
+
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropifexists('TRIGGER', 'apopenTrigger');
+CREATE TRIGGER apopenTrigger BEFORE INSERT OR UPDATE ON apopen FOR EACH ROW EXECUTE PROCEDURE _apopenTrigger();
diff --git a/foundation-database/public/trigger_functions/arapply.sql b/foundation-database/public/trigger_functions/arapply.sql
new file mode 100644 (file)
index 0000000..3733cd2
--- /dev/null
@@ -0,0 +1,34 @@
+CREATE OR REPLACE FUNCTION _arapplyTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _tpaid NUMERIC;
+
+BEGIN
+
+-- get the exchange rate for the doc date
+  IF (TG_OP = 'INSERT') THEN
+    IF (NEW.arapply_target_doctype != 'K') THEN 
+      SELECT round(currtocurr(NEW.arapply_curr_id,aropen_curr_id,NEW.arapply_applied,NEW.arapply_postdate),2) 
+        INTO NEW.arapply_target_paid
+      FROM aropen
+      WHERE ( aropen_id=NEW.arapply_target_aropen_id );
+    ELSE
+      SELECT round(currtocurr(NEW.arapply_curr_id,aropen_curr_id,NEW.arapply_applied,NEW.arapply_postdate),2) 
+        INTO NEW.arapply_target_paid
+      FROM aropen
+      WHERE ( aropen_id=NEW.arapply_source_aropen_id );
+    END IF;
+    IF NOT FOUND THEN
+      NEW.arapply_target_paid := NEW.arapply_applied;
+    END IF;
+  END IF;
+
+  RETURN NEW;
+
+END;
+
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropifexists('TRIGGER', 'arapplyTrigger');
+CREATE TRIGGER arapplyTrigger BEFORE INSERT OR UPDATE ON arapply FOR EACH ROW EXECUTE PROCEDURE _arapplyTrigger();
diff --git a/foundation-database/public/trigger_functions/aropen.sql b/foundation-database/public/trigger_functions/aropen.sql
new file mode 100644 (file)
index 0000000..fbe9a02
--- /dev/null
@@ -0,0 +1,243 @@
+CREATE OR REPLACE FUNCTION _aropenTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _openAmount NUMERIC;
+  _p RECORD;
+  _lateCount INTEGER := 0;
+  _graceDays INTEGER;
+  _checkLate BOOLEAN := false;
+  _checkLimit BOOLEAN := false;
+  _id INTEGER;
+  _currRate NUMERIC;
+BEGIN
+  -- Checks
+  -- Start with privileges
+  IF ( (NOT checkPrivilege('MaintainARMemos')) AND
+       (NOT checkPrivilege('PostMiscInvoices')) AND
+       (NOT checkPrivilege('PostARDocuments')) ) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain A/R Memos.';
+  END IF;
+
+  IF ( (NEW.aropen_docnumber IS NULL) OR (LENGTH(NEW.aropen_docnumber) = 0) ) THEN
+    RAISE EXCEPTION 'You must enter a valid Document # for this A/R Memo.';
+  END IF;
+
+  IF ( (NEW.aropen_amount IS NOT NULL) AND (NEW.aropen_amount < 0) ) THEN
+    RAISE EXCEPTION 'You must enter a positive Amount for this A/R Memo.';
+  END IF;
+
+  IF (TG_OP IN ('INSERT', 'UPDATE') AND NEW.aropen_cust_id < 0) THEN
+    RAISE NOTICE 'Fixing deprecated use of negative aropen_cust_id';
+    NEW.aropen_cust_id := NULL;
+  END IF;
+
+  IF (TG_OP IN ('INSERT', 'UPDATE') AND NEW.aropen_salesrep_id < 0) THEN
+    RAISE NOTICE 'Fixing deprecated use of negative aropen_salesrep_id';
+    NEW.aropen_salesrep_id := NULL;
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    SELECT aropen_id INTO _id
+    FROM aropen
+    WHERE ( (aropen_doctype=NEW.aropen_doctype)
+      AND   (aropen_docnumber=NEW.aropen_docnumber) )
+    LIMIT 1;
+    IF (FOUND) THEN
+      RAISE EXCEPTION 'This Document Type/Number already exists. You may not enter a duplicate A/R Memo.';
+    END IF;
+
+    --- clear the number from the issue cache if applicable
+    PERFORM clearNumberIssue('ARMemoNumber', NEW.aropen_docnumber);
+  END IF;
+
+-- Determine the number of late invoices
+  IF ( SELECT (metric_value='t')
+         FROM metric
+        WHERE(metric_name='AutoCreditWarnLateCustomers')) THEN
+    _checkLate := true;
+
+    SELECT COALESCE(metric_value::integer, _graceDays)
+      INTO _graceDays
+      FROM metric
+     WHERE(metric_name='DefaultAutoCreditWarnGraceDays');
+    IF (NOT FOUND) THEN
+      _graceDays := 30;
+    END IF;
+    SELECT COALESCE(cust_gracedays, _graceDays)
+      INTO _graceDays
+      FROM custinfo
+     WHERE(cust_id=NEW.aropen_cust_id);
+    IF (NOT FOUND) THEN
+      _graceDays := 30;
+    END IF;
+
+    SELECT count(aropen_id)
+      INTO _lateCount
+      FROM aropen
+     WHERE((NEW.aropen_cust_id = aropen_cust_id)
+       AND (aropen_open)
+       AND (aropen_amount > aropen_paid)
+       AND (aropen_doctype IN ('I', 'D'))
+       AND (aropen_duedate < (CURRENT_DATE - _graceDays)));
+
+  --  Adjust _lateCount if late invoice being paid
+    IF ( (NEW.aropen_paid = NEW.aropen_amount)
+     AND (NEW.aropen_doctype IN ('I', 'D'))
+     AND (NEW.aropen_duedate < (CURRENT_DATE - _graceDays))) THEN
+      _lateCount := _lateCount - 1;
+    END IF;
+  END IF;
+
+-- get the base exchange rate for the doc date
+  IF (TG_OP = 'INSERT' AND NEW.aropen_curr_rate IS NULL) THEN
+    SELECT curr_rate INTO _currrate
+      FROM curr_rate
+    WHERE ( (NEW.aropen_curr_id=curr_id)
+      AND ( NEW.aropen_docdate BETWEEN curr_effective 
+                                   AND curr_expires) );
+    IF (FOUND) THEN
+      NEW.aropen_curr_rate := _currrate;
+    ELSE
+      RAISE EXCEPTION 'Currency exchange rate not found';
+    END IF;
+  END IF;
+
+--  Close this aropen if it is paid
+  IF (NEW.aropen_paid = NEW.aropen_amount) THEN
+    NEW.aropen_open=FALSE;
+
+--  Remove any aropenalloc regards that reference this aropen item
+    DELETE FROM aropenalloc WHERE (aropenalloc_aropen_id=NEW.aropen_id);
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    IF (NEW.aropen_open=FALSE) 
+    AND (NEW.aropen_closedate IS NULL) THEN
+      NEW.aropen_closedate=current_date;
+    END IF;
+  END IF;
+  
+  IF (TG_OP = 'UPDATE') THEN
+    IF ((OLD.aropen_open=TRUE) 
+    AND (NEW.aropen_open=FALSE) 
+    AND (NEW.aropen_closedate IS NULL)) THEN
+      NEW.aropen_closedate=current_date;
+    END IF;
+  END IF;
+
+--  Only check if the customer in question has a non-zero Credit Limit
+  SELECT cust_id, cust_creditlmt, cust_creditstatus,
+         cust_autoupdatestatus, cust_autoholdorders INTO _p
+  FROM custinfo
+  WHERE (cust_id=NEW.aropen_cust_id);
+  IF (_p.cust_creditlmt > 0) THEN
+    _checkLimit := true;
+
+    SELECT COALESCE(SUM( CASE WHEN (aropen_doctype IN ('I', 'D')) THEN (aropen_amount - aropen_paid)
+                     ELSE ((aropen_amount - aropen_paid) * -1)
+                END ), 0.0) INTO _openAmount
+    FROM aropen AS current
+    WHERE ( (current.aropen_cust_id=NEW.aropen_cust_id)
+     AND (current.aropen_open)
+     AND (current.aropen_id <> NEW.aropen_id) );
+
+--  Add in the value of the current aropen item
+    IF (NEW.aropen_doctype IN ('I', 'D')) THEN
+      _openAmount := (_openAmount + (NEW.aropen_amount - NEW.aropen_paid));
+    ELSE
+      _openAmount := (_openAmount - (NEW.aropen_amount - NEW.aropen_paid));
+    END IF;
+  ELSE
+    _openAmount := 0;
+  END IF;
+
+  IF (_checkLimit OR _checkLate) THEN
+--  Handle a Customer that is going under its credit limit
+    IF ((_p.cust_creditlmt >= _openAmount) AND (_lateCount <= 0)) THEN
+
+--  Handle the Customer Status
+      IF ( (_p.cust_autoupdatestatus) AND (_p.cust_creditstatus='W') ) THEN
+        UPDATE custinfo
+        SET cust_creditstatus='G'
+        WHERE (cust_id=NEW.aropen_cust_id);
+      END IF;
+
+--  Handle the open Sales Orders
+      IF (_p.cust_autoholdorders) THEN
+        UPDATE cohead
+        SET cohead_holdtype='N'
+        FROM coitem
+        WHERE ( (coitem_cohead_id=cohead_id)
+         AND (cohead_holdtype='C')
+         AND (coitem_status='O')
+         AND (cohead_cust_id=_p.cust_id) );
+      END IF;
+
+--  Handle a Customer that is going over its credit limit
+    ELSIF ((_p.cust_creditlmt < _openAmount) OR (_lateCount > 0)) THEN
+
+--  Handle the Customer Status
+      IF ( (_p.cust_autoupdatestatus) AND (_p.cust_creditstatus = 'G') ) THEN
+        UPDATE custinfo
+        SET cust_creditstatus='W'
+        WHERE (cust_id=NEW.aropen_cust_id);
+      END IF;
+
+--  Handle the open Sales Orders
+      IF (_p.cust_autoholdorders) THEN
+        UPDATE cohead
+        SET cohead_holdtype='C'
+        FROM coitem
+        WHERE ( (coitem_cohead_id=cohead_id)
+         AND (cohead_holdtype='N')
+         AND (coitem_status='O')
+         AND (cohead_cust_id=_p.cust_id) );
+      END IF;
+
+    END IF;
+
+  END IF;
+
+  RETURN NEW;
+
+END;
+$$
+ LANGUAGE 'plpgsql';
+
+DROP TRIGGER aropenTrigger ON aropen;
+CREATE TRIGGER aropenTrigger BEFORE INSERT OR UPDATE ON aropen FOR EACH ROW EXECUTE PROCEDURE _aropenTrigger();
+
+CREATE OR REPLACE FUNCTION _aropenAfterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _openAmount NUMERIC;
+  _lateCount INTEGER := 0;
+  _graceDays INTEGER;
+  _checkLate BOOLEAN := false;
+  _checkLimit BOOLEAN := false;
+  _id INTEGER;
+BEGIN
+
+  IF (TG_OP = 'INSERT') THEN
+    _id := NEW.aropen_id;
+  ELSE
+    _id := OLD.aropen_id;
+  END IF;
+-- If metric is set then auto close any associated incidents when AR is closed
+  IF (fetchMetricBool('AutoCloseARIncident')) THEN
+    IF (NEW.aropen_open = FALSE) THEN
+      UPDATE incdt SET incdt_status='L' WHERE (incdt_aropen_id=_id);
+    END IF;
+  END IF;
+
+  RETURN NEW;
+
+END;
+$$
+ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'aropenAfterTrigger');
+CREATE TRIGGER aropenAfterTrigger AFTER INSERT OR UPDATE ON aropen FOR EACH ROW EXECUTE PROCEDURE _aropenAfterTrigger();
+
diff --git a/foundation-database/public/trigger_functions/bomhead.sql b/foundation-database/public/trigger_functions/bomhead.sql
new file mode 100644 (file)
index 0000000..2ee74ef
--- /dev/null
@@ -0,0 +1,18 @@
+CREATE OR REPLACE FUNCTION _bomheadTrigger() RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _revid INTEGER;
+  _check TEXT;
+BEGIN
+-- Privilege Checks
+  IF (NOT checkPrivilege(''MaintainBOMs'')) THEN
+    RAISE EXCEPTION ''You do not have privileges to maintain Bills of Material.'';
+  END IF;
+  
+  RETURN NEW;
+END;
+' LANGUAGE 'plpgsql';
+
+DROP TRIGGER bomheadTrigger ON bomhead;
+CREATE TRIGGER bomheadTrigger AFTER INSERT OR UPDATE OR DELETE ON bomhead FOR EACH ROW EXECUTE PROCEDURE _bomheadTrigger();
diff --git a/foundation-database/public/trigger_functions/bomitem.sql b/foundation-database/public/trigger_functions/bomitem.sql
new file mode 100644 (file)
index 0000000..a97c20f
--- /dev/null
@@ -0,0 +1,257 @@
+SELECT dropIfExists('TRIGGER','bomitemTrigger');
+SELECT dropIfExists('FUNCTION','_bomitemTrigger()');
+
+CREATE OR REPLACE FUNCTION _bomitemBeforeTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _bomworksetid INTEGER;
+  _bomworkid INTEGER;
+  _seqNumber INTEGER;
+  _parentItem RECORD;
+BEGIN
+
+  -- Privilege Checks
+  IF (NOT checkPrivilege('MaintainBOMs')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Bills of Material.';
+  END IF;
+
+  -- Cache Parent Item
+   SELECT * INTO _parentItem
+   FROM item
+   WHERE (item_id=NEW.bomitem_parent_item_id);
+
+  IF (TG_OP = 'INSERT') THEN
+    --  Make sure that the parent and component are not the same
+    IF (NEW.bomitem_parent_item_id = NEW.bomitem_item_id) THEN
+      RAISE EXCEPTION 'BOM Item Parent and Component Item cannot be the same. [xtuple: createBOMItem, -1]';
+    END IF;
+
+    --  Make sure that the parent is not used in the component at some level
+    SELECT indentedWhereUsed(NEW.bomitem_parent_item_id) INTO _bomworksetid;
+    SELECT bomwork_id INTO _bomworkid
+    FROM bomwork
+    WHERE ((bomwork_set_id=_bomworksetid)
+      AND  (bomwork_item_id=NEW.bomitem_item_id))
+    LIMIT 1;
+    IF (FOUND) THEN
+      PERFORM deleteBOMWorkset(_bomworksetid);
+      RAISE EXCEPTION 'BOM Item Parent is used by Component, BOM is recursive. [xtuple: createBOMItem, -2]';
+    END IF;
+
+    PERFORM deleteBOMWorkset(_bomworksetid);
+
+    -- Set defaults
+    NEW.bomitem_rev_id := COALESCE(NEW.bomitem_rev_id, -1);
+    NEW.bomitem_booitem_seq_id := COALESCE(NEW.bomitem_booitem_seq_id, -1);
+    NEW.bomitem_schedatwooper := COALESCE(NEW.bomitem_schedatwooper, FALSE);
+    IF (NEW.bomitem_seqnumber IS NULL) THEN
+      --  Grab the next Sequence Number, if any
+      SELECT MAX(bomitem_seqnumber) INTO _seqNumber
+      FROM bomitem(NEW.bomitem_parent_item_id,NEW.bomitem_rev_id);
+      IF (_seqNumber IS NOT NULL) THEN
+        NEW.bomitem_seqnumber := (_seqNumber + 10);
+      ELSE
+        NEW.bomitem_seqnumber := 10;
+      END IF;
+    END IF;
+  END IF; -- end Insert specific
+
+  IF (TG_OP = 'UPDATE') THEN
+    -- Disallow changes that would compromise revision control integrity
+    IF (NEW.bomitem_parent_item_id != OLD.bomitem_parent_item_id) THEN
+      RAISE EXCEPTION 'Parent Item ID may not be changed.';
+    END IF;
+
+    IF (NEW.bomitem_item_id != OLD.bomitem_item_id) THEN
+      RAISE EXCEPTION 'Item ID may not be changed.';
+    END IF;
+
+    IF ((fetchMetricBool('RevControl')) AND (OLD.bomitem_rev_id > -1)) THEN
+      IF (SELECT (rev_status = 'I') FROM rev WHERE (rev_id=OLD.bomitem_rev_id)) THEN
+        RAISE EXCEPTION 'Bill of material is Inactive and may not be modified';
+      END IF;
+    END IF;
+  END IF; -- end Update specific
+
+  -- Check for valid UOM
+  IF (SELECT (count(*) != 1)
+      FROM
+             (SELECT uom_id
+                FROM item JOIN uom ON (item_inv_uom_id=uom_id)
+                WHERE(item_id=NEW.bomitem_item_id)
+              UNION 
+              SELECT uom_id
+                FROM item JOIN itemuomconv ON (itemuomconv_item_id=item_id)
+                          JOIN uom ON (itemuomconv_to_uom_id=uom_id),
+                     itemuom, uomtype 
+               WHERE((itemuomconv_from_uom_id=item_inv_uom_id)
+                 AND (item_id=NEW.bomitem_item_id) 
+                 AND (itemuom_itemuomconv_id=itemuomconv_id) 
+                 AND (uomtype_id=itemuom_uomtype_id) 
+                 AND (uomtype_name='MaterialIssue'))
+              UNION 
+              SELECT uom_id
+                FROM item JOIN itemuomconv ON (itemuomconv_item_id=item_id)
+                          JOIN uom ON (itemuomconv_from_uom_id=uom_id),
+                     itemuom, uomtype 
+               WHERE((itemuomconv_to_uom_id=item_inv_uom_id)
+                 AND (item_id=NEW.bomitem_item_id) 
+                 AND (itemuom_itemuomconv_id=itemuomconv_id) 
+                 AND (uomtype_id=itemuom_uomtype_id) 
+                 AND (uomtype_name='MaterialIssue'))) AS data
+        WHERE (uom_id=NEW.bomitem_uom_id)) THEN
+    RAISE EXCEPTION 'Unit of Measure Invalid for Material Issue.';
+  END IF;
+
+-- Disallow configuration parameters if parent is not a job item
+   IF (NEW.bomitem_char_id IS NOT NULL) THEN
+     IF (NOT _parentItem.item_config) THEN
+       RAISE EXCEPTION 'Configuration characteristics may only be defined for Configured Items';
+     END IF;
+   END IF;
+
+  -- Kit items must be sold and not kits themselves
+  IF (_parentItem.item_type = 'K') THEN
+    IF (SELECT (COUNT(item_id) = 0)
+          FROM item
+         WHERE ((item_id=NEW.bomitem_item_id)
+           AND (item_sold)
+           AND (item_type != 'K'))) THEN
+       RAISE EXCEPTION 'Bill of Material Items for kits must be sold and not kits themselves';
+     END IF;
+   END IF;
+
+  -- Over ride logic to disallow invalid data
+  IF (NEW.bomitem_createwo) THEN
+    IF (SELECT (item_type != 'M') 
+          FROM item 
+         WHERE (item_id=NEW.bomitem_item_id)) THEN
+      NEW.bomitem_createwo := FALSE;
+    END IF;
+    IF (NEW.bomitem_booitem_seq_id = -1) THEN
+      NEW.bomitem_schedatwooper := FALSE;
+    END IF;
+  END IF;
+
+  NEW.bomitem_moddate := COALESCE(NEW.bomitem_moddate, CURRENT_DATE);
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER','bomitemBeforeTrigger');
+CREATE TRIGGER bomitemBeforeTrigger BEFORE INSERT OR UPDATE ON bomitem FOR EACH ROW EXECUTE PROCEDURE _bomitemBeforeTrigger();
+
+
+CREATE OR REPLACE FUNCTION _bomitemAfterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+
+BEGIN
+
+  IF ( SELECT fetchMetricBool('ItemChangeLog') ) THEN
+    IF (TG_OP = 'INSERT') THEN
+      PERFORM postComment('ChangeLog', 'BMI', NEW.bomitem_id, ('Created BOM Item Sequence ' || NEW.bomitem_seqnumber::TEXT));
+
+    ELSIF (TG_OP = 'UPDATE') THEN
+      IF (NEW.bomitem_effective <> OLD.bomitem_effective) THEN
+        PERFORM postComment( 'ChangeLog', 'BMI', NEW.bomitem_id,
+                             ( 'Effective Date Changed from ' || formatDate(OLD.bomitem_effective, 'Always') ||
+                               ' to ' || formatDate(NEW.bomitem_effective, 'Always' ) ) );
+      END IF;
+
+      IF (NEW.bomitem_expires <> OLD.bomitem_expires) THEN
+        PERFORM postComment( 'ChangeLog', 'BMI', NEW.bomitem_id,
+                             ( 'Expiration Date Changed from ' || formatDate(OLD.bomitem_expires, 'Never') ||
+                               ' to ' || formatDate(NEW.bomitem_expires, 'Never' ) ) );
+      END IF;
+
+      IF (NEW.bomitem_qtyfxd <> OLD.bomitem_qtyfxd) THEN
+        PERFORM postComment( 'ChangeLog', 'BMI', NEW.bomitem_id,
+                             ( 'Fixed Qty. Changed from ' || formatQtyPer(OLD.bomitem_qtyfxd) ||
+                               ' to ' || formatQtyPer(NEW.bomitem_qtyfxd ) ) );
+      END IF;
+
+      IF (NEW.bomitem_qtyper <> OLD.bomitem_qtyper) THEN
+        PERFORM postComment( 'ChangeLog', 'BMI', NEW.bomitem_id,
+                             ( 'Qty. Per Changed from ' || formatQtyPer(OLD.bomitem_qtyper) ||
+                               ' to ' || formatQtyPer(NEW.bomitem_qtyper ) ) );
+      END IF;
+
+      IF (NEW.bomitem_scrap <> OLD.bomitem_scrap) THEN
+        PERFORM postComment( 'ChangeLog', 'BMI', NEW.bomitem_id,
+                             ( 'Scrap % Changed from ' || formatPrcnt(OLD.bomitem_scrap) ||
+                               ' to ' || formatPrcnt(NEW.bomitem_scrap ) ) );
+      END IF;
+
+      IF (NEW.bomitem_issuemethod <> OLD.bomitem_issuemethod) THEN
+        PERFORM postComment( 'ChangeLog', 'BMI', NEW.bomitem_id,
+                             ( 'Issue Method Changed from ' || (CASE WHEN(OLD.bomitem_issuemethod='S') THEN 'Push'
+                                                                     WHEN(OLD.bomitem_issuemethod='L') THEN 'Pull'
+                                                                     WHEN(OLD.bomitem_issuemethod='M') THEN 'Mixed'
+                                                                     ELSE OLD.bomitem_issuemethod END) ||
+                               ' to ' || (CASE WHEN(NEW.bomitem_issuemethod='S') THEN 'Push'
+                                               WHEN(NEW.bomitem_issuemethod='L') THEN 'Pull'
+                                               WHEN(NEW.bomitem_issuemethod='M') THEN 'Mixed'
+                                               ELSE NEW.bomitem_issuemethod END) ) );
+      END IF;
+
+      IF (NEW.bomitem_ecn <> OLD.bomitem_ecn) THEN
+        PERFORM postComment( 'ChangeLog', 'BMI', NEW.bomitem_id,
+                             ( 'ECN Changed from ' || OLD.bomitem_ecn ||
+                               ' to ' || NEW.bomitem_ecn ) );
+      END IF;
+
+      IF (OLD.bomitem_createwo <> NEW.bomitem_createwo) THEN
+        IF (NEW.bomitem_createwo) THEN
+          PERFORM postComment('ChangeLog', 'BMI', NEW.bomitem_id, 'Create Child W/O activated');
+        ELSE
+          PERFORM postComment('ChangeLog', 'BMI', NEW.bomitem_id, 'Create Child W/O deactivated');
+        END IF;
+      END IF;
+
+      IF (OLD.bomitem_issuewo <> NEW.bomitem_issuewo) THEN
+        IF (NEW.bomitem_issuewo) THEN
+          PERFORM postComment('ChangeLog', 'BMI', NEW.bomitem_id, 'Issue Child W/O activated');
+        ELSE
+          PERFORM postComment('ChangeLog', 'BMI', NEW.bomitem_id, 'Issue Child W/O deactivated');
+        END IF;
+      END IF;
+
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'DELETE') THEN
+    DELETE FROM comment
+     WHERE ( (comment_source='BMI')
+       AND   (comment_source_id=OLD.bomitem_id) );
+
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER','bomitemAfterTrigger');
+CREATE TRIGGER bomitemAfterTrigger AFTER INSERT OR UPDATE ON bomitem FOR EACH ROW EXECUTE PROCEDURE _bomitemAfterTrigger();
+
+
+CREATE OR REPLACE FUNCTION _bomitemBeforeDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+BEGIN
+
+  DELETE FROM comment
+   WHERE ( (comment_source='BMI')
+     AND   (comment_source_id=OLD.bomitem_id) );
+
+  RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER','bomitemBeforeDeleteTrigger');
+CREATE TRIGGER bomitemBeforeDeleteTrigger BEFORE DELETE ON bomitem FOR EACH ROW EXECUTE PROCEDURE _bomitemBeforeDeleteTrigger();
diff --git a/foundation-database/public/trigger_functions/bomitemsub.sql b/foundation-database/public/trigger_functions/bomitemsub.sql
new file mode 100644 (file)
index 0000000..3a093d9
--- /dev/null
@@ -0,0 +1,21 @@
+CREATE OR REPLACE FUNCTION _bomitemsubTrigger() RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+-- Privilege Checks
+  IF (NOT checkPrivilege(''MaintainBOMs'')) THEN
+    RAISE EXCEPTION ''You do not have privileges to maintain Bills of Material.'';
+  END IF;
+
+  IF (TG_OP = ''DELETE'') THEN
+    RETURN OLD;
+  ELSE
+    RETURN NEW;
+  END IF;
+
+END;
+' LANGUAGE 'plpgsql';
+
+DROP TRIGGER bomitemsubTrigger ON bomitemsub;
+CREATE TRIGGER bomitemsubTrigger BEFORE INSERT OR UPDATE OR DELETE ON bomitemsub FOR EACH ROW EXECUTE PROCEDURE _bomitemsubTrigger();
diff --git a/foundation-database/public/trigger_functions/cashrcpt.sql b/foundation-database/public/trigger_functions/cashrcpt.sql
new file mode 100644 (file)
index 0000000..cae0bb2
--- /dev/null
@@ -0,0 +1,72 @@
+CREATE OR REPLACE FUNCTION _cashRcptTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _check      BOOLEAN;
+  _checkId    INTEGER;
+  _currId     INTEGER;
+  _bankCurrId INTEGER;
+  _currrate   NUMERIC;
+
+BEGIN
+
+  -- Checks
+  -- Start with privileges
+  IF (TG_OP = 'INSERT') THEN
+    SELECT checkPrivilege('MaintainCashReceipts') INTO _check;
+    IF NOT (_check) THEN
+      RAISE EXCEPTION 'You do not have privileges to add new Cash Receipts.';
+    END IF;
+  ELSE
+    SELECT checkPrivilege('MaintainCashReceipts') INTO _check;
+    IF NOT (_check) THEN
+      RAISE EXCEPTION 'You do not have privileges to alter a Cash Receipt.';
+    END IF;
+  END IF;
+
+  -- Currency must be same as Bank Currency
+  IF (TG_OP = 'INSERT') THEN
+    _currId = COALESCE(NEW.cashrcpt_curr_id, basecurrid());
+
+     --- clear the number from the issue cache
+    PERFORM clearNumberIssue('CashRcptNumber', NEW.cashrcpt_number);
+  ELSE
+    _currId = NEW.cashrcpt_curr_id;
+  END IF;
+
+-- get the base exchange rate for the dist date
+  IF (NEW.cashrcpt_curr_rate IS NULL) THEN
+    SELECT curr_rate INTO _currrate
+    FROM curr_rate
+    WHERE ( (NEW.cashrcpt_curr_id=curr_id)
+      AND ( NEW.cashrcpt_distdate BETWEEN curr_effective 
+                                 AND curr_expires) );
+    IF (FOUND) THEN
+      NEW.cashrcpt_curr_rate := _currrate;
+    ELSE
+      RAISE EXCEPTION 'Currency exchange rate not found';
+    END IF;
+  END IF;
+
+  -- Create CashReceiptPosted Event
+  IF (TG_OP = 'UPDATE') THEN
+    IF (OLD.cashrcpt_posted=FALSE AND NEW.cashrcpt_posted=TRUE) THEN
+      PERFORM postEvent('CashReceiptPosted', NULL, NEW.cashrcpt_id,
+                        NULL,
+                        (cust_number || '-' ||
+                        NEW.cashrcpt_docnumber || ' ' ||
+                        currConcat(NEW.cashrcpt_curr_id) ||
+                        formatMoney(NEW.cashrcpt_amount)),
+                        NULL, NULL, NULL, NULL)
+      FROM custinfo
+      WHERE (cust_id=NEW.cashrcpt_cust_id);
+    END IF;
+  END IF;
+
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'cashRcptTrigger');
+CREATE TRIGGER cashRcptTrigger BEFORE INSERT OR UPDATE ON cashrcpt FOR EACH ROW EXECUTE PROCEDURE _cashRcptTrigger();
diff --git a/foundation-database/public/trigger_functions/cashrcptitem.sql b/foundation-database/public/trigger_functions/cashrcptitem.sql
new file mode 100644 (file)
index 0000000..71228ec
--- /dev/null
@@ -0,0 +1,74 @@
+CREATE OR REPLACE FUNCTION _cashRcptItemTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _check      BOOLEAN;
+  _openAmount NUMERIC;
+
+BEGIN
+
+  -- Checks
+  -- Start with Privileges
+  IF (TG_OP = 'INSERT') THEN
+    SELECT checkPrivilege('MaintainCashReceipts') INTO _check;
+    IF NOT (_check) THEN
+      RAISE EXCEPTION 'You do not have privileges to add a new Cash Receipt Application.';
+    END IF;
+  ELSE
+    SELECT checkPrivilege('MaintainCashReceipts') INTO _check;
+    IF NOT (_check) THEN
+      RAISE EXCEPTION 'You do not have privileges to alter a Cash Receipt Application.';
+    END IF;
+  END IF;
+
+  -- Over Application
+  SELECT round(currToCurr(aropen_curr_id, cashrcpt_curr_id,
+               aropen_amount - aropen_paid, cashrcpt_distdate) -
+               COALESCE((SELECT SUM(cashrcptitem_amount)
+                           FROM cashrcptitem, cashrcpt
+                           WHERE ((cashrcpt_id=cashrcptitem_cashrcpt_id)
+                             AND  (NOT cashrcpt_void)
+                             AND  (NOT cashrcpt_posted)
+                             AND  (cashrcpt_id != NEW.cashrcptitem_cashrcpt_id)
+                             AND  (cashrcptitem_aropen_id=NEW.cashrcptitem_aropen_id))), 0),2) INTO _openAmount
+  FROM aropen, cashrcpt
+  WHERE ( (aropen_id=NEW.cashrcptitem_aropen_id)
+    AND   (cashrcpt_id=NEW.cashrcptitem_cashrcpt_id) );
+  IF (NEW.cashrcptitem_amount > _openAmount) THEN
+    RAISE EXCEPTION 'You may not apply more than the balance of this item.';
+  END IF;
+
+
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'cashRcptItemTrigger');
+CREATE TRIGGER cashRcptItemTrigger BEFORE INSERT OR UPDATE ON cashrcptitem FOR EACH ROW EXECUTE PROCEDURE _cashRcptItemTrigger();
+
+CREATE OR REPLACE FUNCTION _cashRcptItemAfterTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _total      NUMERIC;
+
+BEGIN
+
+  -- Checks
+  -- Total Over Application Warning
+  SELECT (cashrcpt_amount - SUM(COALESCE(cashrcptitem_amount, 0))) INTO _total
+  FROM cashrcptitem JOIN cashrcpt ON (cashrcpt_id=cashrcptitem_cashrcpt_id)
+  WHERE (cashrcptitem_cashrcpt_id=NEW.cashrcptitem_cashrcpt_id)
+  GROUP BY cashrcpt_amount;
+  IF (_total < 0.0) THEN
+    RAISE WARNING 'Warning -- the Cash Receipt has been over applied.';
+  END IF;
+  
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'cashRcptItemAfterTrigger');
+CREATE TRIGGER cashRcptItemAfterTrigger AFTER INSERT OR UPDATE ON cashrcptitem FOR EACH ROW EXECUTE PROCEDURE _cashRcptItemAfterTrigger();
diff --git a/foundation-database/public/trigger_functions/cashrcptmisc.sql b/foundation-database/public/trigger_functions/cashrcptmisc.sql
new file mode 100644 (file)
index 0000000..48b31cc
--- /dev/null
@@ -0,0 +1,39 @@
+CREATE OR REPLACE FUNCTION _cashRcptMiscTrigger () RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _check      BOOLEAN;
+
+BEGIN
+
+  -- Checks
+  -- Start with Privileges
+  IF (TG_OP = ''INSERT'') THEN
+    SELECT checkPrivilege(''MaintainCashReceipts'') INTO _check;
+    IF NOT (_check) THEN
+      RAISE EXCEPTION ''You do not have privileges to add a new Cash Receipt Misc. Application.'';
+    END IF;
+  ELSE
+    SELECT checkPrivilege(''MaintainCashReceipts'') INTO _check;
+    IF NOT (_check) THEN
+      RAISE EXCEPTION ''You do not have privileges to alter a Cash Receipt Misc. Application.'';
+    END IF;
+  END IF;
+
+  -- Account is required
+  IF (NEW.cashrcptmisc_accnt_id IS NULL) THEN
+    RAISE EXCEPTION ''You must supply a valid GL Account.'';
+  END IF;
+
+  -- Amount is required
+  IF (COALESCE(NEW.cashrcptmisc_amount, 0) = 0) THEN
+    RAISE EXCEPTION ''You must supply a valid Amount.'';
+  END IF;
+
+  RETURN NEW;
+
+END;
+' LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'cashRcptMiscTrigger');
+CREATE TRIGGER cashRcptMiscTrigger BEFORE INSERT OR UPDATE ON cashrcptmisc FOR EACH ROW EXECUTE PROCEDURE _cashRcptMiscTrigger();
diff --git a/foundation-database/public/trigger_functions/ccard.sql b/foundation-database/public/trigger_functions/ccard.sql
new file mode 100644 (file)
index 0000000..83d21e4
--- /dev/null
@@ -0,0 +1,43 @@
+CREATE OR REPLACE FUNCTION _ccardtrigger() RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+
+BEGIN
+
+  New.ccard_lastupdated := current_timestamp;
+  New.ccard_last_updated_by_username := getEffectiveXtUser();
+
+  IF (TG_OP = ''UPDATE'') THEN
+    INSERT INTO ccardaud
+         VALUES (nextval(''ccardaud_ccardaud_id_seq''), NEW.ccard_id,
+                 OLD.ccard_seq, NEW.ccard_seq, OLD.ccard_cust_id, NEW.ccard_cust_id,
+                 OLD.ccard_active, NEW.ccard_active, OLD.ccard_name, NEW.ccard_name,
+                 OLD.ccard_address1, NEW.ccard_address1, OLD.ccard_address2,
+                 NEW.ccard_address2, OLD.ccard_city, NEW.ccard_city, OLD.ccard_state,
+                 NEW.ccard_state, OLD.ccard_zip, NEW.ccard_zip, OLD.ccard_country,
+                 NEW.ccard_country, OLD.ccard_number, NEW.ccard_number, OLD.ccard_debit,
+                 NEW.ccard_debit, OLD.ccard_month_expired, NEW.ccard_month_expired,
+                 OLD.ccard_year_expired, NEW.ccard_year_expired, OLD.ccard_type, NEW.ccard_type);
+  ELSE
+-- We are inserting a record, therefore no old values
+    INSERT INTO ccardaud
+         VALUES (nextval(''ccardaud_ccardaud_id_seq''), NEW.ccard_id,
+                 NULL, NEW.ccard_seq, NULL, NEW.ccard_cust_id, NULL,
+                 NEW.ccard_active, NULL, NEW.ccard_name, NULL,
+                 NEW.ccard_address1, NULL, NEW.ccard_address2, NULL,
+                 NEW.ccard_city, NULL, NEW.ccard_state, NULL,
+                 NEW.ccard_zip, NULL, NEW.ccard_country, NULL,
+                 NEW.ccard_number, NULL, NEW.ccard_debit, NULL,
+                 NEW.ccard_month_expired, NULL, NEW.ccard_year_expired, NULL,
+                 NEW.ccard_type);
+  END IF;
+
+  RETURN NEW;
+
+END;
+'
+  LANGUAGE 'plpgsql';
+
+DROP TRIGGER ccardtrigger ON ccard;
+CREATE TRIGGER ccardtrigger BEFORE INSERT OR UPDATE ON ccard FOR EACH ROW EXECUTE PROCEDURE _ccardtrigger();
diff --git a/foundation-database/public/trigger_functions/char.sql b/foundation-database/public/trigger_functions/char.sql
new file mode 100644 (file)
index 0000000..aec2857
--- /dev/null
@@ -0,0 +1,14 @@
+CREATE OR REPLACE FUNCTION _charBeforeTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (NOT checkPrivilege('MaintainCharacteristics')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Characteristics.';
+  END IF;
+
+  RETURN NEW;
+END;
+$$      LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'charBeforeTrigger');
+CREATE TRIGGER charBeforeTrigger BEFORE INSERT OR UPDATE ON char FOR EACH ROW EXECUTE PROCEDURE _charBeforeTrigger();
diff --git a/foundation-database/public/trigger_functions/charass.sql b/foundation-database/public/trigger_functions/charass.sql
new file mode 100644 (file)
index 0000000..31b9588
--- /dev/null
@@ -0,0 +1,95 @@
+CREATE OR REPLACE FUNCTION _charassTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+-- Privilege Checks
+   IF (NEW.charass_target_type = 'I' AND NOT checkPrivilege('MaintainItemMasters')) THEN
+     RAISE EXCEPTION 'You do not have privileges to maintain Items.';
+   END IF;
+
+   IF (NEW.charass_target_type = 'C' AND NOT checkPrivilege('MaintainCustomerMasters')) THEN
+     RAISE EXCEPTION 'You do not have privileges to maintain Customers.';
+   END IF;
+
+-- Data check
+  IF (NEW.charass_char_id IS NULL) THEN
+       RAISE EXCEPTION 'You must supply a valid Characteristic ID.';
+  END IF;
+
+-- Default Logic
+  IF (NEW.charass_default) THEN
+    UPDATE charass
+    SET charass_default = false 
+    WHERE ((charass_target_id=NEW.charass_target_id)
+    AND  (charass_target_type=NEW.charass_target_type)
+    AND  (charass_char_id=NEW.charass_char_id)
+    AND  (charass_id <> NEW.charass_ID));
+  END IF;
+
+-- Incident update
+  IF (NEW.charass_target_type = 'INCDT') THEN
+    UPDATE incdt SET incdt_updated = now() WHERE incdt_id = NEW.charass_target_id;
+  END IF;
+  
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+select dropIfExists('TRIGGER', 'charassTrigger');
+CREATE TRIGGER charassTrigger AFTER INSERT OR UPDATE ON charass FOR EACH ROW EXECUTE PROCEDURE _charassTrigger();
+
+CREATE OR REPLACE FUNCTION _charassHistoryTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF(TG_OP = 'DELETE') THEN
+    IF (OLD.charass_target_type = 'INCDT') THEN
+      INSERT INTO incdthist
+            (incdthist_incdt_id, incdthist_descrip)
+      VALUES(OLD.charass_target_id,
+             ('Characteristic ' || 
+               COALESCE((SELECT char_name 
+                           FROM char
+                          WHERE (char_id=OLD.charass_char_id)), '')
+              || ' Deleted: "' || 
+              COALESCE(OLD.charass_value,'')
+              || '"') );
+    END IF;
+    RETURN OLD;
+  ELSIF (NEW.charass_target_type = 'INCDT') THEN
+    IF (TG_OP = 'INSERT') THEN
+      INSERT INTO incdthist
+            (incdthist_incdt_id, incdthist_descrip)
+      VALUES(NEW.charass_target_id,
+             ('Characteristic ' || 
+               COALESCE((SELECT char_name 
+                           FROM char
+                          WHERE (char_id=NEW.charass_char_id)), '')
+              || ' Added: "' || 
+              COALESCE(NEW.charass_value,'')
+              || '"') );
+    ELSIF (TG_OP = 'UPDATE') THEN
+      IF (COALESCE(NEW.charass_value,'') <> COALESCE(OLD.charass_value,'')) THEN
+        INSERT INTO incdthist
+              (incdthist_incdt_id, incdthist_descrip)
+        VALUES(NEW.charass_target_id,
+               ('Characteristic ' || 
+                 COALESCE((SELECT char_name 
+                             FROM char
+                            WHERE (char_id=NEW.charass_char_id)), '')
+                || ' Changed: "' || 
+                COALESCE(OLD.charass_value,'')
+                || '" -> "' ||
+                COALESCE(NEW.charass_value,'')
+                || '"') );
+      END IF;
+    END IF;
+  END IF;
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+select dropIfExists('TRIGGER', 'charassHistoryTrigger');
+CREATE TRIGGER charassHistoryTrigger BEFORE INSERT OR UPDATE OR DELETE ON charass FOR EACH ROW EXECUTE PROCEDURE _charassHistoryTrigger();
+
diff --git a/foundation-database/public/trigger_functions/charopt.sql b/foundation-database/public/trigger_functions/charopt.sql
new file mode 100644 (file)
index 0000000..9ccd11d
--- /dev/null
@@ -0,0 +1,30 @@
+CREATE OR REPLACE FUNCTION _charoptTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (NOT checkPrivilege('MaintainCharacteristics')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Characteristic options.';
+  END IF;
+
+  IF (TG_OP = 'UPDATE') THEN
+    UPDATE charass SET
+      charass_value = NEW.charopt_value
+    WHERE ((charass_char_id=NEW.charopt_char_id)
+      AND (charass_value=OLD.charopt_value));
+  END IF;
+
+  IF (TG_OP = 'DELETE') THEN
+    IF (SELECT (count(charass_id) > 0)
+        FROM charass
+        WHERE ((charass_char_id=OLD.charopt_char_id)
+         AND (charass_value=OLD.charopt_value))) THEN
+       RAISE EXCEPTION 'This characteristic option value is in use and can not be deleted.';
+    END IF;
+  END IF;
+  
+  RETURN NEW;
+END;
+$$      LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'charoptTrigger');
+CREATE TRIGGER charoptTrigger AFTER UPDATE OR DELETE ON charopt FOR EACH ROW EXECUTE PROCEDURE _charoptTrigger();
diff --git a/foundation-database/public/trigger_functions/checkhead.sql b/foundation-database/public/trigger_functions/checkhead.sql
new file mode 100644 (file)
index 0000000..2bddec9
--- /dev/null
@@ -0,0 +1,50 @@
+CREATE OR REPLACE FUNCTION _checkheadBeforeTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE 
+  _amount NUMERIC;
+  _currrate NUMERIC;
+
+BEGIN
+
+-- get the base exchange rate for the check date
+  IF (TG_OP = 'INSERT' AND NEW.checkhead_curr_rate IS NULL) THEN
+    SELECT curr_rate INTO _currrate
+    FROM curr_rate
+    WHERE ( (NEW.checkhead_curr_id=curr_id)
+      AND ( NEW.checkhead_checkdate BETWEEN curr_effective 
+                                   AND curr_expires) );
+    IF (FOUND) THEN
+      NEW.checkhead_curr_rate := _currrate;
+    ELSE
+      RAISE EXCEPTION 'Currency exchange rate not found';
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'INSERT' OR TG_OP = 'UPDATE') THEN
+    IF (NOT EXISTS (SELECT checkrecip_id
+                   FROM checkrecip
+                   WHERE ((checkrecip_type=NEW.checkhead_recip_type)
+                     AND  (checkrecip_id=NEW.checkhead_recip_id)) )) THEN
+      RAISE EXCEPTION 'Cannot verify recipient for check % (type %  id %)',
+                     NEW.checkhead_number, NEW.checkhead_recip_type,
+                     NEW.checkhead_recip_id;
+    END IF;
+
+    IF (NEW.checkhead_journalnumber IS NOT NULL
+        AND NOT EXISTS (SELECT jrnluse_number
+                       FROM jrnluse
+                       WHERE (jrnluse_number=NEW.checkhead_journalnumber))
+       ) THEN
+      RAISE EXCEPTION 'Journal Number % does not exist and cannot be used for check %.',
+                     NEW.checkhead_journalnumber, NEW.checkhead_number;
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'checkheadBeforeTrigger');
+CREATE TRIGGER checkheadBeforeTrigger BEFORE INSERT OR UPDATE ON checkhead FOR EACH ROW EXECUTE PROCEDURE _checkheadBeforeTrigger();
+
diff --git a/foundation-database/public/trigger_functions/cmhead.sql b/foundation-database/public/trigger_functions/cmhead.sql
new file mode 100644 (file)
index 0000000..19410cc
--- /dev/null
@@ -0,0 +1,161 @@
+CREATE OR REPLACE FUNCTION _cmheadBeforeTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _check BOOLEAN;
+  _id INTEGER;
+BEGIN
+  -- Checks
+  -- Start with privileges
+  SELECT checkPrivilege('MaintainCreditMemos') INTO _check;
+  IF ( (TG_OP = 'INSERT') OR (TG_OP = 'DELETE') ) THEN
+    IF NOT (_check) THEN
+      RAISE EXCEPTION 'You do not have privileges to maintain Credit Memos.';
+    END IF;
+  END IF;
+  IF (TG_OP = 'UPDATE') THEN
+    IF ((OLD.cmhead_printed = NEW.cmhead_printed) AND NOT (_check) ) THEN
+      RAISE EXCEPTION 'You do not have privileges to maintain Credit Memos.';
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'DELETE') THEN
+    DELETE FROM cmheadtax
+    WHERE (taxhist_parent_id=OLD.cmhead_id);
+
+    RETURN OLD;
+  END IF;
+
+  IF ( (NEW.cmhead_number IS NULL) OR (LENGTH(NEW.cmhead_number) = 0) ) THEN
+    RAISE EXCEPTION 'You must enter a valid Memo # for this Credit Memo.';
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    SELECT cmhead_id INTO _id
+    FROM cmhead
+    WHERE (cmhead_number=NEW.cmhead_number);
+    IF (FOUND) THEN
+      RAISE EXCEPTION 'The Memo # is already in use.';
+    END IF;
+
+    IF (fetchMetricText('CMNumberGeneration') IN ('A','O')) THEN
+      --- clear the number from the issue cache
+      PERFORM clearNumberIssue('CmNumber', NEW.cmhead_number);
+    ELSIF (fetchMetricText('CMNumberGeneration') = 'S') THEN
+      --- clear the number from the issue cache
+      PERFORM clearNumberIssue('SoNumber', NEW.cmhead_number);
+    END IF;
+  END IF;
+
+  IF (NEW.cmhead_cust_id IS NOT NULL) THEN
+    SELECT cust_id INTO _id
+    FROM custinfo
+    WHERE (cust_id=NEW.cmhead_cust_id);
+    IF (NOT FOUND) THEN
+      RAISE EXCEPTION 'You must enter a valid Customer # for this Credit Memo.';
+    END IF;
+  END IF;
+
+  IF ( (NEW.cmhead_misc > 0) AND (NEW.cmhead_misc_accnt_id = -1) ) THEN
+    RAISE EXCEPTION 'You may not enter a Misc. Charge without indicating the G/L Sales Account.';
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'cmheadbeforetrigger');
+CREATE TRIGGER cmheadbeforetrigger
+  BEFORE INSERT OR UPDATE OR DELETE
+  ON cmhead
+  FOR EACH ROW
+  EXECUTE PROCEDURE _cmheadBeforeTrigger();
+
+
+CREATE OR REPLACE FUNCTION _cmheadTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    -- If this was created by a return, then reset the return
+    IF (OLD.cmhead_rahead_id IS NOT NULL) THEN
+      UPDATE rahead SET
+        rahead_headcredited=false
+      WHERE (rahead_id=OLD.cmhead_rahead_id);
+      DELETE FROM rahist
+      WHERE ((rahist_rahead_id=OLD.cmhead_rahead_id)
+      AND (rahist_source='CM')
+      AND (rahist_source_id=OLD.cmhead_id));
+    END IF;
+    RETURN OLD;
+  END IF;
+
+-- Insert new row
+  IF (TG_OP = 'INSERT') THEN
+
+  -- Calculate Freight Tax
+    IF (NEW.cmhead_freight <> 0) THEN
+      PERFORM calculateTaxHist( 'cmheadtax',
+                                NEW.cmhead_id,
+                                NEW.cmhead_taxzone_id,
+                                getFreightTaxtypeId(),
+                                NEW.cmhead_docdate,
+                                NEW.cmhead_curr_id,
+                                NEW.cmhead_freight * -1 );
+    END IF;
+  END IF;
+
+-- Update row
+  IF (TG_OP = 'UPDATE') THEN
+
+    IF ( (NEW.cmhead_freight <> OLD.cmhead_freight) OR
+         (COALESCE(NEW.cmhead_taxzone_id,-1) <> COALESCE(OLD.cmhead_taxzone_id,-1)) OR
+         (NEW.cmhead_docdate <> OLD.cmhead_docdate) OR
+         (NEW.cmhead_curr_id <> OLD.cmhead_curr_id) ) THEN
+  -- Calculate cmhead Tax
+      PERFORM calculateTaxHist( 'cmheadtax',
+                                NEW.cmhead_id,
+                                NEW.cmhead_taxzone_id,
+                                getFreightTaxtypeId(),
+                                NEW.cmhead_docdate,
+                                NEW.cmhead_curr_id,
+                                NEW.cmhead_freight * -1 );
+    END IF;
+
+    IF ( (COALESCE(NEW.cmhead_taxzone_id,-1) <> COALESCE(OLD.cmhead_taxzone_id,-1)) OR
+         (NEW.cmhead_docdate <> OLD.cmhead_docdate) OR
+         (NEW.cmhead_curr_id <> OLD.cmhead_curr_id) ) THEN
+  -- Calculate cmitem Tax
+      IF (COALESCE(NEW.cmhead_taxzone_id,-1) <> COALESCE(OLD.cmhead_taxzone_id,-1)) THEN
+    -- Cmitem trigger will calculate tax
+        UPDATE cmitem SET cmitem_taxtype_id=getItemTaxType(itemsite_item_id,NEW.cmhead_taxzone_id)
+        FROM itemsite 
+        WHERE ((itemsite_id=cmitem_itemsite_id)
+          AND (cmitem_cmhead_id=NEW.cmhead_id));
+      ELSE
+        PERFORM calculateTaxHist( 'cmitemtax',
+                                  cmitem_id,
+                                  NEW.cmhead_taxzone_id,
+                                  cmitem_taxtype_id,
+                                  NEW.cmhead_docdate,
+                                  NEW.cmhead_curr_id,
+                                  (cmitem_qtycredit * cmitem_qty_invuomratio) *
+                                  (cmitem_unitprice / cmitem_price_invuomratio) * -1)
+        FROM cmitem
+        WHERE (cmitem_cmhead_id = NEW.cmhead_id);
+      END IF;
+    END IF;
+
+  END IF;
+
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'cmheadtrigger');
+CREATE TRIGGER cmheadtrigger
+  AFTER INSERT OR UPDATE OR DELETE
+  ON cmhead
+  FOR EACH ROW
+  EXECUTE PROCEDURE _cmheadTrigger();
diff --git a/foundation-database/public/trigger_functions/cmitem.sql b/foundation-database/public/trigger_functions/cmitem.sql
new file mode 100644 (file)
index 0000000..710f17c
--- /dev/null
@@ -0,0 +1,120 @@
+CREATE OR REPLACE FUNCTION _cmitemBeforeTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _check BOOLEAN;
+  _id INTEGER;
+BEGIN
+  -- Checks
+  -- Start with privileges
+  SELECT checkPrivilege('MaintainCreditMemos') INTO _check;
+  IF NOT (_check) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Credit Memos.';
+  END IF;
+
+  IF (TG_OP = 'DELETE') THEN
+    DELETE FROM cmitemtax
+    WHERE (taxhist_parent_id=OLD.cmitem_id);
+
+    RETURN OLD;
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    IF ( (NEW.cmitem_qtycredit IS NULL) OR (NEW.cmitem_qtycredit = 0) ) THEN
+      RAISE EXCEPTION 'Quantity to Credit must be greater than zero.';
+    END IF;
+    SELECT cmitem_id INTO _id
+    FROM cmitem
+    WHERE ( (cmitem_cmhead_id=NEW.cmitem_cmhead_id) AND (cmitem_linenumber=NEW.cmitem_linenumber) );
+    IF (FOUND) THEN
+      RAISE EXCEPTION 'The Memo Line Number is already in use.';
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'cmitembeforetrigger');
+CREATE TRIGGER cmitembeforetrigger
+  BEFORE INSERT OR UPDATE OR DELETE
+  ON cmitem
+  FOR EACH ROW
+  EXECUTE PROCEDURE _cmitemBeforeTrigger();
+
+
+CREATE OR REPLACE FUNCTION _cmitemTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _ext NUMERIC;
+  _r RECORD;
+
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+
+--  If this was created by a return, reset return values
+    IF (OLD.cmitem_raitem_id) IS NOT NULL THEN
+      _ext := ROUND((OLD.cmitem_qtycredit * OLD.cmitem_qty_invuomratio) *  (OLD.cmitem_unitprice / OLD.cmitem_price_invuomratio),2);
+      UPDATE raitem SET
+        raitem_status = 'O',
+        raitem_qtycredited = raitem_qtycredited-OLD.cmitem_qtycredit,
+        raitem_amtcredited = raitem_amtcredited-_ext
+      WHERE (raitem_id=OLD.cmitem_raitem_id);
+    END IF;
+    RETURN OLD;
+  END IF;
+
+-- Cache Credit Memo Head
+  SELECT * INTO _r
+  FROM cmhead
+  WHERE (cmhead_id=NEW.cmitem_cmhead_id);
+  IF (NOT FOUND) THEN
+    RAISE EXCEPTION 'Credit Memo head not found';
+  END IF;
+
+-- Insert new row
+  IF (TG_OP = 'INSERT') THEN
+
+  -- Calculate Tax
+      PERFORM calculateTaxHist( 'cmitemtax',
+                                NEW.cmitem_id,
+                                COALESCE(_r.cmhead_taxzone_id, -1),
+                                NEW.cmitem_taxtype_id,
+                                COALESCE(_r.cmhead_docdate, CURRENT_DATE),
+                                COALESCE(_r.cmhead_curr_id, -1),
+                                (NEW.cmitem_qtycredit * NEW.cmitem_qty_invuomratio) *
+                                (NEW.cmitem_unitprice / NEW.cmitem_price_invuomratio) * -1);
+  END IF;
+
+-- Update row
+  IF (TG_OP = 'UPDATE') THEN
+
+  -- Calculate Tax
+    IF ( (NEW.cmitem_qtycredit <> OLD.cmitem_qtycredit) OR
+         (NEW.cmitem_qty_invuomratio <> OLD.cmitem_qty_invuomratio) OR
+         (NEW.cmitem_unitprice <> OLD.cmitem_unitprice) OR
+         (NEW.cmitem_price_invuomratio <> OLD.cmitem_price_invuomratio) OR
+         (COALESCE(NEW.cmitem_taxtype_id, -1) <> COALESCE(OLD.cmitem_taxtype_id, -1)) ) THEN
+      PERFORM calculateTaxHist( 'cmitemtax',
+                                NEW.cmitem_id,
+                                COALESCE(_r.cmhead_taxzone_id, -1),
+                                NEW.cmitem_taxtype_id,
+                                COALESCE(_r.cmhead_docdate, CURRENT_DATE),
+                                COALESCE(_r.cmhead_curr_id, -1),
+                                (NEW.cmitem_qtycredit * NEW.cmitem_qty_invuomratio) *
+                                (NEW.cmitem_unitprice / NEW.cmitem_price_invuomratio) * -1);
+    END IF;
+  END IF;
+
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'cmitemtrigger');
+CREATE TRIGGER cmitemtrigger
+  AFTER INSERT OR UPDATE OR DELETE
+  ON cmitem
+  FOR EACH ROW
+  EXECUTE PROCEDURE _cmitemTrigger();
diff --git a/foundation-database/public/trigger_functions/cntct.sql b/foundation-database/public/trigger_functions/cntct.sql
new file mode 100644 (file)
index 0000000..4dd524e
--- /dev/null
@@ -0,0 +1,138 @@
+-- Before trigger
+CREATE OR REPLACE FUNCTION _cntctTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+  NEW.cntct_name := formatCntctName(NULL, NEW.cntct_first_name, NEW.cntct_middle, NEW.cntct_last_name, NEW.cntct_suffix);
+  NEW.cntct_email := lower(NEW.cntct_email);
+
+  IF (TG_OP = 'INSERT') THEN
+    --- clear the number from the issue cache
+    PERFORM clearNumberIssue('ContactNumber', NEW.cntct_number);
+  END IF;
+  
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'cntctTrigger');
+CREATE TRIGGER cntcttrigger
+  BEFORE INSERT OR UPDATE
+  ON cntct
+  FOR EACH ROW
+  EXECUTE PROCEDURE _cntctTrigger();
+
+CREATE OR REPLACE FUNCTION _cntctTriggerBeforeDelete() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    DELETE FROM cntctaddr WHERE cntctaddr_cntct_id=OLD.cntct_id;
+    DELETE FROM cntctdata WHERE cntctdata_cntct_id=OLD.cntct_id;
+    DELETE FROM cntcteml  WHERE cntcteml_cntct_id=OLD.cntct_id;
+    DELETE FROM docass WHERE docass_source_id = OLD.cntct_id AND docass_source_type = 'T';
+    DELETE FROM docass WHERE docass_target_id = OLD.cntct_id AND docass_target_type = 'T';
+
+    -- these have denormalized cntct info so it should be ok to update them
+    UPDATE cohead SET cohead_billto_cntct_id=NULL
+     WHERE cohead_billto_cntct_id=OLD.cntct_id;
+    UPDATE cohead SET cohead_shipto_cntct_id=NULL
+     WHERE cohead_shipto_cntct_id=OLD.cntct_id;
+
+    UPDATE pohead SET pohead_vend_cntct_id=NULL
+     WHERE pohead_vend_cntct_id=OLD.cntct_id;
+    UPDATE pohead SET pohead_shipto_cntct_id=NULL
+     WHERE pohead_shipto_cntct_id=OLD.cntct_id;
+
+    UPDATE quhead SET quhead_billto_cntct_id=NULL
+     WHERE quhead_billto_cntct_id=OLD.cntct_id;
+    UPDATE quhead SET quhead_shipto_cntct_id=NULL
+     WHERE quhead_shipto_cntct_id=OLD.cntct_id;
+
+    IF (fetchMetricBool('MultiWhs')) THEN
+      UPDATE tohead SET tohead_destcntct_id=NULL
+       WHERE tohead_destcntct_id=OLD.cntct_id;
+      UPDATE tohead SET tohead_srccntct_id=NULL
+       WHERE tohead_srccntct_id=OLD.cntct_id;
+    END IF;
+
+  END IF;
+  RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'cntctTriggerBeforeDelete');
+CREATE TRIGGER cntcttriggerbeforedelete
+  BEFORE DELETE
+  ON cntct
+  FOR EACH ROW
+  EXECUTE PROCEDURE _cntctTriggerBeforeDelete();
+
+-- After trigger
+CREATE OR REPLACE FUNCTION _cntctTriggerAfter() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cntctemlid INTEGER;
+  _rows INTEGER;
+BEGIN
+  IF (TG_OP = 'INSERT') THEN
+    IF(length(coalesce(NEW.cntct_email,'')) > 0) THEN
+      INSERT INTO cntcteml (
+        cntcteml_cntct_id, cntcteml_primary, cntcteml_email )
+      VALUES (
+        NEW.cntct_id, true, NEW.cntct_email );
+    END IF;
+    PERFORM postComment('ChangeLog', 'T', NEW.cntct_id,
+                        ('Created by ' || getEffectiveXtUser()));
+  ELSIF (TG_OP = 'UPDATE') THEN
+    IF (OLD.cntct_email != NEW.cntct_email) THEN
+      SELECT cntcteml_id INTO _cntctemlid
+      FROM cntcteml
+      WHERE ((cntcteml_cntct_id=NEW.cntct_id)
+        AND (cntcteml_email=NEW.cntct_email));
+
+      GET DIAGNOSTICS _rows = ROW_COUNT;
+      IF (_rows = 0) THEN
+        UPDATE cntcteml SET
+          cntcteml_primary=false
+        WHERE ((cntcteml_cntct_id=NEW.cntct_id)
+         AND (cntcteml_primary=true));
+       
+        INSERT INTO cntcteml (
+          cntcteml_cntct_id, cntcteml_primary, cntcteml_email )
+        VALUES (
+          NEW.cntct_id, true, NEW.cntct_email ); 
+      ELSE
+        UPDATE cntcteml SET
+          cntcteml_primary=false
+        WHERE ((cntcteml_cntct_id=NEW.cntct_id)
+         AND (cntcteml_primary=true));
+
+        UPDATE cntcteml SET
+          cntcteml_primary=true
+        WHERE (cntcteml_id=_cntctemlid);
+      END IF;
+    END IF;
+  ELSIF (TG_OP = 'DELETE') THEN
+      DELETE FROM comment
+       WHERE (comment_source_id=OLD.cntct_id AND comment_source = 'T');
+      DELETE FROM docass
+       WHERE (docass_source_id=OLD.cntct_id AND docass_source_type = 'T')
+          OR (docass_target_id=OLD.cntct_id AND docass_target_type = 'T');
+      
+      RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'cntctTriggerAfter');
+CREATE TRIGGER cntcttriggerafter
+  AFTER INSERT OR UPDATE OR DELETE
+  ON cntct
+  FOR EACH ROW
+  EXECUTE PROCEDURE _cntctTriggerAfter();
+
diff --git a/foundation-database/public/trigger_functions/cntslip.sql b/foundation-database/public/trigger_functions/cntslip.sql
new file mode 100644 (file)
index 0000000..70aff67
--- /dev/null
@@ -0,0 +1,61 @@
+CREATE OR REPLACE FUNCTION _cntslipTrigger() RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _p RECORD;
+  _comments TEXT;
+  _temp TEXT;
+
+BEGIN
+  IF (TG_OP = ''DELETE'') THEN
+    SELECT itemsite_loccntrl, itemsite_controlmethod,
+           cntslip_posted, cntslip_lotserial, cntslip_comments,
+           cntslip_number, cntslip_qty INTO _p
+      FROM cntslip, invcnt, itemsite
+     WHERE ( (cntslip_cnttag_id=invcnt_id)
+       AND   (invcnt_itemsite_id=itemsite_id)
+       AND   (cntslip_id=OLD.cntslip_id) );
+
+    IF(_p.cntslip_posted) THEN
+      SELECT ( ''
+Count Slip #'' || _p.cntslip_number ||
+             '' deleted '' || formatQty(_p.cntslip_qty) ) INTO _comments;
+
+--  Add the Location name if the itemsite is MLC
+      IF (_p.itemsite_loccntrl) THEN
+        SELECT ( '', Location:'' || location_name ) INTO _temp
+          FROM location, cntslip
+         WHERE ( (cntslip_location_id=location_id)
+           AND   (cntslip_id=OLD.cntslip_id) );
+  
+        _comments := (_comments || _temp);
+      END IF;
+  
+--  Add the Lot/Serial if the itemsite is Lot or Serial controlled
+      IF (_p.itemsite_controlmethod = ''L'') THEN
+        _comments := (_comments || ( '', Lot #:'' || _p.cntslip_lotserial));
+      ELSIF (_p.itemsite_controlmethod = ''S'') THEN
+        _comments := (_comments || ( '', Serial #:'' || _p.cntslip_lotserial));
+      END IF;
+  
+      _comments := (_comments || '' '' || _p.cntslip_comments);
+  
+      UPDATE invcnt
+         SET invcnt_qoh_after = ( COALESCE(invcnt_qoh_after, 0) - cntslip_qty),
+             invcnt_comments = (invcnt_comments || _comments)
+        FROM cntslip
+       WHERE ( (cntslip_cnttag_id=invcnt_id)
+         AND   (NOT invcnt_posted)
+         AND   (cntslip_id=OLD.cntslip_id) );
+
+    END IF;
+
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+' LANGUAGE 'plpgsql';
+
+DROP TRIGGER cntslipTrigger ON cntslip;
+CREATE TRIGGER cntslipTrigger BEFORE INSERT OR UPDATE OR DELETE ON cntslip FOR EACH ROW EXECUTE PROCEDURE _cntslipTrigger();
diff --git a/foundation-database/public/trigger_functions/cobill.sql b/foundation-database/public/trigger_functions/cobill.sql
new file mode 100644 (file)
index 0000000..032d63a
--- /dev/null
@@ -0,0 +1,88 @@
+CREATE OR REPLACE FUNCTION _cobillBeforeTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    DELETE FROM cobilltax
+    WHERE (taxhist_parent_id=OLD.cobill_id);
+
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'cobillBeforeTrigger');
+CREATE TRIGGER cobillBeforeTrigger
+  BEFORE INSERT OR UPDATE OR DELETE
+  ON cobill
+  FOR EACH ROW
+  EXECUTE PROCEDURE _cobillBeforeTrigger();
+
+CREATE OR REPLACE FUNCTION _cobillTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _r RECORD;
+
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+-- Cache Billing Head
+  SELECT * INTO _r
+  FROM cobmisc
+  WHERE (cobmisc_id=NEW.cobill_cobmisc_id);
+  IF (NOT FOUND) THEN
+    RAISE EXCEPTION 'Billing head not found';
+  END IF;
+
+-- Insert new row
+  IF (TG_OP = 'INSERT') THEN
+
+  -- Calculate Tax
+      PERFORM calculateTaxHist( 'cobilltax',
+                                NEW.cobill_id,
+                                COALESCE(_r.cobmisc_taxzone_id, -1),
+                                NEW.cobill_taxtype_id,
+                                COALESCE(_r.cobmisc_shipdate, CURRENT_DATE),
+                                COALESCE(_r.cobmisc_curr_id, -1),
+                                (NEW.cobill_qty * coitem_qty_invuomratio) *
+                                (coitem_price / coitem_price_invuomratio) )
+      FROM coitem
+      WHERE (coitem_id=NEW.cobill_coitem_id);
+  END IF;
+
+-- Update row
+  IF (TG_OP = 'UPDATE') THEN
+
+  -- Calculate Tax
+    IF ( (NEW.cobill_qty <> OLD.cobill_qty) OR
+         (NEW.cobill_taxtype_id <> OLD.cobill_taxtype_id) ) THEN
+      PERFORM calculateTaxHist( 'cobilltax',
+                                NEW.cobill_id,
+                                COALESCE(_r.cobmisc_taxzone_id, -1),
+                                NEW.cobill_taxtype_id,
+                                COALESCE(_r.cobmisc_shipdate, CURRENT_DATE),
+                                COALESCE(_r.cobmisc_curr_id, -1),
+                                (NEW.cobill_qty * coitem_qty_invuomratio) *
+                                (coitem_price / coitem_price_invuomratio) )
+      FROM coitem
+      WHERE (coitem_id=NEW.cobill_coitem_id);
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'cobilltrigger');
+CREATE TRIGGER cobilltrigger
+  AFTER INSERT OR UPDATE OR DELETE
+  ON cobill
+  FOR EACH ROW
+  EXECUTE PROCEDURE _cobillTrigger();
diff --git a/foundation-database/public/trigger_functions/cobmisc.sql b/foundation-database/public/trigger_functions/cobmisc.sql
new file mode 100644 (file)
index 0000000..3e3e7c3
--- /dev/null
@@ -0,0 +1,94 @@
+CREATE OR REPLACE FUNCTION _cobmiscBeforeTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    DELETE FROM cobmisctax
+    WHERE (taxhist_parent_id=OLD.cobmisc_id);
+
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'cobmiscBeforeTrigger');
+CREATE TRIGGER cobmiscBeforeTrigger
+  BEFORE INSERT OR UPDATE OR DELETE
+  ON cobmisc
+  FOR EACH ROW
+  EXECUTE PROCEDURE _cobmiscBeforeTrigger();
+
+CREATE OR REPLACE FUNCTION _cobmiscTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    -- Something can go here
+    RETURN OLD;
+  END IF;
+
+-- Insert new row
+  IF (TG_OP = 'INSERT') THEN
+
+  -- Calculate Freight Tax
+    IF (NEW.cobmisc_freight <> 0) THEN
+      PERFORM calculateTaxHist( 'cobmisctax',
+                                NEW.cobmisc_id,
+                                NEW.cobmisc_taxzone_id,
+                                getFreightTaxtypeId(),
+                                NEW.cobmisc_invcdate,
+                                NEW.cobmisc_curr_id,
+                                NEW.cobmisc_freight );
+    END IF;
+  END IF;
+
+-- Update row
+  IF (TG_OP = 'UPDATE') THEN
+
+  -- Calculate Tax
+    IF (COALESCE(NEW.cobmisc_taxzone_id,-1) <> COALESCE(OLD.cobmisc_taxzone_id,-1)) THEN
+      UPDATE cobill SET cobill_taxtype_id=getItemTaxType(itemsite_item_id,NEW.cobmisc_taxzone_id)
+      FROM coitem
+        JOIN itemsite ON (coitem_itemsite_id=itemsite_id)
+      WHERE ((coitem_id=cobill_coitem_id)
+       AND (cobill_cobmisc_id=NEW.cobmisc_id));
+    END IF;
+    
+    IF ( (NEW.cobmisc_freight <> OLD.cobmisc_freight) OR
+         (COALESCE(NEW.cobmisc_taxzone_id,-1) <> COALESCE(OLD.cobmisc_taxzone_id,-1)) OR
+         (NEW.cobmisc_invcdate <> OLD.cobmisc_invcdate) OR
+         (NEW.cobmisc_curr_id <> OLD.cobmisc_curr_id) ) THEN
+      PERFORM calculateTaxHist( 'cobmisctax',
+                                NEW.cobmisc_id,
+                                NEW.cobmisc_taxzone_id,
+                                getFreightTaxtypeId(),
+                                NEW.cobmisc_invcdate,
+                                NEW.cobmisc_curr_id,
+                                NEW.cobmisc_freight );
+      PERFORM calculateTaxHist( 'cobilltax',
+                                cobill_id,
+                                NEW.cobmisc_taxzone_id,
+                                cobill_taxtype_id,
+                                NEW.cobmisc_invcdate,
+                                NEW.cobmisc_curr_id,
+                                (cobill_qty * coitem_qty_invuomratio) *
+                                (coitem_price / coitem_price_invuomratio) )
+      FROM cobill JOIN coitem ON (coitem_id = cobill_coitem_id)
+      WHERE (cobill_cobmisc_id = NEW.cobmisc_id);
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'cobmisctrigger');
+CREATE TRIGGER cobmisctrigger
+  AFTER INSERT OR UPDATE OR DELETE
+  ON cobmisc
+  FOR EACH ROW
+  EXECUTE PROCEDURE _cobmiscTrigger();
diff --git a/foundation-database/public/trigger_functions/cohead.sql b/foundation-database/public/trigger_functions/cohead.sql
new file mode 100644 (file)
index 0000000..c9848d7
--- /dev/null
@@ -0,0 +1,537 @@
+
+CREATE OR REPLACE FUNCTION _soheadTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _p RECORD;
+  _a RECORD;
+  _w RECORD;
+  _shiptoId INTEGER;
+  _addrId INTEGER;
+  _prjId INTEGER;
+  _check BOOLEAN;
+  _numGen CHAR(1);
+
+BEGIN
+
+  -- Checks
+  -- Start with privileges
+  IF (TG_OP = 'INSERT') THEN
+    IF ( (NOT checkPrivilege('MaintainSalesOrders')) AND
+       (NOT checkPrivilege('EnterReceipts')) ) THEN
+      RAISE EXCEPTION 'You do not have privileges to create a Sales Order.';
+    END IF;
+  ELSIF (TG_OP = 'UPDATE') THEN
+    IF ( (NOT checkPrivilege('MaintainSalesOrders')) AND
+         (NOT checkPrivilege('IssueStockToShipping')) AND
+         (NEW.cohead_holdtype = OLD.cohead_holdtype) ) THEN
+      RAISE EXCEPTION 'You do not have privileges to alter a Sales Order.';
+    END IF;
+  ELSE
+    IF ( (NOT checkPrivilege('MaintainSalesOrders')) AND
+         (NOT checkPrivilege('IssueStockToShipping')) ) THEN
+      RAISE EXCEPTION 'You do not have privileges to alter a Sales Order.';
+    END IF;
+  END IF;
+
+  -- If this is imported, check the order number
+  IF (TG_OP = 'INSERT') THEN
+    IF (NEW.cohead_imported) THEN
+      SELECT fetchMetricText('CONumberGeneration') INTO _numGen;
+      IF ((NEW.cohead_number IS NULL) AND (_numGen='M')) THEN
+        RAISE EXCEPTION 'You must supply an Order Number.';
+      ELSE
+        IF (NEW.cohead_number IS NULL) THEN
+          SELECT fetchsonumber() INTO NEW.cohead_number;
+        END IF;
+      END IF;
+    END IF;
+
+    IF (fetchMetricText('CONumberGeneration') IN ('A','O')) THEN
+      --- clear the number from the issue cache
+      PERFORM clearNumberIssue('SoNumber', NEW.cohead_number);
+    END IF;
+  ELSE
+    IF (TG_OP = 'UPDATE') THEN
+      IF (NEW.cohead_number <> OLD.cohead_number) THEN
+        RAISE EXCEPTION 'The order number may not be changed.';
+      END IF;
+    END IF;
+  END IF;
+
+  IF (TG_OP IN ('INSERT','UPDATE')) THEN
+
+    -- Get Customer data
+    IF (NEW.cohead_shipto_id IS NULL) THEN
+      SELECT cust_creditstatus,cust_number,cust_usespos,cust_blanketpos,cust_ffbillto,
+            cust_ffshipto,cust_name,cust_salesrep_id,cust_terms_id,cust_shipvia,
+            cust_shipchrg_id,cust_shipform_id,cust_commprcnt,cust_curr_id,cust_taxzone_id,
+            cntct.*,addr.*,
+            shipto_id,shipto_addr_id,shipto_name,shipto_salesrep_id,shipto_shipvia,
+            shipto_shipchrg_id,shipto_shipform_id,shipto_commission,shipto_taxzone_id INTO _p
+      FROM custinfo
+        LEFT OUTER JOIN cntct ON (cust_cntct_id=cntct_id)
+        LEFT OUTER JOIN addr ON (cntct_addr_id=addr_id)
+        LEFT OUTER JOIN shiptoinfo ON ((cust_id=shipto_cust_id) AND shipto_default)
+      WHERE (cust_id=NEW.cohead_cust_id);
+    ELSE
+      SELECT cust_creditstatus,cust_number,cust_usespos,cust_blanketpos,cust_ffbillto,
+            cust_ffshipto,cust_name,cust_salesrep_id,cust_terms_id,cust_shipvia,
+            cust_shipchrg_id,cust_shipform_id,cust_commprcnt,cust_curr_id,cust_taxzone_id,
+            cntct.*,addr.*,
+            shipto_id,shipto_addr_id,shipto_name,shipto_salesrep_id,shipto_shipvia,
+            shipto_shipchrg_id,shipto_shipform_id,shipto_commission,shipto_taxzone_id INTO _p
+      FROM shiptoinfo,custinfo
+        LEFT OUTER JOIN cntct ON (cust_cntct_id=cntct_id)
+        LEFT OUTER JOIN addr ON (cntct_addr_id=addr_id)
+      WHERE ((cust_id=NEW.cohead_cust_id)
+        AND  (shipto_id=NEW.cohead_shipto_id));
+    END IF;
+
+    -- If there is customer data, then we can get to work
+    IF (FOUND) THEN
+
+      -- Check Credit
+      IF (TG_OP = 'INSERT') THEN
+          IF (_p.cust_creditstatus = 'H') THEN
+            SELECT checkPrivilege('CreateSOForHoldCustomer') INTO _check;
+            IF NOT (_check) THEN
+              RAISE EXCEPTION 'Customer % has been placed 
+                               on a Credit Hold and you do not have 
+                               privilege to create Sales Orders for 
+                               Customers on Credit Hold.  The selected 
+                               Customer must be taken off of Credit Hold 
+                               before you may create a new Sales Order 
+                               for the Customer.',_p.cust_number;
+            ELSE
+              NEW.cohead_holdtype='C';
+            END IF;
+          END IF;
+          IF (_p.cust_creditstatus = 'W') THEN
+            SELECT checkPrivilege('CreateSOForWarnCustomer') INTO _check;
+            IF NOT (_check) THEN
+              RAISE EXCEPTION 'Customer % has been placed on 
+                              a Credit Warning and you do not have 
+                              privilege to create Sales Orders for 
+                              Customers on Credit Warning.  The 
+                              selected Customer must be taken off of 
+                              Credit Warning before you may create a 
+                              new Sales Order for the Customer.',_p.cust_number;
+            ELSE
+              NEW.cohead_holdtype='C';
+            END IF;
+          END IF;
+
+          -- Set to defaults if values not provided
+          NEW.cohead_shipto_id         := COALESCE(NEW.cohead_shipto_id,_p.shipto_id);
+          NEW.cohead_terms_id          := COALESCE(NEW.cohead_terms_id,_p.cust_terms_id);
+          NEW.cohead_orderdate         := COALESCE(NEW.cohead_orderdate,current_date);
+          NEW.cohead_packdate          := COALESCE(NEW.cohead_packdate,NEW.cohead_orderdate);
+          NEW.cohead_curr_id           := COALESCE(NEW.cohead_curr_id,_p.cust_curr_id,basecurrid());
+          NEW.cohead_freight           := COALESCE(NEW.cohead_freight,0);
+          NEW.cohead_custponumber      := COALESCE(NEW.cohead_custponumber,'');
+          NEW.cohead_ordercomments     := COALESCE(NEW.cohead_ordercomments,'');
+          NEW.cohead_shipcomments      := COALESCE(NEW.cohead_shipcomments,'');
+          NEW.cohead_shiptophone       := COALESCE(NEW.cohead_shiptophone,'');
+          NEW.cohead_misc              := COALESCE(NEW.cohead_misc,0);
+          NEW.cohead_misc_descrip      := COALESCE(NEW.cohead_misc_descrip,'');
+          NEW.cohead_shipcomplete      := COALESCE(NEW.cohead_shipcomplete,false);
+
+          IF (_p.shipto_id IS NOT NULL) THEN -- Pull in over ride values
+           NEW.cohead_salesrep_id      := COALESCE(NEW.cohead_salesrep_id,_p.shipto_salesrep_id);
+           NEW.cohead_shipvia          := COALESCE(NEW.cohead_shipvia,_p.shipto_shipvia);
+           NEW.cohead_shipchrg_id      := COALESCE(NEW.cohead_shipchrg_id,_p.shipto_shipchrg_id);
+           NEW.cohead_shipform_id      := COALESCE(NEW.cohead_shipform_id,_p.shipto_shipform_id);
+           NEW.cohead_commission       := COALESCE(NEW.cohead_commission,_p.shipto_commission);
+           IF (NEW.cohead_taxzone_id=-1) THEN
+             NEW.cohead_taxzone_id     := NULL;
+           ELSE
+             NEW.cohead_taxzone_id     := COALESCE(NEW.cohead_taxzone_id,_p.shipto_taxzone_id);
+           END IF;
+         ELSE
+           NEW.cohead_salesrep_id      := COALESCE(NEW.cohead_salesrep_id,_p.cust_salesrep_id);
+           NEW.cohead_shipvia          := COALESCE(NEW.cohead_shipvia,_p.cust_shipvia);
+           NEW.cohead_shipchrg_id      := COALESCE(NEW.cohead_shipchrg_id,_p.cust_shipchrg_id);
+           NEW.cohead_shipform_id      := COALESCE(NEW.cohead_shipform_id,_p.cust_shipform_id);
+           NEW.cohead_commission       := COALESCE(NEW.cohead_commission,_p.cust_commprcnt);
+           IF (NEW.cohead_taxzone_id=-1) THEN
+             NEW.cohead_taxzone_id     := NULL;
+           ELSE
+             NEW.cohead_taxzone_id     := COALESCE(NEW.cohead_taxzone_id,_p.cust_taxzone_id);
+           END IF;
+          END IF;
+
+          IF ((NEW.cohead_warehous_id IS NULL) OR (NEW.cohead_fob IS NULL)) THEN
+            IF (NEW.cohead_warehous_id IS NULL) THEN
+              SELECT warehous_id,warehous_fob INTO _w
+              FROM usrpref, whsinfo
+              WHERE ((warehous_id=CAST(usrpref_value AS INTEGER))
+                AND (warehous_shipping)
+                AND (warehous_active)
+                AND (usrpref_username=getEffectiveXtUser())
+                AND (usrpref_name='PreferredWarehouse'));
+            ELSE
+              SELECT warehous_id,warehous_fob INTO _w
+              FROM whsinfo
+              WHERE (warehous_id=NEW.cohead_warehous_id);
+            END IF;
+            
+            IF (FOUND) THEN
+              NEW.cohead_warehous_id   := COALESCE(NEW.cohead_warehous_id,_w.warehous_id);
+              NEW.cohead_fob           := COALESCE(NEW.cohead_fob,_w.warehous_fob);
+            END IF;
+          END IF;
+          
+      END IF;
+
+      -- Only Check P/O logic for imports, because UI checks when entire order is saved
+      IF (NEW.cohead_imported) THEN
+
+        -- Check for required Purchase Order
+        IF (_p.cust_usespos AND ((NEW.cohead_custponumber IS NULL) OR (TRIM(BOTH FROM NEW.cohead_custponumber)=''))) THEN
+            RAISE EXCEPTION 'You must enter a Customer P/O for this Sales Order.';
+        END IF;
+        -- Check for duplicate Purchase Orders if not allowed
+        IF (_p.cust_usespos AND NOT (_p.cust_blanketpos)) THEN
+          SELECT cohead_id INTO _a
+          FROM cohead
+          WHERE ((cohead_cust_id=NEW.cohead_cust_id)
+          AND  (cohead_id<>NEW.cohead_id)
+          AND  (UPPER(cohead_custponumber) = UPPER(NEW.cohead_custponumber)) )
+          UNION
+          SELECT quhead_id
+          FROM quhead
+          WHERE ((quhead_cust_id=NEW.cohead_cust_id)
+          AND  (quhead_id<>NEW.cohead_id)
+          AND  (UPPER(quhead_custponumber) = UPPER(NEW.cohead_custponumber)) );
+          IF (FOUND) THEN
+           RAISE EXCEPTION 'This Customer does not use Blanket P/O
+                            Numbers and the P/O Number you entered has 
+                            already been used for another Sales Order.
+                            Please verify the P/O Number and either
+                            enter a new P/O Number or add to the
+                            existing Sales Order.';
+         END IF;
+        END IF;
+      END IF;
+
+      --Auto create project if applicable
+      IF ((TG_OP = 'INSERT') AND (COALESCE(NEW.cohead_prj_id,-1)=-1)) THEN
+        SELECT fetchMetricBool('AutoCreateProjectsForOrders') INTO _check;
+        IF (_check) THEN
+          SELECT NEXTVAL('prj_prj_id_seq') INTO _prjId;
+          NEW.cohead_prj_id := _prjId;
+          INSERT INTO prj (prj_id, prj_number, prj_name, prj_descrip,
+                           prj_status, prj_so, prj_wo, prj_po,
+                           prj_owner_username, prj_start_date, prj_due_date,
+                           prj_assigned_date, prj_completed_date, prj_username,
+                           prj_recurring_prj_id, prj_crmacct_id,
+                           prj_cntct_id, prj_prjtype_id)
+          SELECT _prjId, NEW.cohead_number, NEW.cohead_number, 'Auto Generated Project from Sales Order.',
+                 'O', TRUE, TRUE, TRUE,
+                 getEffectiveXTUser(), NEW.cohead_orderdate, NEW.cohead_packdate,
+                 NEW.cohead_orderdate, NULL, getEffectiveXTUser(),
+                 NULL, crmacct_id,
+                 NEW.cohead_billto_cntct_id, NULL
+          FROM crmacct
+          WHERE (crmacct_cust_id=NEW.cohead_cust_id);
+        END IF;
+      END IF;
+
+      IF (TG_OP = 'UPDATE') THEN
+        SELECT true INTO _check
+        FROM coitem
+        WHERE ( (coitem_status='C')
+        AND (coitem_cohead_id=NEW.cohead_id) ) 
+        LIMIT 1;
+
+        IF (NOT FOUND) THEN
+
+        --Update project references on supply
+        UPDATE pr SET pr_prj_id=NEW.cohead_prj_id
+                   FROM coitem
+                   WHERE ((coitem_cohead_id=NEW.cohead_id) 
+                   AND  (coitem_order_type='R') 
+                   AND  (coitem_order_id=pr_id));
+
+        PERFORM changeWoProject(coitem_order_id, NEW.cohead_prj_id, TRUE)
+                    FROM coitem
+                    WHERE ((coitem_cohead_id=NEW.cohead_id)
+                    AND  (coitem_order_type='W'));
+        ELSE
+          IF NEW.cohead_prj_id <> COALESCE(OLD.cohead_prj_id,-1) THEN
+            RAISE EXCEPTION 'You can not change the project ID on orders with closed lines.';
+          END IF;
+        END IF;
+      END IF;
+
+      -- Deal with Billing Address
+      IF (TG_OP = 'INSERT') THEN
+        IF (_p.cust_ffbillto) THEN
+          -- If they didn't supply data, we'll put in the bill to contact and address
+          NEW.cohead_billto_cntct_id=COALESCE(NEW.cohead_billto_cntct_id,_p.cntct_id);
+          NEW.cohead_billto_cntct_honorific=COALESCE(NEW.cohead_billto_cntct_honorific,_p.cntct_honorific,'');
+          NEW.cohead_billto_cntct_first_name=COALESCE(NEW.cohead_billto_cntct_first_name,_p.cntct_first_name,'');
+          NEW.cohead_billto_cntct_middle=COALESCE(NEW.cohead_billto_cntct_middle,_p.cntct_middle,'');    
+          NEW.cohead_billto_cntct_last_name=COALESCE(NEW.cohead_billto_cntct_last_name,_p.cntct_last_name,''); 
+          NEW.cohead_billto_cntct_phone=COALESCE(NEW.cohead_billto_cntct_phone,_p.cntct_phone,'');
+          NEW.cohead_billto_cntct_title=COALESCE(NEW.cohead_billto_cntct_title,_p.cntct_title,'');
+          NEW.cohead_billto_cntct_fax=COALESCE(NEW.cohead_billto_cntct_fax,_p.cntct_fax,''); 
+          NEW.cohead_billto_cntct_email=COALESCE(NEW.cohead_billto_cntct_email,_p.cntct_email,''); 
+          NEW.cohead_billtoname=COALESCE(NEW.cohead_billtoname,_p.cust_name,'');
+          NEW.cohead_billtoaddress1=COALESCE(NEW.cohead_billtoaddress1,_p.addr_line1,'');
+          NEW.cohead_billtoaddress2=COALESCE(NEW.cohead_billtoaddress2,_p.addr_line2,'');
+          NEW.cohead_billtoaddress3=COALESCE(NEW.cohead_billtoaddress3,_p.addr_line3,'');    
+          NEW.cohead_billtocity=COALESCE(NEW.cohead_billtocity,_p.addr_city,''); 
+          NEW.cohead_billtostate=COALESCE(NEW.cohead_billtostate,_p.addr_state,'');
+          NEW.cohead_billtozipcode=COALESCE(NEW.cohead_billtozipcode,_p.addr_postalcode,'');
+          NEW.cohead_billtocountry=COALESCE(NEW.cohead_billtocountry,_p.addr_country,'');   
+        ELSE
+          -- Free form not allowed, we're going to put in the address regardless
+          NEW.cohead_billto_cntct_id=_p.cntct_id;
+          NEW.cohead_billto_cntct_honorific=COALESCE(_p.cntct_honorific,'');
+          NEW.cohead_billto_cntct_first_name=COALESCE(_p.cntct_first_name,'');
+          NEW.cohead_billto_cntct_middle=COALESCE(_p.cntct_middle,'');    
+          NEW.cohead_billto_cntct_last_name=COALESCE(_p.cntct_last_name,''); 
+          NEW.cohead_billto_cntct_phone=COALESCE(_p.cntct_phone,'');
+          NEW.cohead_billto_cntct_title=COALESCE(_p.cntct_title,'');
+          NEW.cohead_billto_cntct_fax=COALESCE(_p.cntct_fax,''); 
+          NEW.cohead_billto_cntct_email=COALESCE(_p.cntct_email,''); 
+          NEW.cohead_billtoname=COALESCE(_p.cust_name,'');
+          NEW.cohead_billtoaddress1=COALESCE(_p.addr_line1,'');
+          NEW.cohead_billtoaddress2=COALESCE(_p.addr_line2,'');
+          NEW.cohead_billtoaddress3=COALESCE(_p.addr_line3,'');    
+          NEW.cohead_billtocity=COALESCE(_p.addr_city,''); 
+          NEW.cohead_billtostate=COALESCE(_p.addr_state,'');
+          NEW.cohead_billtozipcode=COALESCE(_p.addr_postalcode,'');
+          NEW.cohead_billtocountry=COALESCE(_p.addr_country,'');
+        END IF;
+      END IF;
+
+      -- Now let's look at Shipto Address
+      -- If there's nothing in the address fields and there is a shipto id 
+      -- or there is a default address available, let's put in some shipto address data
+      IF ((TG_OP = 'INSERT') 
+        AND NOT ((NEW.cohead_shipto_id IS NULL) AND NOT _p.cust_ffshipto)
+        AND (NEW.cohead_shipto_cntct_id IS NULL)
+        AND (NEW.cohead_shipto_cntct_honorific IS NULL)
+        AND (NEW.cohead_shipto_cntct_first_name IS NULL)
+        AND (NEW.cohead_shipto_cntct_middle IS NULL)
+        AND (NEW.cohead_shipto_cntct_last_name IS NULL)
+        AND (NEW.cohead_shipto_cntct_suffix IS NULL)
+        AND (NEW.cohead_shipto_cntct_phone IS NULL)
+        AND (NEW.cohead_shipto_cntct_title IS NULL)
+        AND (NEW.cohead_shipto_cntct_fax IS NULL)
+        AND (NEW.cohead_shipto_cntct_email IS NULL)
+        AND (NEW.cohead_shiptoname IS NULL)
+        AND (NEW.cohead_shiptoaddress1 IS NULL)
+        AND (NEW.cohead_shiptoaddress2 IS NULL)
+        AND (NEW.cohead_shiptoaddress3 IS NULL)
+        AND (NEW.cohead_shiptocity IS NULL)
+        AND (NEW.cohead_shiptostate IS NULL)
+        AND (NEW.cohead_shiptocountry IS NULL)) THEN
+        IF ((NEW.cohead_shipto_id IS NULL) AND (_p.shipto_id IS NOT NULL)) THEN
+          _shiptoId := _p.shipto_addr_id;
+        ELSE
+          _shiptoId := NEW.cohead_shipto_id;
+        END IF;
+
+        SELECT * INTO _a 
+        FROM shiptoinfo
+          LEFT OUTER JOIN addr ON (addr_id=shipto_addr_id)
+          LEFT OUTER JOIN cntct ON (cntct_id=shipto_cntct_id)
+        WHERE (shipto_id=_shiptoId);
+
+        NEW.cohead_shipto_cntct_id := _a.cntct_id;
+        NEW.cohead_shipto_cntct_honorific := COALESCE(_a.cntct_honorific,'');
+        NEW.cohead_shipto_cntct_first_name := COALESCE(_a.cntct_first_name,'');
+        NEW.cohead_shipto_cntct_middle := COALESCE(_a.cntct_middle,'');
+        NEW.cohead_shipto_cntct_last_name := COALESCE(_a.cntct_last_name,'');
+       NEW.cohead_shipto_cntct_suffix := COALESCE(_a.cntct_suffix,'');
+       NEW.cohead_shipto_cntct_phone := COALESCE(_a.cntct_phone,'');
+       NEW.cohead_shipto_cntct_title := COALESCE(_a.cntct_title,'');
+       NEW.cohead_shipto_cntct_fax := COALESCE(_a.cntct_fax,'');
+       NEW.cohead_shipto_cntct_email := COALESCE(_a.cntct_email,'');
+        NEW.cohead_shiptoname := COALESCE(_p.shipto_name,'');
+        NEW.cohead_shiptoaddress1 := COALESCE(_a.addr_line1,'');
+        NEW.cohead_shiptoaddress2 := COALESCE(_a.addr_line2,'');
+        NEW.cohead_shiptoaddress3 := COALESCE(_a.addr_line3,'');    
+        NEW.cohead_shiptocity := COALESCE(_a.addr_city,''); 
+        NEW.cohead_shiptostate := COALESCE(_a.addr_state,'');
+        NEW.cohead_shiptozipcode := COALESCE(_a.addr_postalcode,'');
+        NEW.cohead_shiptocountry := COALESCE(_a.addr_country,'');
+      ELSE
+        IF (_p.cust_ffshipto) THEN
+          -- Use Address Save function to see if the new address entered matches
+          -- data for the shipto number.  If not that will insert new address for CRM
+          SELECT SaveAddr(
+            NULL,
+            NULL,
+            NEW.cohead_shiptoaddress1,
+            NEW.cohead_shiptoaddress2,
+            NEW.cohead_shiptoaddress3,
+            NEW.cohead_shiptocity,
+            NEW.cohead_shiptostate,
+            NEW.cohead_shiptozipcode,
+            NEW.cohead_shiptocountry,
+            'CHANGEONE') INTO _addrId;
+          SELECT shipto_addr_id INTO _shiptoid FROM shiptoinfo WHERE (shipto_id=NEW.cohead_shipto_id);
+          -- If the address passed doesn't match shipto address, then it's something else
+          IF (_shiptoid <> _addrId) THEN
+            NEW.cohead_shipto_id := NULL;
+          END IF;
+        ELSE
+          SELECT cohead_shipto_id INTO _shiptoid FROM cohead WHERE (cohead_id=NEW.cohead_id);
+          -- Get the shipto address
+          IF (COALESCE(NEW.cohead_shipto_id,-1) <> COALESCE(_shiptoid,-1)) THEN
+            SELECT * INTO _a 
+            FROM shiptoinfo
+              LEFT OUTER JOIN cntct ON (shipto_cntct_id=cntct_id)
+              LEFT OUTER JOIN addr ON (shipto_addr_id=addr_id)
+            WHERE (shipto_id=NEW.cohead_shipto_id);
+            IF (FOUND) THEN
+              -- Free form not allowed so we're going to make sure address matches Shipto data
+              NEW.cohead_shipto_cntct_id=_a.cntct_id;
+              NEW.cohead_shipto_cntct_honorific=COALESCE(_a.cntct_honorific,'');
+              NEW.cohead_shipto_cntct_first_name=COALESCE(_a.cntct_first_name,'');
+              NEW.cohead_shipto_cntct_middle=COALESCE(_a.cntct_middle,'');    
+              NEW.cohead_shipto_cntct_last_name=COALESCE(_a.cntct_last_name,''); 
+              NEW.cohead_shipto_cntct_phone=COALESCE(_a.cntct_phone,'');
+              NEW.cohead_shipto_cntct_title=COALESCE(_a.cntct_title,'');
+              NEW.cohead_shipto_cntct_fax=COALESCE(_a.cntct_fax,''); 
+              NEW.cohead_shipto_cntct_email=COALESCE(_a.cntct_email,''); 
+              NEW.cohead_shiptoname := COALESCE(_a.shipto_name,'');
+              NEW.cohead_shiptophone := COALESCE(_a.cntct_phone,'');
+              NEW.cohead_shiptoaddress1 := COALESCE(_a.addr_line1,'');
+              NEW.cohead_shiptoaddress2 := COALESCE(_a.addr_line2,'');
+              NEW.cohead_shiptoaddress3 := COALESCE(_a.addr_line3,'');    
+              NEW.cohead_shiptocity := COALESCE(_a.addr_city,''); 
+              NEW.cohead_shiptostate := COALESCE(_a.addr_state,'');
+              NEW.cohead_shiptozipcode := COALESCE(_a.addr_postalcode,'');
+              NEW.cohead_shiptocountry := COALESCE(_a.addr_country,''); 
+            ELSE
+              -- If no shipto data and free form not allowed, this won't work
+              RAISE EXCEPTION 'Free form Shipto is not allowed on this Customer. You must supply a valid Shipto ID.';
+            END IF;
+          END IF;
+        END IF;
+      END IF;
+    END IF;
+  END IF;
+
+  IF ( SELECT (metric_value='t')
+       FROM metric
+       WHERE (metric_name='SalesOrderChangeLog') ) THEN
+
+    IF (TG_OP = 'INSERT') THEN
+      PERFORM postComment('ChangeLog', 'S', NEW.cohead_id, 'Created');
+
+    ELSIF (TG_OP = 'UPDATE') THEN
+
+      IF ( (OLD.cohead_terms_id <> NEW.cohead_terms_id) AND
+           (OLD.cohead_cust_id = NEW.cohead_cust_id) ) THEN
+        PERFORM postComment( 'ChangeLog', 'S', NEW.cohead_id,
+                             ('Terms Changed from "' || oldterms.terms_code || '" to "' || newterms.terms_code || '"') )
+        FROM terms AS oldterms, terms AS newterms
+        WHERE ( (oldterms.terms_id=OLD.cohead_terms_id)
+         AND (newterms.terms_id=NEW.cohead_terms_id) );
+      END IF;
+
+      IF ( (OLD.cohead_shipvia <> NEW.cohead_shipvia) AND
+           (OLD.cohead_cust_id = NEW.cohead_cust_id) ) THEN
+        PERFORM postComment ('ChangeLog', 'S', New.cohead_id, ('Shipvia Changed from "' || OLD.cohead_shipvia || '" to "' || NEW.cohead_shipvia || '"'));
+      END IF;
+
+      IF (OLD.cohead_holdtype <> NEW.cohead_holdtype) THEN
+        PERFORM postComment( 'ChangeLog', 'S', NEW.cohead_id,
+                             ( 'Hold Type Changed from ' || (CASE OLD.cohead_holdtype WHEN('N') THEN 'No Hold'
+                                                                                      WHEN('C') THEN 'Credit Hold'
+                                                                                      WHEN('P') THEN 'Packing Hold'
+                                                                                      WHEN('S') THEN 'Shipping Hold'
+                                                                                      ELSE 'Unknown/Error' END) ||
+                               ' to ' || (CASE NEW.cohead_holdtype WHEN('N') THEN 'No Hold'
+                                                                   WHEN('C') THEN 'Credit Hold'
+                                                                   WHEN('P') THEN 'Packing Hold'
+                                                                   WHEN('S') THEN 'Shipping Hold'
+                                                                   ELSE 'Unknown/Error' END) ) );
+      END IF;
+
+    ELSIF (TG_OP = 'DELETE') THEN
+      DELETE FROM docass WHERE docass_source_id = OLD.cohead_id AND docass_source_type = 'S';
+      DELETE FROM docass WHERE docass_target_id = OLD.cohead_id AND docass_target_type = 'S';
+      
+      DELETE FROM comment
+      WHERE ( (comment_source='S')
+       AND (comment_source_id=OLD.cohead_id) );
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'UPDATE') THEN
+    IF ( (NOT (OLD.cohead_holdtype = 'N')) AND
+         (NEW.cohead_holdtype='N') ) THEN
+      PERFORM postEvent('SoReleased', 'S', NEW.cohead_id,
+                        NEW.cohead_warehous_id, NEW.cohead_number,
+                        NULL, NULL, NULL, NULL);
+    END IF;
+
+    IF (OLD.cohead_ordercomments <> NEW.cohead_ordercomments) THEN
+      PERFORM postEvent('SoNotesChanged', 'S', NEW.cohead_id,
+                        NEW.cohead_warehous_id, NEW.cohead_number,
+                        NULL, NULL, NULL, NULL);
+    END IF;
+
+    IF ((OLD.cohead_shipchrg_id != NEW.cohead_shipchrg_id)
+        OR (OLD.cohead_freight != NEW.cohead_freight)
+        OR (OLD.cohead_shipvia != NEW.cohead_shipvia)) THEN
+      UPDATE shiphead SET 
+        shiphead_shipchrg_id=
+            CASE WHEN (NEW.cohead_shipchrg_id <= 0) THEN NULL
+                 ELSE NEW.cohead_shipchrg_id
+            END,
+        shiphead_freight=NEW.cohead_freight,
+        shiphead_shipvia=NEW.cohead_shipvia
+      WHERE ((shiphead_order_type='SO')
+      AND  (shiphead_order_id=NEW.cohead_id)
+      AND  (NOT shiphead_shipped));
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  ELSE
+    NEW.cohead_lastupdated = CURRENT_TIMESTAMP;
+
+    RETURN NEW;
+  END IF;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER soheadTrigger ON cohead;
+CREATE TRIGGER soheadTrigger BEFORE INSERT OR UPDATE OR DELETE ON cohead FOR EACH ROW EXECUTE PROCEDURE _soheadTrigger();
+
+CREATE OR REPLACE FUNCTION _soheadTriggerAfter() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (COALESCE(NEW.cohead_taxzone_id,-1) <> COALESCE(OLD.cohead_taxzone_id,-1)) THEN
+    UPDATE coitem SET coitem_taxtype_id=getItemTaxType(itemsite_item_id,NEW.cohead_taxzone_id)
+    FROM itemsite 
+    WHERE ((itemsite_id=coitem_itemsite_id)
+     AND (coitem_cohead_id=NEW.cohead_id));
+  END IF;
+
+  -- update comments on any associated drop ship POs
+  IF (COALESCE(NEW.cohead_shipcomments, TEXT('')) <> COALESCE(OLD.cohead_shipcomments, TEXT(''))) THEN
+    UPDATE pohead SET pohead_comments=NEW.cohead_shipcomments
+    FROM poitem JOIN coitem ON (coitem_cohead_id=NEW.cohead_id AND coitem_order_type='P' AND coitem_order_id=poitem_id)
+    WHERE (pohead_id=poitem_pohead_id);
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropifexists('TRIGGER','soheadTriggerAfter');
+CREATE TRIGGER soheadTriggerAfter AFTER UPDATE ON cohead FOR EACH ROW EXECUTE PROCEDURE _soheadTriggerAfter();
diff --git a/foundation-database/public/trigger_functions/coitem.sql b/foundation-database/public/trigger_functions/coitem.sql
new file mode 100644 (file)
index 0000000..0de39ce
--- /dev/null
@@ -0,0 +1,785 @@
+CREATE OR REPLACE FUNCTION _soitemTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _changelog BOOLEAN := FALSE;
+  _check BOOLEAN;
+  _kit BOOLEAN;
+  _shipped BOOLEAN;
+  _atShipping NUMERIC;
+  _tmp INTEGER;
+  _rec RECORD;
+BEGIN
+  -- Check
+  SELECT checkPrivilege('MaintainSalesOrders') OR checkPrivilege('ShipOrders') OR checkPrivilege('IssueStockToShipping') INTO _check;
+  IF NOT (_check) THEN
+    RAISE EXCEPTION 'You do not have privileges to alter a Sales Order.';
+  END IF;
+
+  IF ( SELECT fetchMetricBool('SalesOrderChangeLog') ) THEN
+    _changelog := TRUE;
+  END IF;
+
+  IF (TG_OP IN ('INSERT','UPDATE')) THEN
+    IF (NEW.coitem_scheddate IS NULL) THEN
+      IF (fetchmetricbool('AllowASAPShipSchedules')) THEN
+        NEW.coitem_scheddate := current_date;
+      ELSE
+        RAISE EXCEPTION 'A schedule date is required.';
+      END IF;
+    END IF;
+  END IF;
+
+  _rec := NEW;
+
+  SELECT COALESCE(item_type,'')='K'
+    INTO _kit
+    FROM itemsite, item
+   WHERE((itemsite_item_id=item_id)
+     AND (itemsite_id=_rec.coitem_itemsite_id));
+  _kit := COALESCE(_kit, false);
+  _shipped := false;
+  IF(_kit AND _rec.coitem_status <> 'C' AND _rec.coitem_status <> 'X') THEN
+    SELECT coitem_id
+      INTO _tmp
+      FROM coitem JOIN shipitem ON (shipitem_orderitem_id=coitem_id)
+                  JOIN shiphead ON (shiphead_id=shipitem_shiphead_id AND shiphead_order_type='SO')
+     WHERE((coitem_cohead_id=_rec.coitem_cohead_id)
+       AND (coitem_linenumber=_rec.coitem_linenumber)
+       AND (coitem_subnumber > 0))
+     GROUP BY coitem_id
+    HAVING (SUM(shipitem_qty) > 0)
+     LIMIT 1;
+    IF (FOUND) THEN
+      _shipped := true;
+    END IF;
+  END IF;
+  
+  IF (TG_OP ='UPDATE') THEN
+    IF ((OLD.coitem_status <> 'C') AND (NEW.coitem_status = 'C')) THEN
+      SELECT qtyAtShipping(NEW.coitem_id) INTO _atShipping;
+      IF (_atShipping > 0) THEN
+        RAISE EXCEPTION 'Line % cannot be Closed at this time as there is inventory at shipping.',NEW.coitem_linenumber;
+      END IF;
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    PERFORM postEvent('SoitemCreated', 'S', NEW.coitem_id,
+                      itemsite_warehous_id, (cohead_number || '-' || NEW.coitem_linenumber),
+                      NULL, NULL, NULL, NULL)
+    FROM cohead, itemsite
+    WHERE ( (cohead_id=NEW.coitem_cohead_id)
+      AND   (itemsite_id=NEW.coitem_itemsite_id)
+      AND   (NEW.coitem_scheddate <= (CURRENT_DATE + itemsite_eventfence)) );
+
+    IF (_changelog) THEN
+      PERFORM postComment('ChangeLog', 'SI', NEW.coitem_id, 'Created');
+    END IF;
+
+    --Set defaults if no values passed
+    NEW.coitem_linenumber      := COALESCE(NEW.coitem_linenumber,
+                                          (SELECT (COALESCE(MAX(coitem_linenumber), 0) + 1)
+                                           FROM coitem
+                                           WHERE (coitem_cohead_id=NEW.coitem_cohead_id)));
+    NEW.coitem_status          := COALESCE(NEW.coitem_status,'O');
+    NEW.coitem_scheddate       := COALESCE(NEW.coitem_scheddate,
+                                          (SELECT MIN(coitem_scheddate)
+                                           FROM coitem
+                                           WHERE (coitem_cohead_id=NEW.coitem_cohead_id)));
+    NEW.coitem_memo            := COALESCE(NEW.coitem_memo,'');
+    NEW.coitem_prcost          := COALESCE(NEW.coitem_prcost,0);
+    NEW.coitem_warranty        := COALESCE(NEW.coitem_warranty,false);
+
+    IF (NEW.coitem_status='O') THEN
+      UPDATE cohead SET cohead_status = 'O'
+       WHERE ((cohead_id=NEW.coitem_cohead_id)
+         AND  (cohead_status='C'));
+    END IF;
+
+    RETURN NEW;
+
+  ELSIF (TG_OP = 'UPDATE') THEN
+    IF (NEW.coitem_qtyord <> OLD.coitem_qtyord) THEN
+      IF(_kit) THEN
+        IF(_shipped) THEN
+          RAISE EXCEPTION 'You can not change the qty ordered for a Kit item when one or more of its components have shipped inventory.';
+        END IF;
+      END IF;
+      PERFORM postEvent('SoitemQtyChanged', 'S', NEW.coitem_id,
+                        itemsite_warehous_id, (cohead_number || '-' || NEW.coitem_linenumber),
+                        NEW.coitem_qtyord, OLD.coitem_qtyord, NULL, NULL)
+      FROM cohead, itemsite
+      WHERE ( (cohead_id=NEW.coitem_cohead_id)
+        AND   (itemsite_id=NEW.coitem_itemsite_id)
+        AND   ( (NEW.coitem_scheddate <= (CURRENT_DATE + itemsite_eventfence))
+         OR     (OLD.coitem_scheddate <= (CURRENT_DATE + itemsite_eventfence)) ) );
+
+      IF (_changelog) THEN
+       PERFORM postComment( 'ChangeLog', 'SI', NEW.coitem_id,
+                            ( 'Changed Qty. Ordered from ' || formatQty(OLD.coitem_qtyord) ||
+                              ' to ' || formatQty(NEW.coitem_qtyord) ) );
+      END IF;
+
+    END IF;
+
+    IF (NEW.coitem_price <> OLD.coitem_price) THEN
+      IF (_changelog) THEN
+       PERFORM postComment( 'ChangeLog', 'SI', NEW.coitem_id,
+                            ( 'Changed Unit Price from ' || formatPrice(OLD.coitem_price) ||
+                              ' to ' || formatPrice(NEW.coitem_price) ) );
+      END IF;
+
+    END IF;
+
+    IF (NEW.coitem_scheddate <> OLD.coitem_scheddate) THEN
+      PERFORM postEvent('SoitemSchedDateChanged', 'S', NEW.coitem_id,
+                        itemsite_warehous_id, (cohead_number || '-' || NEW.coitem_linenumber),
+                        NULL, NULL, NEW.coitem_scheddate, OLD.coitem_scheddate)
+      FROM cohead, itemsite
+      WHERE ( (cohead_id=NEW.coitem_cohead_id)
+        AND   (itemsite_id=NEW.coitem_itemsite_id)
+        AND   ( (NEW.coitem_scheddate <= (CURRENT_DATE + itemsite_eventfence))
+         OR     (OLD.coitem_scheddate <= (CURRENT_DATE + itemsite_eventfence)) ) );
+
+      IF (_changelog) THEN
+       PERFORM postComment( 'ChangeLog', 'SI', NEW.coitem_id,
+                            ( 'Changed Sched. Date from ' || formatDate(OLD.coitem_scheddate) ||
+                              ' to ' || formatDate(NEW.coitem_scheddate)) );
+      END IF;
+
+    END IF;
+
+    IF ((NEW.coitem_status = 'C') AND (OLD.coitem_status <> 'C')) THEN
+      NEW.coitem_closedate = CURRENT_TIMESTAMP;
+      NEW.coitem_close_username = getEffectiveXtUser();
+      NEW.coitem_qtyreserved := 0;
+
+      IF (_changelog) THEN
+       PERFORM postComment('ChangeLog', 'SI', NEW.coitem_id, 'Closed');
+      END IF;
+    END IF;
+
+    IF ((NEW.coitem_status <> 'C') AND (OLD.coitem_status = 'C')) THEN
+      NEW.coitem_closedate = NULL;
+      NEW.coitem_close_username = NULL;
+
+      IF (_changelog) THEN
+       PERFORM postComment('ChangeLog', 'SI', NEW.coitem_id, 'Reopened');
+      END IF;
+    END IF;
+
+    IF ((NEW.coitem_status = 'X') AND (OLD.coitem_status <> 'X')) THEN
+      IF ((OLD.coitem_order_type = 'W') AND
+         (SELECT wo_status IN ('O', 'E', 'R')
+           FROM wo
+           WHERE (wo_id=OLD.coitem_order_id))) THEN
+      -- Close any associated W/O
+        PERFORM closeWo(OLD.coitem_order_id, FALSE, CURRENT_DATE);
+      ELSIF (OLD.coitem_order_type = 'R') THEN 
+      -- Delete any associated P/R
+        PERFORM deletePr(OLD.coitem_order_id);
+      END IF;
+
+      NEW.coitem_qtyreserved := 0;
+
+      IF (_changelog) THEN
+       PERFORM postComment('ChangeLog', 'SI', NEW.coitem_id, 'Canceled');
+       PERFORM postComment('ChangeLog', 'S', NEW.coitem_cohead_id, 'Line # '|| NEW.coitem_linenumber ||' Canceled');
+      END IF;
+
+      PERFORM postEvent('SoitemCancelled', 'S', OLD.coitem_id,
+                        itemsite_warehous_id, (cohead_number || '-' || OLD.coitem_linenumber),
+                        NULL, NULL, NULL, NULL)
+      FROM cohead, itemsite
+      WHERE ( (cohead_id=OLD.coitem_cohead_id)
+        AND   (itemsite_id=OLD.coitem_itemsite_id)
+        AND   (OLD.coitem_scheddate <= (CURRENT_DATE + itemsite_eventfence)) );
+
+    END IF;
+
+    IF ((NEW.coitem_qtyreserved <> OLD.coitem_qtyreserved) AND (_changelog)) THEN
+      PERFORM postComment('ChangeLog', 'SI', NEW.coitem_id, 'Changed Qty Reserved to '|| NEW.coitem_qtyreserved);
+    END IF;
+
+  END IF;
+
+  NEW.coitem_lastupdated = CURRENT_TIMESTAMP;
+
+  -- Handle status for header
+  IF (TG_OP = 'UPDATE') THEN
+    IF (OLD.coitem_status <> NEW.coitem_status) THEN
+      IF ( (SELECT (count(*) < 1)
+              FROM coitem
+             WHERE ((coitem_cohead_id=NEW.coitem_cohead_id)
+               AND  (coitem_id != NEW.coitem_id)
+               AND  (coitem_status='O')) ) AND (NEW.coitem_status<>'O') ) THEN
+        UPDATE cohead SET cohead_status = 'C'
+         WHERE ((cohead_id=NEW.coitem_cohead_id)
+           AND  (cohead_status='O'));
+      ELSE
+        UPDATE cohead SET cohead_status = 'O'
+         WHERE ((cohead_id=NEW.coitem_cohead_id)
+           AND  (cohead_status='C'));
+      END IF;
+    END IF;
+  END IF;
+
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'soitemTrigger');
+CREATE TRIGGER soitemTrigger BEFORE INSERT OR UPDATE ON coitem FOR EACH ROW EXECUTE PROCEDURE _soitemTrigger();
+
+CREATE OR REPLACE FUNCTION _soitemBeforeTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _check NUMERIC;
+  _itemNumber TEXT;
+  _r RECORD;
+  _kit BOOLEAN;
+
+BEGIN
+
+  --Determine if this is a kit for later processing
+  SELECT COALESCE(item_type,'')='K'
+  INTO _kit
+  FROM itemsite, item
+  WHERE((itemsite_item_id=item_id)
+  AND (itemsite_id=NEW.coitem_itemsite_id));
+  _kit := COALESCE(_kit, false);
+  
+  IF (TG_OP = 'INSERT') THEN
+
+    -- If this is imported, go ahead and insert default characteristics
+    IF (NEW.coitem_imported) THEN
+      INSERT INTO charass (charass_target_type, charass_target_id, charass_char_id, charass_value, charass_price)
+      SELECT 'SI', NEW.coitem_id, char_id, charass_value,
+             itemcharprice(item_id,char_id,charass_value,cohead_cust_id,cohead_shipto_id,NEW.coitem_qtyord,cohead_curr_id,cohead_orderdate) 
+        FROM (
+           SELECT DISTINCT char_id, char_name, charass_value, item_id, cohead_cust_id, cohead_shipto_id, cohead_curr_id, cohead_orderdate
+             FROM cohead, charass, char, itemsite, item
+            WHERE((itemsite_id=NEW.coitem_itemsite_id)
+              AND (itemsite_item_id=item_id)
+              AND (charass_target_type='I') 
+              AND (charass_target_id=item_id)
+              AND (charass_default)
+              AND (char_id=charass_char_id)
+              AND (cohead_id=NEW.coitem_cohead_id))
+           ORDER BY char_name) AS data;
+    END IF;
+  END IF;
+
+  -- Create work order and process if flagged to do so
+  IF ((NEW.coitem_order_type='W') AND (NEW.coitem_order_id=-1)) THEN
+    SELECT createwo(CAST(cohead_number AS INTEGER),
+                    NEW.coitem_itemsite_id,
+                    1, -- priority
+                   validateOrderQty(NEW.coitem_itemsite_id, NEW.coitem_qtyord, TRUE),
+                    itemsite_leadtime,
+                    NEW.coitem_scheddate,
+                   NEW.coitem_memo,
+                    'S',
+                    NEW.coitem_id,
+                   cohead_prj_id) INTO NEW.coitem_order_id
+    FROM cohead, itemsite 
+    WHERE ((cohead_id=NEW.coitem_cohead_id)
+    AND (itemsite_id=NEW.coitem_itemsite_id));
+
+    INSERT INTO charass
+      (charass_target_type, charass_target_id,
+       charass_char_id, charass_value) 
+       SELECT 'W', NEW.coitem_order_id, charass_char_id, charass_value
+       FROM charass
+       WHERE ((charass_target_type='SI')
+       AND  (charass_target_id=NEW.coitem_id));
+  END IF;
+   
+  IF (TG_OP = 'UPDATE') THEN
+--  Update P/R date if applicable
+
+    IF (NEW.coitem_scheddate <> OLD.coitem_scheddate AND NEW.coitem_order_type='R' AND NEW.coitem_order_id > 1) THEN
+      UPDATE pr SET pr_duedate = NEW.coitem_scheddate WHERE (pr_order_id=NEW.coitem_id AND pr_order_type='S');
+    END IF;
+    
+--  If closing or cancelling and there is a job item work order, then close job and distribute remaining costs
+    IF ((NEW.coitem_status = 'C' AND OLD.coitem_status <> 'C')
+     OR (NEW.coitem_status = 'X' AND OLD.coitem_status <> 'X'))
+     AND (OLD.coitem_order_id > -1) THEN
+
+      SELECT wo_id, wo_wipvalue INTO _r
+       FROM wo,itemsite,item
+      WHERE ((wo_ordtype='S')
+      AND (wo_ordid=OLD.coitem_id)
+      AND (itemsite_id=wo_itemsite_id)
+      AND (item_id=itemsite_item_id)
+      AND (itemsite_costmethod = 'J'));
+
+      IF (FOUND) THEN
+        IF (_r.wo_wipvalue > 0) THEN
+        --  Distribute to G/L, debit Cost of Sales, credit WIP
+          PERFORM MIN(insertGLTransaction( 'W/O', 'WO', formatWoNumber(NEW.coitem_order_id), 'Job Closed Incomplete',
+                                           costcat_wip_accnt_id,
+                                           CASE WHEN (COALESCE(NEW.coitem_cos_accnt_id, -1) != -1)
+                                                  THEN NEW.coitem_cos_accnt_id
+                                                WHEN (NEW.coitem_warranty=TRUE)
+                                                  THEN resolveCOWAccount(itemsite_id, cohead_cust_id, cohead_saletype_id, cohead_shipzone_id)
+                                                ELSE resolveCOSAccount(itemsite_id, cohead_cust_id, cohead_saletype_id, cohead_shipzone_id)
+                                           END,
+                                           -1,  _r.wo_wipvalue, current_date ))
+          FROM itemsite, costcat, cohead
+          WHERE ((itemsite_id=NEW.coitem_itemsite_id)
+           AND (itemsite_costcat_id=costcat_id)
+           AND (cohead_id=NEW.coitem_cohead_id));
+        END IF;
+
+        UPDATE wo SET
+          wo_status = 'C',
+          wo_wipvalue = 0
+        WHERE (wo_id = _r.wo_id);
+
+      END IF;
+    END IF;
+
+--  Likewise, reopen the job if line reopened
+    IF ((NEW.coitem_status != 'C' AND OLD.coitem_status = 'C')
+     OR (NEW.coitem_status != 'X' AND OLD.coitem_status = 'X'))
+     AND (OLD.coitem_order_id > -1) THEN
+        UPDATE wo SET
+          wo_status = 'I'
+        FROM itemsite, item
+        WHERE ((wo_ordtype = 'S')
+         AND (wo_ordid=NEW.coitem_id)
+         AND (wo_itemsite_id=itemsite_id)
+         AND (itemsite_item_id=item_id)
+         AND (itemsite_costmethod='J'));
+    END IF;
+
+--  Handle links to Return Authorization
+    IF (fetchMetricBool('EnableReturnAuth')) THEN 
+      SELECT * INTO _r 
+      FROM raitem,rahead 
+      WHERE ((raitem_new_coitem_id=NEW.coitem_id)
+      AND (rahead_id=raitem_rahead_id));
+      IF (FOUND) THEN
+        IF ((_r.raitem_qtyauthorized <> NEW.coitem_qtyord OR
+            _r.raitem_qty_uom_id <> NEW.coitem_qty_uom_id OR
+            _r.raitem_qty_invuomratio <> NEW.coitem_qty_invuomratio OR
+            _r.raitem_price_uom_id <> NEW.coitem_price_uom_id OR
+            _r.raitem_price_invuomratio <> NEW.coitem_price_invuomratio)
+            AND NOT (NEW.coitem_status = 'X' AND _r.raitem_qtyauthorized = 0)) THEN
+          RAISE EXCEPTION 'Quantities for line item % may only be changed on the Return Authorization that created it.',NEW.coitem_linenumber;
+        END IF;
+        IF (OLD.coitem_warranty <> NEW.coitem_warranty) THEN
+          UPDATE raitem SET raitem_warranty = NEW.coitem_warranty
+           WHERE((raitem_new_coitem_id=NEW.coitem_id)
+             AND (raitem_warranty != NEW.coitem_warranty));
+        END IF;
+        IF (OLD.coitem_cos_accnt_id <> NEW.coitem_cos_accnt_id) THEN
+          UPDATE raitem SET raitem_cos_accnt_id = NEW.coitem_cos_accnt_id
+           WHERE((raitem_new_coitem_id=NEW.coitem_id)
+             AND (COALESCE(raitem_cos_accnt_id,-1) != COALESCE(NEW.coitem_cos_accnt_id,-1)));
+        END IF;
+        IF (OLD.coitem_taxtype_id <> NEW.coitem_taxtype_id) THEN
+          UPDATE raitem SET raitem_taxtype_id = NEW.coitem_taxtype_id
+           WHERE((raitem_new_coitem_id=NEW.coitem_id)
+             AND (COALESCE(raitem_taxtype_id,-1) != COALESCE(NEW.coitem_taxtype_id,-1)));
+        END IF;
+        IF (OLD.coitem_scheddate <> NEW.coitem_scheddate) THEN
+          UPDATE raitem SET raitem_scheddate = NEW.coitem_scheddate
+           WHERE((raitem_new_coitem_id=NEW.coitem_id)
+             AND (raitem_scheddate != NEW.coitem_scheddate));
+        END IF;
+        IF (OLD.coitem_memo <> NEW.coitem_memo) THEN
+          UPDATE raitem SET raitem_notes = NEW.coitem_memo
+           WHERE((raitem_new_coitem_id=NEW.coitem_id)
+             AND (raitem_notes != NEW.coitem_memo));
+        END IF;
+        IF ((OLD.coitem_qtyshipped <> NEW.coitem_qtyshipped) AND 
+           (NEW.coitem_qtyshipped >= _r.raitem_qtyauthorized) AND
+           ((_r.raitem_disposition = 'S') OR
+           (_r.raitem_status = 'O') AND
+           (_r.raitem_disposition IN ('P','V')) AND
+           (_r.raitem_qtyreceived >= _r.raitem_qtyauthorized))) THEN
+          UPDATE raitem SET raitem_status = 'C' 
+          WHERE (raitem_new_coitem_id=NEW.coitem_id);
+        END IF;
+      END IF;
+    END IF; 
+  END IF; 
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'soitemBeforeTrigger');
+CREATE TRIGGER soitemBeforeTrigger BEFORE INSERT OR UPDATE ON coitem FOR EACH ROW EXECUTE PROCEDURE _soitemBeforeTrigger();
+-- TODO: there are two BEFORE triggers. should these be merged?
+
+
+CREATE OR REPLACE FUNCTION _soitemAfterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _check NUMERIC;
+  _r RECORD;
+  _kit BOOLEAN;
+  _fractional BOOLEAN;
+  _rec RECORD;
+  _kstat TEXT;
+  _pstat TEXT;
+  _result INTEGER;
+  _coitemid INTEGER;
+  _itemsrcid INTEGER;
+  _orderid INTEGER;
+
+BEGIN
+
+  _rec := NEW;
+
+  --Cache some information
+  SELECT * INTO _r
+  FROM cohead
+  WHERE (cohead_id=_rec.coitem_cohead_id);
+
+  --Determine if this is a kit for later processing
+  SELECT COALESCE(item_type,'')='K', item_fractional
+    INTO _kit, _fractional
+    FROM itemsite, item
+   WHERE((itemsite_item_id=item_id)
+     AND (itemsite_id=_rec.coitem_itemsite_id));
+  _kit := COALESCE(_kit, false);
+  _fractional := COALESCE(_fractional, false);
+
+  IF (_kit) THEN
+  -- Kit Processing
+    IF (TG_OP = 'INSERT') THEN
+  -- Create Sub Lines for Kit Components
+      PERFORM explodeKit(NEW.coitem_cohead_id, NEW.coitem_linenumber, 0, NEW.coitem_itemsite_id,
+                         NEW.coitem_qtyord, NEW.coitem_scheddate, NEW.coitem_promdate, NEW.coitem_memo);
+      IF (fetchMetricBool('KitComponentInheritCOS')) THEN
+  -- Update kit line item COS
+        UPDATE coitem
+        SET coitem_cos_accnt_id = CASE WHEN (COALESCE(NEW.coitem_cos_accnt_id, -1) != -1)
+                                         THEN NEW.coitem_cos_accnt_id
+                                       WHEN (NEW.coitem_warranty)
+                                         THEN resolveCOWAccount(NEW.coitem_itemsite_id, _r.cohead_cust_id, _r.cohead_saletype_id, _r.cohead_shipzone_id)
+                                       ELSE resolveCOSAccount(NEW.coitem_itemsite_id, _r.cohead_cust_id, _r.cohead_saletype_id, _r.cohead_shipzone_id)
+                                  END
+        WHERE((coitem_cohead_id=NEW.coitem_cohead_id)
+          AND (coitem_linenumber = NEW.coitem_linenumber)
+          AND (coitem_subnumber > 0));
+      END IF;
+    END IF;
+    IF (TG_OP = 'UPDATE') THEN
+      IF (NEW.coitem_qtyord <> OLD.coitem_qtyord) THEN
+  -- Recreate Sub Lines for Kit Components
+      FOR _coitemid IN
+        SELECT coitem_id
+        FROM coitem
+        WHERE ( (coitem_cohead_id=OLD.coitem_cohead_id)
+          AND   (coitem_linenumber=OLD.coitem_linenumber)
+          AND   (coitem_subnumber > 0) )
+        LOOP
+          SELECT deleteSoItem(_coitemid) INTO _result;
+          IF (_result < 0) THEN
+             RAISE EXCEPTION 'Error deleting kit components: deleteSoItem(integer) Error:%', _result;
+          END IF;
+        END LOOP;
+
+        PERFORM explodeKit(NEW.coitem_cohead_id, NEW.coitem_linenumber, 0, NEW.coitem_itemsite_id,
+                           NEW.coitem_qtyord, NEW.coitem_scheddate, NEW.coitem_promdate);
+      END IF;
+      IF ( (NEW.coitem_qtyord <> OLD.coitem_qtyord) OR
+           (NEW.coitem_cos_accnt_id <> OLD.coitem_cos_accnt_id) ) THEN
+        IF (fetchMetricBool('KitComponentInheritCOS')) THEN
+  -- Update kit line item COS
+          UPDATE coitem
+          SET coitem_cos_accnt_id = CASE WHEN (COALESCE(NEW.coitem_cos_accnt_id, -1) != -1)
+                                           THEN NEW.coitem_cos_accnt_id
+                                         WHEN (NEW.coitem_warranty)
+                                           THEN resolveCOWAccount(NEW.coitem_itemsite_id, _r.cohead_cust_id, _r.cohead_saletype_id, _r.cohead_shipzone_id)
+                                         ELSE resolveCOSAccount(NEW.coitem_itemsite_id, _r.cohead_cust_id, _r.cohead_saletype_id, _r.cohead_shipzone_id)
+                                    END
+          WHERE((coitem_cohead_id=NEW.coitem_cohead_id)
+            AND (coitem_linenumber = NEW.coitem_linenumber)
+            AND (coitem_subnumber > 0));
+        END IF;
+      END IF;
+      IF (NEW.coitem_scheddate <> OLD.coitem_scheddate) THEN
+  -- Update kit line item Schedule Date
+        UPDATE coitem
+        SET coitem_scheddate = NEW.coitem_scheddate
+        WHERE((coitem_cohead_id=NEW.coitem_cohead_id)
+          AND (coitem_linenumber = NEW.coitem_linenumber)
+          AND (coitem_subnumber > 0));
+      END IF;
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    -- Create Purchase Request if flagged to do so
+    IF ((NEW.coitem_order_type='R') AND (NEW.coitem_order_id=-1)) THEN
+      SELECT createpr(CAST(cohead_number AS INTEGER), 'S', NEW.coitem_id) INTO _orderid
+      FROM cohead
+      WHERE (cohead_id=NEW.coitem_cohead_id);
+      IF (_orderid > 0) THEN
+        UPDATE coitem SET coitem_order_id=_orderid
+        WHERE (coitem_id=NEW.coitem_id);
+      END IF;
+    END IF;
+
+    -- Create Purchase Order if flagged to do so
+    IF ((NEW.coitem_order_type='P') AND (NEW.coitem_order_id=-1)) THEN
+      SELECT itemsrc_id INTO _itemsrcid
+      FROM itemsite JOIN itemsrc ON (itemsrc_item_id=itemsite_item_id AND itemsrc_default)
+      WHERE (itemsite_id=NEW.coitem_itemsite_id);
+      IF (FOUND) THEN
+        SELECT createPurchaseToSale(NEW.coitem_id,
+                                    _itemsrcid,
+                                    itemsite_dropship,
+                                    CASE WHEN (NEW.coitem_prcost=0.0) THEN NULL
+                                         ELSE NEW.coitem_prcost
+                                    END) INTO _orderid
+        FROM itemsite
+        WHERE (itemsite_id=NEW.coitem_itemsite_id);
+        IF (_orderid > 0) THEN
+          UPDATE coitem SET coitem_order_id=_orderid
+          WHERE (coitem_id=NEW.coitem_id);
+        END IF;
+      END IF;
+    END IF;
+
+    -- Update Purchase Order comments
+    IF (NEW.coitem_order_type='P') THEN
+      UPDATE poitem SET poitem_comments=NEW.coitem_memo
+      WHERE ((poitem_order_id=NEW.coitem_id) AND (poitem_order_type='S'));
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'UPDATE') THEN
+    IF (NEW.coitem_order_type = 'P') THEN
+      --If soitem is cancelled
+      IF ((NEW.coitem_status = 'X') AND (OLD.coitem_status <> 'X')) THEN
+        PERFORM postEvent('PoItemSoCancelled', 'P', poitem_id,
+                          itemsite_warehous_id,
+                          (pohead_number || '-' || poitem_linenumber || ':' || item_number),
+                          NULL, NULL, NULL, NULL)
+        FROM poitem JOIN itemsite ON (itemsite_id=poitem_itemsite_id)
+                    JOIN item ON (item_id=itemsite_item_id)
+                    JOIN pohead ON (pohead_id=poitem_pohead_id)
+        WHERE ( (poitem_id=OLD.coitem_order_id)
+          AND   (poitem_duedate <= (CURRENT_DATE + itemsite_eventfence)) );
+      --If soitem notes changed
+      ELSIF (NEW.coitem_memo <> OLD.coitem_memo) THEN 
+        UPDATE poitem SET poitem_comments=NEW.coitem_memo
+        WHERE ((poitem_order_id=NEW.coitem_id) AND (poitem_order_type='S'));
+      END IF;
+    END IF;
+  END IF;
+
+  IF (_rec.coitem_subnumber > 0) THEN
+    SELECT coitem_status
+      INTO _kstat
+      FROM coitem
+     WHERE((coitem_cohead_id=_rec.coitem_cohead_id)
+       AND (coitem_linenumber=_rec.coitem_linenumber)
+       AND (coitem_subnumber = 0));
+    IF ((SELECT count(*)
+           FROM coitem
+          WHERE((coitem_cohead_id=_rec.coitem_cohead_id)
+            AND (coitem_linenumber=_rec.coitem_linenumber)
+            AND (coitem_subnumber <> _rec.coitem_subnumber)
+            AND (coitem_subnumber > 0)
+            AND (coitem_status = 'O'))) > 0) THEN
+      _pstat := 'O';
+    ELSE
+      _pstat := _rec.coitem_status;
+    END IF;
+  END IF;
+
+  IF(TG_OP = 'INSERT') THEN
+    IF (_rec.coitem_subnumber > 0 AND _rec.coitem_status = 'O') THEN
+      _pstat := 'O';
+    END IF;
+  ELSIF (TG_OP = 'UPDATE') THEN
+    IF (_rec.coitem_subnumber > 0 AND _rec.coitem_status = 'O') THEN
+      _pstat := 'O';
+    END IF;
+
+    IF ((NEW.coitem_status = 'C') AND (OLD.coitem_status <> 'C')) THEN
+      IF(_kit) THEN
+        UPDATE coitem
+           SET coitem_status='C'
+         WHERE((coitem_cohead_id=OLD.coitem_cohead_id)
+           AND (coitem_linenumber=OLD.coitem_linenumber)
+           AND (coitem_status='O')
+           AND (coitem_subnumber > 0));
+      END IF;
+    END IF;
+
+    IF ((NEW.coitem_status = 'X') AND (OLD.coitem_status <> 'X')) THEN
+      IF(_kit) THEN
+        UPDATE coitem
+           SET coitem_status='X'
+         WHERE((coitem_cohead_id=OLD.coitem_cohead_id)
+           AND (coitem_linenumber=OLD.coitem_linenumber)
+           AND (coitem_status='O')
+           AND (coitem_subnumber > 0));
+      END IF;
+    END IF;
+
+    IF(NEW.coitem_status = 'O' AND OLD.coitem_status <> 'O') THEN
+      IF(_kit) THEN
+        UPDATE coitem
+           SET coitem_status='O'
+         WHERE((coitem_cohead_id=OLD.coitem_cohead_id)
+           AND (coitem_linenumber=OLD.coitem_linenumber)
+           AND ((coitem_qtyord - coitem_qtyshipped + coitem_qtyreturned) > 0)
+           AND (coitem_subnumber > 0));
+      END IF;
+    END IF;
+
+  END IF;
+
+  IF ((_kstat IS NOT NULL) AND (_pstat IS NOT NULL) AND (_rec.coitem_subnumber > 0) AND (_kstat <> _pstat)) THEN
+    UPDATE coitem
+       SET coitem_status = _pstat
+     WHERE((coitem_cohead_id=_rec.coitem_cohead_id)
+       AND (coitem_linenumber=_rec.coitem_linenumber)
+       AND (coitem_subnumber = 0));
+  END IF;
+
+  --If auto calculate freight, recalculate cohead_freight
+  IF (SELECT cohead_calcfreight FROM cohead WHERE (cohead_id=NEW.coitem_cohead_id)) THEN
+    UPDATE cohead SET cohead_freight = COALESCE(
+      (SELECT SUM(freightdata_total) FROM freightDetail('SO',
+                                                        cohead_id,
+                                                        cohead_cust_id,
+                                                        cohead_shipto_id,
+                                                        cohead_orderdate,
+                                                        cohead_shipvia,
+                                                        cohead_curr_id)), 0)
+    WHERE cohead_id=NEW.coitem_cohead_id;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'soitemAfterTrigger');
+CREATE TRIGGER soitemAfterTrigger AFTER INSERT OR UPDATE ON coitem FOR EACH ROW EXECUTE PROCEDURE _soitemAfterTrigger();
+
+CREATE OR REPLACE FUNCTION _soitemBeforeDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+
+  _r              RECORD;
+  _kit            BOOLEAN := FALSE;
+  _shipped        BOOLEAN := FALSE;
+  _coitemid       INTEGER := 0;
+  _result         INTEGER := 0;
+
+BEGIN
+
+  -- Check Priv
+  IF NOT (checkPrivilege('MaintainSalesOrders')) THEN
+    RAISE EXCEPTION 'You do not have privileges to alter a Sales Order.';
+  END IF;
+
+  -- Cache some information
+  SELECT * INTO _r
+    FROM cohead, itemsite, item
+   WHERE ( (cohead_id=OLD.coitem_cohead_id)
+     AND   (itemsite_id=OLD.coitem_itemsite_id)
+     AND   (item_id=itemsite_item_id) );
+
+  _kit := (COALESCE(_r.item_type,'')='K');
+
+  -- Check for shipped kit components
+  IF(_kit AND OLD.coitem_status <> 'C' AND OLD.coitem_status <> 'X') THEN
+    IF (EXISTS (SELECT coitem_id
+                  FROM coitem JOIN shipitem ON (shipitem_orderitem_id=coitem_id)
+                              JOIN shiphead ON (shiphead_id=shipitem_shiphead_id AND shiphead_order_type='SO')
+                 WHERE ((coitem_cohead_id=OLD.coitem_cohead_id)
+                   AND  (coitem_linenumber=OLD.coitem_linenumber)
+                   AND (coitem_subnumber > 0))
+              GROUP BY coitem_id
+                HAVING (SUM(shipitem_qty) > 0)
+                 LIMIT 1) ) THEN
+      _shipped := TRUE;
+    END IF;
+  END IF;
+
+  IF(_kit AND _shipped) THEN
+    RAISE EXCEPTION 'You can not delete this Sales Order Line as it has several sub components that have already been shipped.';
+  END IF;
+
+  DELETE FROM comment
+   WHERE ( (comment_source='SI')
+     AND   (comment_source_id=OLD.coitem_id) );
+
+  DELETE FROM charass
+   WHERE ((charass_target_type='SI')
+     AND  (charass_target_id=OLD.coitem_id));
+
+  -- Delete Sub Lines for Kit Components
+  IF (OLD.coitem_subnumber = 0) THEN
+    FOR _coitemid IN
+      SELECT coitem_id
+        FROM coitem
+       WHERE ( (coitem_cohead_id=OLD.coitem_cohead_id)
+         AND   (coitem_linenumber=OLD.coitem_linenumber)
+         AND   (coitem_subnumber > 0) )
+      LOOP
+      SELECT deleteSoItem(_coitemid) INTO _result;
+      IF (_result < 0) THEN
+        IF NOT (_r.itemsite_createsopo AND (_result = -10 OR _result = -20)) THEN
+          RAISE EXCEPTION 'Error deleting kit components: deleteSoItem(integer) Error:%', _result;
+        END IF;
+      END IF;
+    END LOOP;
+  END IF;
+
+  IF (OLD.coitem_scheddate <= (CURRENT_DATE + _r.itemsite_eventfence)) THEN
+    PERFORM postEvent('SoitemCancelled', 'S', OLD.coitem_id,
+                      _r.itemsite_warehous_id, (_r.cohead_number || '-' || OLD.coitem_linenumber),
+                      NULL, NULL, NULL, NULL);
+  END IF;
+
+  RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'soitemBeforeDeleteTrigger');
+CREATE TRIGGER soitemBeforeDeleteTrigger BEFORE DELETE ON coitem FOR EACH ROW EXECUTE PROCEDURE _soitemBeforeDeleteTrigger();
+
+CREATE OR REPLACE FUNCTION _soitemAfterDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+
+BEGIN
+
+  IF (OLD.coitem_status = 'O') THEN
+    IF ( (SELECT (count(*) < 1)
+            FROM coitem
+           WHERE ((coitem_cohead_id=OLD.coitem_cohead_id)
+             AND  (coitem_id != OLD.coitem_id)
+             AND  (coitem_status = 'O')) ) ) THEN
+      UPDATE cohead SET cohead_status = 'C'
+       WHERE ((cohead_id=OLD.coitem_cohead_id)
+         AND  (cohead_status='O'));
+    END IF;
+  END IF;
+
+  RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'soitemAfterDeleteTrigger');
+CREATE TRIGGER soitemAfterDeleteTrigger AFTER DELETE ON coitem FOR EACH ROW EXECUTE PROCEDURE _soitemAfterDeleteTrigger();
diff --git a/foundation-database/public/trigger_functions/comment.sql b/foundation-database/public/trigger_functions/comment.sql
new file mode 100644 (file)
index 0000000..008de9f
--- /dev/null
@@ -0,0 +1,16 @@
+CREATE OR REPLACE FUNCTION _commentTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (NEW.comment_cmnttype_id IS NULL) THEN
+       RAISE EXCEPTION 'You must supply a valid Comment Type ID.';
+  ELSIF (NEW.comment_source = 'INCDT') THEN
+    UPDATE incdt SET incdt_updated = now() WHERE incdt_id = NEW.comment_source_id;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER commentTrigger ON comment;
+CREATE TRIGGER commentTrigger AFTER INSERT OR UPDATE ON comment FOR EACH ROW EXECUTE PROCEDURE _commentTrigger();
diff --git a/foundation-database/public/trigger_functions/company.sql b/foundation-database/public/trigger_functions/company.sql
new file mode 100644 (file)
index 0000000..ce479a4
--- /dev/null
@@ -0,0 +1,96 @@
+CREATE OR REPLACE FUNCTION _companyTrigger() RETURNS "trigger" AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _used        BOOLEAN := false;
+
+BEGIN
+  IF (NEW.company_external AND NOT OLD.company_external) THEN
+    IF EXISTS(SELECT accnt_id
+              FROM accnt, company, (
+                  SELECT DISTINCT apaccnt_ap_accnt_id AS test_accnt_id FROM apaccnt
+                  UNION SELECT DISTINCT apaccnt_discount_accnt_id FROM apaccnt
+                  UNION SELECT DISTINCT apaccnt_prepaid_accnt_id FROM apaccnt
+                  UNION SELECT DISTINCT apopen_accnt_id FROM apopen
+                  UNION SELECT DISTINCT araccnt_ar_accnt_id FROM araccnt
+                  UNION SELECT DISTINCT araccnt_deferred_accnt_id FROM araccnt
+                  UNION SELECT DISTINCT araccnt_freight_accnt_id FROM araccnt
+                  UNION SELECT DISTINCT araccnt_prepaid_accnt_id FROM araccnt
+                  UNION SELECT DISTINCT aropen_accnt_id FROM aropen
+                  UNION SELECT DISTINCT bankaccnt_accnt_id FROM bankaccnt
+                  UNION SELECT DISTINCT bankaccnt_rec_accnt_id FROM bankaccnt
+                  UNION SELECT DISTINCT budgitem_accnt_id FROM budgitem
+                  UNION SELECT DISTINCT cashrcptmisc_accnt_id FROM cashrcptmisc
+                  UNION SELECT DISTINCT cmhead_misc_accnt_id FROM cmhead
+                  UNION SELECT DISTINCT cobmisc_misc_accnt_id FROM cobmisc
+                  UNION SELECT DISTINCT cohead_misc_accnt_id FROM cohead
+                  UNION SELECT DISTINCT coitem_cos_accnt_id FROM coitem
+                  UNION SELECT DISTINCT costcat_adjustment_accnt_id FROM costcat
+                  UNION SELECT DISTINCT costcat_asset_accnt_id FROM costcat
+                  UNION SELECT DISTINCT costcat_freight_accnt_id FROM costcat
+                  UNION SELECT DISTINCT costcat_invcost_accnt_id FROM costcat
+                  UNION SELECT DISTINCT costcat_laboroverhead_accnt_id FROM costcat
+                  UNION SELECT DISTINCT costcat_liability_accnt_id FROM costcat
+                  UNION SELECT DISTINCT costcat_matusage_accnt_id FROM costcat
+                  UNION SELECT DISTINCT costcat_mfgscrap_accnt_id FROM costcat
+                  UNION SELECT DISTINCT costcat_purchprice_accnt_id FROM costcat
+                  UNION SELECT DISTINCT costcat_scrap_accnt_id FROM costcat
+                  UNION SELECT DISTINCT costcat_shipasset_accnt_id FROM costcat
+                  UNION SELECT DISTINCT costcat_toliability_accnt_id FROM costcat
+                  UNION SELECT DISTINCT costcat_transform_accnt_id FROM costcat
+                  UNION SELECT DISTINCT costcat_wip_accnt_id FROM costcat
+                  UNION SELECT DISTINCT costelem_exp_accnt_id FROM costelem
+                  UNION SELECT DISTINCT expcat_exp_accnt_id FROM expcat
+                  UNION SELECT DISTINCT expcat_freight_accnt_id FROM expcat
+                  UNION SELECT DISTINCT expcat_liability_accnt_id FROM expcat
+                  UNION SELECT DISTINCT expcat_purchprice_accnt_id FROM expcat
+                  UNION SELECT DISTINCT glseries_accnt_id FROM glseries
+                  UNION SELECT DISTINCT gltrans_accnt_id FROM gltrans
+                  UNION SELECT DISTINCT invchead_misc_accnt_id FROM invchead
+                  UNION SELECT DISTINCT quhead_misc_accnt_id FROM quhead
+                  UNION SELECT DISTINCT salesaccnt_cor_accnt_id FROM salesaccnt
+                  UNION SELECT DISTINCT salesaccnt_cos_accnt_id FROM salesaccnt
+                  UNION SELECT DISTINCT salesaccnt_cow_accnt_id FROM salesaccnt
+                  UNION SELECT DISTINCT salesaccnt_credit_accnt_id FROM salesaccnt
+                  UNION SELECT DISTINCT salesaccnt_returns_accnt_id FROM salesaccnt
+                  UNION SELECT DISTINCT salesaccnt_sales_accnt_id FROM salesaccnt
+                  UNION SELECT DISTINCT salescat_ar_accnt_id FROM salescat
+                  UNION SELECT DISTINCT salescat_prepaid_accnt_id FROM salescat
+                  UNION SELECT DISTINCT salescat_sales_accnt_id FROM salescat
+                  UNION SELECT DISTINCT stdjrnlitem_accnt_id FROM stdjrnlitem
+                  UNION SELECT DISTINCT tax_sales_accnt_id FROM tax
+                  UNION SELECT DISTINCT taxauth_accnt_id FROM taxauth
+                  UNION SELECT DISTINCT vodist_accnt_id FROM vodist
+                  UNION SELECT DISTINCT warehous_default_accnt_id FROM whsinfo
+                ) AS dummy
+              WHERE ((accnt_id=test_accnt_id)
+                AND  (accnt_company=company_number)
+                AND  (accnt_company=NEW.company_number))
+    ) THEN
+      RAISE EXCEPTION ''Cannot make Company % External because it is used in the local database.'',
+                      NEW.company_number;
+    ELSIF (fetchMetricBool(''EnableReturnAuth'')) THEN
+      IF EXISTS(SELECT accnt_id
+              FROM accnt, company, (
+                  SELECT DISTINCT rahead_misc_accnt_id AS test_accnt_id FROM rahead
+                  UNION SELECT DISTINCT raitem_cos_accnt_id FROM raitem
+                ) AS dummy
+              WHERE ((accnt_id=test_accnt_id)
+                AND  (accnt_company=company_number)
+                AND  (accnt_company=NEW.company_number))
+      ) THEN
+        RAISE EXCEPTION ''Cannot make Company % External because it is used in the local database.'',
+                        NEW.company_number;
+      END IF;
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+' LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'companyTrigger');
+CREATE TRIGGER companyTrigger BEFORE UPDATE
+ON company
+FOR EACH ROW
+EXECUTE PROCEDURE _companyTrigger();
diff --git a/foundation-database/public/trigger_functions/contrct.sql b/foundation-database/public/trigger_functions/contrct.sql
new file mode 100644 (file)
index 0000000..fafc622
--- /dev/null
@@ -0,0 +1,27 @@
+CREATE OR REPLACE FUNCTION _contrctAfterTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+
+BEGIN
+
+  -- synchronize contract effectivity with item source effectivity
+  IF (NEW.contrct_effective <> OLD.contrct_effective) THEN
+    UPDATE itemsrc SET itemsrc_effective=NEW.contrct_effective
+    WHERE itemsrc_contrct_id=NEW.contrct_id;
+  END IF;
+
+  IF (NEW.contrct_expires <> OLD.contrct_expires) THEN
+    UPDATE itemsrc SET itemsrc_expires=NEW.contrct_expires
+    WHERE itemsrc_contrct_id=NEW.contrct_id;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'contrctAfterTrigger');
+CREATE TRIGGER contrctAfterTrigger AFTER UPDATE
+ON contrct
+FOR EACH ROW
+EXECUTE PROCEDURE _contrctAfterTrigger();
diff --git a/foundation-database/public/trigger_functions/crmacct.sql b/foundation-database/public/trigger_functions/crmacct.sql
new file mode 100644 (file)
index 0000000..619ba4e
--- /dev/null
@@ -0,0 +1,259 @@
+-- TODO: add special handling for converting prospects <-> customers?
+CREATE OR REPLACE FUNCTION _crmacctBeforeTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _count        INTEGER;
+BEGIN
+  -- disallow reusing crmacct_numbers
+  IF (TG_OP IN ('INSERT', 'UPDATE')) THEN
+    IF (TG_OP = 'INSERT' AND fetchMetricText('CRMAccountNumberGeneration') IN ('A','O')) THEN
+      PERFORM clearNumberIssue('CRMAccountNumber', NEW.crmacct_number);
+    END IF;
+
+    NEW.crmacct_usr_username := LOWER(TRIM(NEW.crmacct_usr_username));
+    IF (NEW.crmacct_usr_username = '') THEN
+      NEW.crmacct_usr_username = NULL;
+    END IF;
+
+    NEW.crmacct_owner_username := LOWER(TRIM(NEW.crmacct_owner_username));
+    IF (COALESCE(NEW.crmacct_owner_username, '') = '') THEN
+      NEW.crmacct_owner_username = getEffectiveXtUser();
+    END IF;
+
+    IF (NEW.crmacct_competitor_id < 0) THEN
+      NEW.crmacct_competitor_id := NULL;
+    END IF;
+    IF (NEW.crmacct_partner_id < 0) THEN
+      NEW.crmacct_partner_id := NULL;
+    END IF;
+
+    NEW.crmacct_number = UPPER(NEW.crmacct_number);
+
+    IF (TG_OP = 'UPDATE') THEN
+      -- TODO: why not ALTER USER OLD.crmacct_number RENAME TO LOWER(NEW.crmacct_number)?
+      IF (NEW.crmacct_number != UPPER(OLD.crmacct_number) AND
+          NEW.crmacct_usr_username IS NOT NULL            AND
+          UPPER(NEW.crmacct_usr_username) != NEW.crmacct_number) THEN
+        RAISE EXCEPTION 'The CRM Account % is associated with a system User so the number cannot be changed.',
+                        NEW.crmacct_number;
+      END IF;
+    END IF;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    UPDATE cntct SET cntct_crmacct_id = NULL
+     WHERE cntct_crmacct_id = OLD.crmacct_id;
+
+    DELETE FROM docass WHERE docass_source_id = OLD.crmacct_id AND docass_source_type = 'CRMA';
+    DELETE FROM docass WHERE docass_target_id = OLD.crmacct_id AND docass_target_type = 'CRMA';
+
+    GET DIAGNOSTICS _count = ROW_COUNT;
+    RAISE DEBUG 'updated % contacts', _count;
+
+    RETURN OLD;
+
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER crmacctBeforeTrigger ON crmacct;
+CREATE TRIGGER crmacctBeforeTrigger BEFORE INSERT OR UPDATE OR DELETE
+  ON crmacct FOR EACH ROW EXECUTE PROCEDURE _crmacctBeforeTrigger();
+
+CREATE OR REPLACE FUNCTION _crmacctAfterTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid INTEGER;
+  _gotpriv    BOOLEAN;
+
+BEGIN
+  /* update _number and _name separately to propagate just what changed.
+     the priv manipulation allows targeted updates of crmaccount-maintained data
+     (note: grantPriv() == false if the user already had the priv, true if this
+     call granted the priv).
+   */
+  IF (TG_OP = 'INSERT' OR TG_OP = 'UPDATE') THEN
+    IF (NEW.crmacct_cust_id IS NOT NULL) THEN
+      _gotpriv := grantPriv(getEffectiveXtUser(), 'MaintainCustomerMasters');
+      UPDATE custinfo SET cust_number = NEW.crmacct_number
+      WHERE ((cust_id=NEW.crmacct_cust_id)
+        AND  (cust_number!=NEW.crmacct_number));
+      UPDATE custinfo SET cust_name = NEW.crmacct_name
+      WHERE ((cust_id=NEW.crmacct_cust_id)
+        AND  (cust_name!=NEW.crmacct_name));
+      IF (_gotpriv) THEN
+        PERFORM revokePriv(getEffectiveXtUser(), 'MaintainCustomerMasters');
+      END IF;
+    END IF;
+
+    IF (NEW.crmacct_emp_id IS NOT NULL) THEN
+      _gotpriv := grantPriv(getEffectiveXtUser(), 'MaintainEmployees');
+      UPDATE emp SET emp_code = NEW.crmacct_number
+      WHERE ((emp_id=NEW.crmacct_emp_id)
+        AND  (emp_code!=NEW.crmacct_number));
+      UPDATE emp SET emp_name = NEW.crmacct_name
+      WHERE ((emp_id=NEW.crmacct_emp_id)
+        AND  (emp_name!=NEW.crmacct_name));
+      IF (_gotpriv) THEN
+        PERFORM revokePriv(getEffectiveXtUser(), 'MaintainEmployees');
+      END IF;
+    END IF;
+
+    IF (NEW.crmacct_prospect_id IS NOT NULL) THEN
+      _gotpriv := grantPriv(getEffectiveXtUser(), 'MaintainProspectMasters');
+      UPDATE prospect SET prospect_number = NEW.crmacct_number
+      WHERE ((prospect_id=NEW.crmacct_prospect_id)
+        AND  (prospect_number!=NEW.crmacct_number));
+      UPDATE prospect SET prospect_name = NEW.crmacct_name
+      WHERE ((prospect_id=NEW.crmacct_prospect_id)
+        AND  (prospect_name!=NEW.crmacct_name));
+      IF (_gotpriv) THEN
+        PERFORM revokePriv(getEffectiveXtUser(), 'MaintainProspectMasters');
+      END IF;
+    END IF;
+
+    IF (NEW.crmacct_salesrep_id IS NOT NULL) THEN
+      _gotpriv := grantPriv(getEffectiveXtUser(), 'MaintainSalesReps');
+      UPDATE salesrep SET salesrep_number = NEW.crmacct_number
+      WHERE ((salesrep_id=NEW.crmacct_salesrep_id)
+        AND  (salesrep_number!=NEW.crmacct_number));
+      UPDATE salesrep SET salesrep_name = NEW.crmacct_name
+      WHERE ((salesrep_id=NEW.crmacct_salesrep_id)
+        AND  (salesrep_name!=NEW.crmacct_name));
+      IF (_gotpriv) THEN
+        PERFORM revokePriv(getEffectiveXtUser(), 'MaintainSalesReps');
+      END IF;
+    END IF;
+
+    IF (NEW.crmacct_taxauth_id IS NOT NULL) THEN
+      _gotpriv := grantPriv(getEffectiveXtUser(), 'MaintainTaxAuthorities');
+      UPDATE taxauth SET taxauth_code = NEW.crmacct_number
+      WHERE ((taxauth_id=NEW.crmacct_taxauth_id)
+        AND  (taxauth_code!=NEW.crmacct_number));
+      UPDATE taxauth SET taxauth_name = NEW.crmacct_name
+      WHERE ((taxauth_id=NEW.crmacct_taxauth_id)
+        AND  (taxauth_name!=NEW.crmacct_name));
+      IF (_gotpriv) THEN
+        PERFORM revokePriv(getEffectiveXtUser(), 'MaintainTaxAuthorities');
+      END IF;
+    END IF;
+
+    IF (NEW.crmacct_vend_id IS NOT NULL) THEN
+      _gotpriv := grantPriv(getEffectiveXtUser(), 'MaintainVendors');
+      UPDATE vendinfo SET vend_number = NEW.crmacct_number
+      WHERE ((vend_id=NEW.crmacct_vend_id)
+        AND  (vend_number!=NEW.crmacct_number));
+      UPDATE vendinfo SET vend_name = NEW.crmacct_name
+      WHERE ((vend_id=NEW.crmacct_vend_id)
+        AND  (vend_name!=NEW.crmacct_name));
+      IF (_gotpriv) THEN
+        PERFORM revokePriv(getEffectiveXtUser(), 'MaintainVendors');
+      END IF;
+    END IF;
+
+    -- Link Primary and Secondary Contacts to this Account if they are not already
+    IF (NEW.crmacct_cntct_id_1 IS NOT NULL) THEN
+      _gotpriv := grantPriv(getEffectiveXtUser(), 'MaintainAllContacts');
+      UPDATE cntct SET cntct_crmacct_id = NEW.crmacct_id
+       WHERE cntct_id=NEW.crmacct_cntct_id_1;
+      IF (_gotpriv) THEN
+        PERFORM revokePriv(getEffectiveXtUser(), 'MaintainAllContacts');
+      END IF;
+    END IF;
+
+    IF (NEW.crmacct_cntct_id_2 IS NOT NULL) THEN
+      _gotpriv := grantPriv(getEffectiveXtUser(), 'MaintainAllContacts');
+      UPDATE cntct SET cntct_crmacct_id = NEW.crmacct_id
+       WHERE cntct_id=NEW.crmacct_cntct_id_2;
+      IF (_gotpriv) THEN
+        PERFORM revokePriv(getEffectiveXtUser(), 'MaintainAllContacts');
+      END IF;
+    END IF;
+
+    -- cannot have fkey references to system catalogs so enforce them here
+    IF (NEW.crmacct_usr_username IS NOT NULL) THEN
+      IF (NOT EXISTS(SELECT usr_username
+                       FROM usr
+                      WHERE usr_username=NEW.crmacct_usr_username)) THEN
+        RAISE EXCEPTION 'User % does not exist so this CRM Account Number is invalid.',
+                        NEW.crmacct_usr_username;
+      END IF;
+      IF (TG_OP = 'UPDATE') THEN
+        -- reminder: this evaluates to false if either is NULL
+        IF (NEW.crmacct_usr_username != OLD.crmacct_usr_username) THEN
+          RAISE EXCEPTION 'Cannot change the user name for %',
+                          OLD.crmacct_usr_username;
+        END IF;
+      END IF;
+      UPDATE usrpref SET usrpref_value = NEW.crmacct_name
+      WHERE ((usrpref_username=NEW.crmacct_usr_username)
+        AND  (usrpref_name='propername')
+        AND  (usrpref_value!=NEW.crmacct_name));
+    END IF;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    IF (OLD.crmacct_cust_id IS NOT NULL) THEN
+      RAISE EXCEPTION 'Cannot delete CRM Account because it is a Customer [xtuple: deleteCrmAccount, -1]';
+    END IF;
+
+    IF (OLD.crmacct_emp_id IS NOT NULL) THEN
+      RAISE EXCEPTION 'Cannot delete CRM Account because it is an Employee [xtuple: deleteCrmAccount, -7]';
+    END IF;
+
+    IF (OLD.crmacct_prospect_id IS NOT NULL) THEN
+      RAISE EXCEPTION 'Cannot delete CRM Account because it is a Prospect [xtuple: deleteCrmAccount, -3]';
+    END IF;
+
+    DELETE FROM salesrep WHERE salesrep_id  = OLD.crmacct_salesrep_id;
+    IF (OLD.crmacct_salesrep_id IS NOT NULL) THEN
+      RAISE EXCEPTION 'Cannot delete CRM Account because it is a Sales Rep [xtuple: deleteCrmAccount, -6]';
+    END IF;
+
+    IF (OLD.crmacct_taxauth_id IS NOT NULL) THEN
+      RAISE EXCEPTION 'Cannot delete CRM Account because it is a Tax Authority [xtuple: deleteCrmAccount, -5]';
+    END IF;
+
+    IF (EXISTS(SELECT usename
+                 FROM pg_user
+                WHERE usename=OLD.crmacct_usr_username)) THEN
+      RAISE EXCEPTION 'Cannot delete CRM Account because it is a User [xtuple: deleteCrmAccount, -8]';
+    END IF;
+
+    IF (OLD.crmacct_vend_id IS NOT NULL) THEN
+      RAISE EXCEPTION 'Cannot delete CRM Account because it is a Vendor [xtuple: deleteCrmAccount, -2]';
+    END IF;
+
+    DELETE FROM imageass
+     WHERE (imageass_source_id=OLD.crmacct_id) AND (imageass_source='CRMA');
+    DELETE FROM url
+     WHERE (url_source_id=OLD.crmacct_id)      AND (url_source='CRMA');
+
+  END IF;
+
+  SELECT cmnttype_id INTO _cmnttypeid
+    FROM cmnttype
+   WHERE (cmnttype_name='ChangeLog');
+  IF (_cmnttypeid IS NOT NULL) THEN
+    IF (TG_OP = 'INSERT') THEN
+      PERFORM postComment(_cmnttypeid, 'CRMA', NEW.crmacct_id,
+                          ('Created by ' || getEffectiveXtUser()));
+
+    ELSIF (TG_OP = 'DELETE') THEN
+      PERFORM postComment(_cmnttypeid, 'CRMA', OLD.crmacct_id,
+                          'Deleted "' || OLD.crmacct_number || '"');
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER crmacctAfterTrigger ON crmacct;
+CREATE TRIGGER crmacctAfterTrigger AFTER INSERT OR UPDATE OR DELETE ON crmacct FOR EACH ROW EXECUTE PROCEDURE _crmacctAfterTrigger();
diff --git a/foundation-database/public/trigger_functions/curr_rate.sql b/foundation-database/public/trigger_functions/curr_rate.sql
new file mode 100644 (file)
index 0000000..624d03e
--- /dev/null
@@ -0,0 +1,45 @@
+CREATE OR REPLACE FUNCTION currExchangeCheckOverlap () RETURNS trigger AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+    numberOfOverlaps INTEGER NOT NULL := 0;
+    curr_string VARCHAR(16);
+    new_id INTEGER;
+BEGIN
+  new_id := NEW.curr_id;
+  -- ensure that effective date <= expiration date
+  IF NEW.curr_effective > NEW.curr_expires THEN
+    RAISE EXCEPTION
+      ''Effective date % must be earlier than expiration date %'',
+      NEW.curr_effective, NEW.curr_expires;
+  END IF;
+
+  -- ensure new exchange rate does not overlap in time with any others
+  SELECT count(*) INTO numberOfOverlaps
+    FROM curr_rate
+    WHERE curr_id = NEW.curr_id
+      AND curr_rate_id != NEW.curr_rate_id
+      AND (
+          (curr_effective BETWEEN
+              NEW.curr_effective AND NEW.curr_expires OR
+           curr_expires BETWEEN
+              NEW.curr_effective AND NEW.curr_expires)
+         OR (curr_effective <= NEW.curr_effective AND
+             curr_expires   >= NEW.curr_expires)
+      );
+  IF numberOfOverlaps > 0 THEN
+    SELECT currConcat(curr_symbol, curr_abbr)
+      INTO curr_string
+      FROM curr_symbol
+      WHERE curr_id = new_id;
+    RAISE EXCEPTION
+      ''The date range % to % overlaps with another date range.'',
+      NEW.curr_effective, NEW.curr_expires;
+  END IF;
+  RETURN NEW;
+END;
+' LANGUAGE 'plpgsql';
+
+DROP TRIGGER currExchangeCheckOverlap ON curr_rate;
+CREATE TRIGGER currExchangeCheckOverlap BEFORE INSERT OR UPDATE ON curr_rate
+    FOR EACH ROW EXECUTE PROCEDURE currExchangeCheckOverlap();
diff --git a/foundation-database/public/trigger_functions/curr_symbol.sql b/foundation-database/public/trigger_functions/curr_symbol.sql
new file mode 100644 (file)
index 0000000..3cbf009
--- /dev/null
@@ -0,0 +1,37 @@
+CREATE OR REPLACE FUNCTION currOneBase() RETURNS trigger AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  baseCount INTEGER := 0;
+BEGIN
+  IF NEW.curr_base = TRUE THEN
+    SELECT count(*)
+      INTO baseCount
+      FROM curr_symbol
+      WHERE curr_base = TRUE
+        AND curr_id != NEW.curr_id;
+    IF baseCount > 0 THEN
+      RAISE EXCEPTION
+          ''Cannot make % - % the base currency because one is already defined.'',
+          NEW.curr_symbol, NEW.curr_abbr;
+    ELSE
+      SELECT count(*)
+        INTO baseCount
+        FROM curr_rate
+        WHERE curr_id = NEW.curr_id;
+      IF baseCount = 0 THEN
+        -- put a row in the curr_rate table to avoid special-case
+        -- code for converting base currency to base currency
+        INSERT INTO curr_rate
+          (curr_id, curr_rate, curr_effective, curr_expires) VALUES
+          (NEW.curr_id, 1, startOfTime(), endOfTime());
+      END IF;
+    END IF;
+  END IF;
+  RETURN NEW;
+END;
+' LANGUAGE 'plpgsql';
+
+DROP TRIGGER currOneBase ON curr_symbol;
+CREATE TRIGGER currOneBase AFTER INSERT OR UPDATE ON curr_symbol
+    FOR EACH ROW EXECUTE PROCEDURE currOneBase();
diff --git a/foundation-database/public/trigger_functions/cust.sql b/foundation-database/public/trigger_functions/cust.sql
new file mode 100644 (file)
index 0000000..094b18e
--- /dev/null
@@ -0,0 +1,268 @@
+CREATE OR REPLACE FUNCTION _custTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple.
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF NOT (checkPrivilege('MaintainCustomerMasters') OR
+          checkPrivilege('PostMiscInvoices')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Customers.';
+  END IF;
+
+  IF (NEW.cust_number IS NULL) THEN
+        RAISE EXCEPTION 'You must supply a valid Customer Number.';
+  END IF;
+
+  IF (LENGTH(COALESCE(NEW.cust_name,''))=0) THEN
+        RAISE EXCEPTION 'You must supply a valid Customer Name.';
+  END IF;
+
+  IF (NEW.cust_custtype_id IS NULL) THEN
+        RAISE EXCEPTION 'You must supply a valid Customer Type ID.';
+  END IF;
+
+  IF (NEW.cust_salesrep_id IS NULL) THEN
+        RAISE EXCEPTION 'You must supply a valid Sales Rep ID.';
+  END IF;
+
+  IF (NEW.cust_terms_id IS NULL) THEN
+        RAISE EXCEPTION 'You must supply a valid Terms Code ID.';
+  END IF;
+
+  IF (TG_OP = 'INSERT' AND fetchMetricText('CRMAccountNumberGeneration') IN ('A','O')) THEN
+    PERFORM clearNumberIssue('CRMAccountNumber', NEW.cust_number);
+  END IF;
+
+  NEW.cust_number := UPPER(NEW.cust_number);
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'custTrigger');
+CREATE TRIGGER custTrigger BEFORE INSERT OR UPDATE ON custinfo
+       FOR EACH ROW EXECUTE PROCEDURE _custTrigger();
+
+CREATE OR REPLACE FUNCTION _custAfterTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple.
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid INTEGER;
+  _whsId      INTEGER := -1;
+
+BEGIN
+
+  IF (TG_OP = 'INSERT') THEN
+    -- http://www.postgresql.org/docs/current/static/plpgsql-control-structures.html#PLPGSQL-UPSERT-EXAMPLE
+    LOOP
+      UPDATE crmacct SET crmacct_cust_id=NEW.cust_id,
+                         crmacct_name=NEW.cust_name,
+                         crmacct_prospect_id=NULL
+      WHERE crmacct_number=NEW.cust_number;
+      IF (FOUND) THEN
+        DELETE FROM prospect WHERE prospect_id=NEW.cust_id;
+        EXIT;
+      END IF;
+      BEGIN
+        INSERT INTO crmacct(crmacct_number,  crmacct_name,    crmacct_active,
+                            crmacct_type,    crmacct_cust_id, crmacct_cntct_id_1,
+                            crmacct_cntct_id_2
+                  ) VALUES (NEW.cust_number, NEW.cust_name,   NEW.cust_active,
+                            'O',             NEW.cust_id,     NEW.cust_cntct_id,
+                            NEW.cust_corrcntct_id);
+        EXIT;
+      EXCEPTION WHEN unique_violation THEN
+            -- do nothing, and loop to try the UPDATE again
+      END;
+    END LOOP;
+
+    PERFORM updateCharAssignment('C', NEW.cust_id, char_id, charass_value)
+       FROM custtype
+       JOIN charass ON (custtype_id=charass_target_id AND charass_target_type='CT')
+       JOIN char ON (charass_char_id=char_id)
+       WHERE ((custtype_id=NEW.cust_custtype_id)
+          AND (custtype_char)
+          AND (charass_default));
+
+  ELSIF (TG_OP = 'UPDATE') THEN
+    UPDATE crmacct SET crmacct_number = NEW.cust_number
+    WHERE ((crmacct_cust_id=NEW.cust_id)
+      AND  (crmacct_number!=NEW.cust_number));
+
+    UPDATE crmacct SET crmacct_name = NEW.cust_name
+    WHERE ((crmacct_cust_id=NEW.cust_id)
+      AND  (crmacct_name!=NEW.cust_name));
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    PERFORM postEvent('NewCustomer', 'C', NEW.cust_id,
+                      NULL, NEW.cust_number,
+                      NULL, NULL, NULL, NULL);
+  END IF;
+
+  IF (fetchMetricBool('CustomerChangeLog')) THEN
+    SELECT cmnttype_id INTO _cmnttypeid
+      FROM cmnttype
+     WHERE (cmnttype_name='ChangeLog');
+
+    IF (_cmnttypeid IS NOT NULL) THEN
+      IF (TG_OP = 'INSERT') THEN
+        PERFORM postComment(_cmnttypeid, 'C', NEW.cust_id, 'Created');
+
+      ELSIF (TG_OP = 'UPDATE') THEN
+
+        IF (OLD.cust_number <> NEW.cust_number) THEN
+          PERFORM postComment( _cmnttypeid, 'C', NEW.cust_id,
+                              ('Number changed from "' || OLD.cust_number ||
+                               '" to "' || NEW.cust_number || '"') );
+        END IF;
+
+        IF (OLD.cust_name <> NEW.cust_name) THEN
+          PERFORM postComment( _cmnttypeid, 'C', NEW.cust_id,
+                              ('Name changed from "' || OLD.cust_name ||
+                               '" to "' || NEW.cust_name || '"') );
+        END IF;
+
+        IF (OLD.cust_active <> NEW.cust_active) THEN
+          PERFORM postComment(_cmnttypeid, 'C', NEW.cust_id,
+                              CASE WHEN NEW.cust_active THEN 'Activated'
+                                   ELSE 'Deactivated' END);
+        END IF;
+
+        IF (OLD.cust_discntprcnt <> NEW.cust_discntprcnt) THEN
+          PERFORM postComment(_cmnttypeid, 'C', NEW.cust_id,
+                              ('Discount changed from "' ||
+                               formatprcnt(OLD.cust_discntprcnt) || '%" to "' ||
+                               formatprcnt(NEW.cust_discntprcnt) || '%"') );
+        END IF;
+
+        IF (OLD.cust_creditlmt <> NEW.cust_creditlmt) THEN
+          PERFORM postComment(_cmnttypeid, 'C', NEW.cust_id,
+                              ('Credit Limit changed from ' || formatMoney(OLD.cust_creditlmt) ||
+                               ' to ' || formatMoney(NEW.cust_creditlmt)));
+        END IF;
+
+        IF (OLD.cust_creditstatus <> NEW.cust_creditstatus) THEN
+          PERFORM postComment(_cmnttypeid, 'C', NEW.cust_id,
+                              ('Credit Status Changed from "' ||
+                               CASE OLD.cust_creditstatus
+                                    WHEN 'G' THEN 'In Good Standing'
+                                    WHEN 'W' THEN 'Credit Warning'
+                                    WHEN 'H' THEN 'Credit Hold'
+                                    ELSE 'Unknown/Error'
+                               END || '" to "' ||
+                               CASE NEW.cust_creditstatus
+                                    WHEN 'G' THEN 'In Good Standing'
+                                    WHEN 'W' THEN 'Credit Warning'
+                                    WHEN 'H' THEN 'Credit Hold'
+                                    ELSE 'Unknown/Error'
+                               END || '"') );
+        END IF;
+
+        IF (OLD.cust_custtype_id <> NEW.cust_custtype_id) THEN
+          PERFORM postComment(_cmnttypeid, 'C', NEW.cust_id,
+                              ('Customer type changed from "' ||
+                               (SELECT custtype_code FROM custtype
+                                 WHERE custtype_id = OLD.cust_custtype_id) || '" to "' ||
+                               (SELECT custtype_code FROM custtype
+                                 WHERE custtype_id = NEW.cust_custtype_id) || '"') );
+        END IF;
+
+        IF (COALESCE(OLD.cust_gracedays,-1) <> COALESCE(NEW.cust_gracedays,-1)) THEN
+          PERFORM postComment(_cmnttypeid, 'C', NEW.cust_id,
+                              ('Grace Days changed from "' ||
+                               COALESCE(TEXT(OLD.cust_gracedays), 'Default') ||
+                               '" to "' ||
+                               COALESCE(TEXT(NEW.cust_gracedays), 'Default') || '"'));
+        END IF;
+
+        IF (OLD.cust_terms_id <> NEW.cust_terms_id) THEN
+          PERFORM postComment(_cmnttypeid, 'C', NEW.cust_id,
+                              ('Terms changed from "' ||
+                               (SELECT terms_code FROM terms
+                                 WHERE terms_id = OLD.cust_terms_id) || '" to "' ||
+                               (SELECT terms_code FROM terms
+                                 WHERE terms_id = NEW.cust_terms_id) || '"'));
+        END IF;
+
+      END IF;
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'custAfterTrigger');
+CREATE TRIGGER custAfterTrigger AFTER INSERT OR UPDATE ON custinfo
+       FOR EACH ROW EXECUTE PROCEDURE _custAfterTrigger();
+
+CREATE OR REPLACE FUNCTION _custinfoBeforeDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple.
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF NOT (checkPrivilege('MaintainCustomerMasters')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Customers.';
+  END IF;
+
+  UPDATE crmacct SET crmacct_cust_id = NULL
+   WHERE crmacct_cust_id = OLD.cust_id;
+
+  RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'custinfoBeforeDeleteTrigger');
+CREATE TRIGGER custinfoBeforeDeleteTrigger BEFORE DELETE ON custinfo
+       FOR EACH ROW EXECUTE PROCEDURE _custinfoBeforeDeleteTrigger();
+
+CREATE OR REPLACE FUNCTION _custinfoAfterDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple.
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  -- handle transitory state when converting customer to prospect
+  IF EXISTS(SELECT quhead_id
+              FROM quhead
+             WHERE (quhead_cust_id=OLD.cust_id) AND
+     NOT EXISTS(SELECT prospect_id
+                  FROM prospect
+                 WHERE prospect_id=OLD.cust_id)) THEN
+    RAISE EXCEPTION '[xtuple: deleteCustomer, -8]';
+  END IF;
+
+  IF EXISTS(SELECT invchead_id
+              FROM invchead
+             WHERE (invchead_cust_id=OLD.cust_id)) THEN
+    RAISE EXCEPTION '[xtuple: deleteCustomer, -7]';
+  END IF;
+  -- end TODO
+
+  IF EXISTS(SELECT checkhead_recip_id
+              FROM checkhead
+             WHERE ((checkhead_recip_id=OLD.cust_id)
+               AND  (checkhead_recip_type='C'))) THEN
+    RAISE EXCEPTION '[xtuple: deleteCustomer, -6]';
+  END IF;
+
+  DELETE FROM taxreg
+   WHERE ((taxreg_rel_type='C')
+     AND  (taxreg_rel_id=OLD.cust_id));
+
+  DELETE FROM ipsass
+   WHERE (ipsass_cust_id=OLD.cust_id);
+
+  DELETE FROM docass WHERE docass_source_id = OLD.cust_id AND docass_source_type = 'C';
+  DELETE FROM docass WHERE docass_target_id = OLD.cust_id AND docass_target_type = 'C';
+
+  IF (fetchMetricBool('CustomerChangeLog')) THEN
+    PERFORM postComment(cmnttype_id, 'C', OLD.cust_id,
+                        ('Deleted "' || OLD.cust_number || '"'))
+      FROM cmnttype
+     WHERE (cmnttype_name='ChangeLog');
+  END IF;
+
+  RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'custinfoAfterDeleteTrigger');
+CREATE TRIGGER custinfoAfterDeleteTrigger AFTER DELETE ON custinfo
+       FOR EACH ROW EXECUTE PROCEDURE _custinfoAfterDeleteTrigger();
diff --git a/foundation-database/public/trigger_functions/custtype.sql b/foundation-database/public/trigger_functions/custtype.sql
new file mode 100644 (file)
index 0000000..fb1f686
--- /dev/null
@@ -0,0 +1,49 @@
+CREATE OR REPLACE FUNCTION _custtypeTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _check      BOOLEAN;
+  _code       TEXT;
+
+BEGIN
+
+--  Checks
+  IF (TG_OP IN ('INSERT','UPDATE')) THEN
+
+    IF (LENGTH(COALESCE(NEW.custtype_code, ''))=0) THEN
+      RAISE EXCEPTION 'You must supply a valid Customer Type Code.';
+    END IF;
+
+    SELECT custtype_code INTO _code
+    FROM custtype
+    WHERE ( (UPPER(custtype_code)=UPPER(NEW.custtype_code))
+      AND (custtype_id<>NEW.custtype_id) );
+    IF (FOUND) THEN
+      RAISE EXCEPTION 'The Customer Type Code entered cannot be used as it is in use.';
+    END IF;
+
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE PLPGSQL;
+
+SELECT dropIfExists('TRIGGER', 'custtypeTrigger');
+CREATE TRIGGER custtypeTrigger BEFORE INSERT OR UPDATE ON custtype FOR EACH ROW EXECUTE PROCEDURE _custtypeTrigger();
+
+CREATE OR REPLACE FUNCTION _custtypeAfterDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (SELECT fetchMetricValue('DefaultCustType') = OLD.custtype_id) THEN
+    RAISE EXCEPTION 'Cannot delete the default Customer Type [xtuple: custtype, -1, %]',
+                    OLD.custtype_code;
+  END IF;
+
+  RETURN OLD;
+END;
+$$ LANGUAGE PLPGSQL;
+
+DROP TRIGGER IF EXISTS custtypeAfterDeleteTrigger ON custtype;
+CREATE TRIGGER custtypeAfterDeleteTrigger AFTER DELETE ON custtype
+  FOR EACH ROW EXECUTE PROCEDURE _custtypeAfterDeleteTrigger();
diff --git a/foundation-database/public/trigger_functions/docass.sql b/foundation-database/public/trigger_functions/docass.sql
new file mode 100644 (file)
index 0000000..aaf6eca
--- /dev/null
@@ -0,0 +1,14 @@
+CREATE OR REPLACE FUNCTION _docassTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (NEW.docass_source_type = 'INCDT') THEN
+    UPDATE incdt SET incdt_updated = now() WHERE incdt_id = NEW.docass_source_id;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropifexists('TRIGGER' ,'docassTrigger');
+CREATE TRIGGER docassTrigger AFTER INSERT OR UPDATE ON docass FOR EACH ROW EXECUTE PROCEDURE _docassTrigger();
diff --git a/foundation-database/public/trigger_functions/emp.sql b/foundation-database/public/trigger_functions/emp.sql
new file mode 100644 (file)
index 0000000..62962a0
--- /dev/null
@@ -0,0 +1,195 @@
+CREATE OR REPLACE FUNCTION _empBeforeTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+  IF NOT (checkPrivilege('MaintainEmployees')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Employees.';
+  END IF;
+
+  IF (NEW.emp_code IS NULL) THEN
+    RAISE EXCEPTION 'You must supply a valid Employee Code.';
+  END IF;
+
+  IF (NEW.emp_number IS NULL) THEN
+    RAISE EXCEPTION 'You must supply a valid Employee Number.';
+  END IF;
+
+  IF (NEW.emp_id = NEW.emp_mgr_emp_id) THEN
+    RAISE EXCEPTION 'An Employee may not be his or her own Manager.';
+  END IF;
+
+  -- ERROR:  cannot use column references in default expression
+  IF (NEW.emp_name IS NULL) THEN
+    NEW.emp_name = COALESCE(formatCntctName(NEW.emp_cntct_id), NEW.emp_number);
+  END IF;
+
+  IF (TG_OP = 'INSERT' AND fetchMetricText('CRMAccountNumberGeneration') IN ('A','O')) THEN
+    PERFORM clearNumberIssue('CRMAccountNumber', NEW.emp_number);
+  END IF;
+
+  NEW.emp_code := UPPER(NEW.emp_code);
+
+  -- deprecated column emp_username
+  IF (TG_OP = 'UPDATE' AND
+      LOWER(NEW.emp_username) != LOWER(NEW.emp_code) AND
+      EXISTS(SELECT 1
+               FROM crmacct
+              WHERE crmacct_emp_id = NEW.emp_id
+                AND crmacct_usr_username IS NOT NULL)) THEN
+    NEW.emp_username = LOWER(NEW.emp_code);
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'empBeforeTrigger');
+CREATE TRIGGER empBeforeTrigger BEFORE INSERT OR UPDATE ON emp
+       FOR EACH ROW EXECUTE PROCEDURE _empBeforeTrigger();
+
+CREATE OR REPLACE FUNCTION _empAfterTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid     INTEGER;
+  _newcrmacctname TEXT;
+
+BEGIN
+
+  IF (TG_OP = 'INSERT') THEN
+    -- http://www.postgresql.org/docs/current/static/plpgsql-control-structures.html#PLPGSQL-UPSERT-EXAMPLE
+    LOOP
+      UPDATE crmacct SET crmacct_emp_id=NEW.emp_id,
+                         crmacct_name=NEW.emp_name
+       WHERE crmacct_number=NEW.emp_code;
+      IF (FOUND) THEN
+        EXIT;
+      END IF;
+      BEGIN
+        INSERT INTO crmacct(crmacct_number,  crmacct_name,    crmacct_active,
+                            crmacct_type,    crmacct_emp_id,  crmacct_cntct_id_1
+                  ) VALUES (NEW.emp_code,    NEW.emp_name,    NEW.emp_active, 
+                            'I',             NEW.emp_id,      NEW.emp_cntct_id);
+        EXIT;
+      EXCEPTION WHEN unique_violation THEN
+            -- do nothing, and loop to try the UPDATE again
+      END;
+    END LOOP;
+
+    /* TODO: default characteristic assignments based on empgrp? */
+
+  ELSIF (TG_OP = 'UPDATE') THEN
+    UPDATE crmacct SET crmacct_number = NEW.emp_code
+    WHERE ((crmacct_emp_id=NEW.emp_id)
+      AND  (crmacct_number!=NEW.emp_code));
+
+    UPDATE crmacct SET crmacct_name = NEW.emp_name
+    WHERE ((crmacct_emp_id=NEW.emp_id)
+      AND  (crmacct_name!=NEW.emp_name));
+  END IF;
+
+  IF (fetchMetricBool('EmployeeChangeLog')) THEN
+    SELECT cmnttype_id INTO _cmnttypeid
+      FROM cmnttype
+     WHERE (cmnttype_name='ChangeLog');
+
+    IF (_cmnttypeid IS NOT NULL) THEN
+      IF (TG_OP = 'INSERT') THEN
+        PERFORM postComment(_cmnttypeid, 'EMP', NEW.emp_id, 'Created');
+
+      ELSIF (TG_OP = 'UPDATE') THEN
+
+        IF (OLD.emp_number <> NEW.emp_number) THEN
+          PERFORM postComment(_cmnttypeid, 'EMP', NEW.emp_id,
+                              ('Number Changed from "' || OLD.emp_number ||
+                               '" to "' || NEW.emp_number || '"'));
+        END IF;
+
+        IF (OLD.emp_code <> NEW.emp_code) THEN
+          PERFORM postComment(_cmnttypeid, 'EMP', NEW.emp_id,
+                              ('Code Changed from "' || OLD.emp_code ||
+                               '" to "' || NEW.emp_code || '"'));
+        END IF;
+
+        IF (OLD.emp_active <> NEW.emp_active) THEN
+          PERFORM postComment(_cmnttypeid, 'EMP', NEW.emp_id,
+                              CASE WHEN NEW.emp_active THEN 'Activated'
+                                   ELSE 'Deactivated' END);
+        END IF;
+
+        IF (COALESCE(OLD.emp_dept_id, -1) <> COALESCE(NEW.emp_dept_id, -1)) THEN
+          PERFORM postComment(_cmnttypeid, 'EMP', NEW.emp_id,
+                              ('Department Changed from "' ||
+                               COALESCE((SELECT dept_number FROM dept
+                                          WHERE dept_id=OLD.emp_dept_id), '')
+                               || '" to "' ||
+                               COALESCE((SELECT dept_number FROM dept
+                                          WHERE dept_id=NEW.emp_dept_id), '') || '"'));
+        END IF;
+
+        IF (COALESCE(OLD.emp_shift_id, -1) <> COALESCE(NEW.emp_shift_id, -1)) THEN
+          PERFORM postComment(_cmnttypeid, 'EMP', NEW.emp_id,
+                              ('Shift Changed from "' ||
+                               COALESCE((SELECT shift_number FROM shift
+                                          WHERE shift_id=OLD.emp_shift_id), '')
+                               || '" to "' ||
+                               COALESCE((SELECT shift_number FROM shift
+                                          WHERE shift_id=NEW.emp_shift_id), '') || '"'));
+        END IF;
+
+      END IF;
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'empAfterTrigger');
+CREATE TRIGGER empAfterTrigger AFTER INSERT OR UPDATE ON emp
+       FOR EACH ROW EXECUTE PROCEDURE _empAfterTrigger();
+
+CREATE OR REPLACE FUNCTION _empBeforeDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF NOT (checkPrivilege('MaintainEmployees')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Employees.';
+  END IF;
+
+  UPDATE crmacct SET crmacct_emp_id = NULL
+   WHERE crmacct_emp_id = OLD.emp_id;
+
+  UPDATE salesrep SET salesrep_emp_id = NULL
+   WHERE salesrep_emp_id = OLD.emp_id;
+
+  DELETE FROM docass WHERE docass_source_id = OLD.emp_id AND docass_source_type = 'EMP';
+  DELETE FROM docass WHERE docass_target_id = OLD.emp_id AND docass_target_type = 'EMP';
+
+  RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'empBeforeDeleteTrigger');
+CREATE TRIGGER empBeforeDeleteTrigger BEFORE DELETE ON emp
+       FOR EACH ROW EXECUTE PROCEDURE _empBeforeDeleteTrigger();
+
+CREATE OR REPLACE FUNCTION _empAfterDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (fetchMetricBool('EmployeeChangeLog')) THEN
+    PERFORM postComment(cmnttype_id, 'EMP', OLD.emp_id,
+                        ('Deleted "' || OLD.emp_code || '"'))
+      FROM cmnttype
+     WHERE (cmnttype_name='ChangeLog');
+  END IF;
+
+  RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'empAfterDeleteTrigger');
+CREATE TRIGGER empAfterDeleteTrigger AFTER DELETE ON emp
+       FOR EACH ROW EXECUTE PROCEDURE _empAfterDeleteTrigger();
diff --git a/foundation-database/public/trigger_functions/evntlog.sql b/foundation-database/public/trigger_functions/evntlog.sql
new file mode 100644 (file)
index 0000000..81608f4
--- /dev/null
@@ -0,0 +1,22 @@
+CREATE OR REPLACE FUNCTION _evntlogAfterInsertTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _r RECORD;
+
+BEGIN
+
+  IF (NEW.evntlog_username = 'autopilot') THEN
+    SELECT * INTO _r FROM evnttype WHERE (evnttype_id=NEW.evntlog_evnttype_id);
+    IF (_r.evnttype_name = 'SoCreated') THEN
+      PERFORM createPrjToSale(NEW.evntlog_ord_id);
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'evntlogAfterInsertTrigger');
+CREATE TRIGGER evntlogAfterInsertTrigger AFTER INSERT ON evntlog
+       FOR EACH ROW EXECUTE PROCEDURE _evntlogAfterInsertTrigger();
diff --git a/foundation-database/public/trigger_functions/gltrans.sql b/foundation-database/public/trigger_functions/gltrans.sql
new file mode 100644 (file)
index 0000000..4947c58
--- /dev/null
@@ -0,0 +1,100 @@
+CREATE OR REPLACE FUNCTION _gltransInsertTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _reqNotes BOOLEAN;
+  _externalCompany      BOOLEAN := false;
+BEGIN
+  -- Checks
+  -- Start with privileges
+  IF ((NEW.gltrans_doctype='JE') AND (NOT checkPrivilege('PostJournalEntries'))) THEN
+      RAISE EXCEPTION 'You do not have privileges to create a Journal Entry.';
+  END IF;
+
+  SELECT company_external INTO _externalCompany
+  FROM company JOIN accnt ON (company_number=accnt_company)
+  WHERE (accnt_id=NEW.gltrans_accnt_id);
+  IF (_externalCompany) THEN
+    RAISE EXCEPTION 'Transactions are not allowed for G/L Accounts with External Company segments.';
+  END IF;
+  -- RAISE NOTICE '_gltransInsertTrigger(): company_external = %', _externalCompany;
+
+  SELECT metric_value='t'
+    INTO _reqNotes
+    FROM metric
+   WHERE(metric_name='MandatoryGLEntryNotes');
+  IF (_reqNotes IS NULL) THEN
+    _reqNotes := false;
+  END IF;
+  IF ((NEW.gltrans_doctype='JE') AND _reqNotes AND (TRIM(BOTH FROM COALESCE(NEW.gltrans_notes,''))='')) THEN
+      RAISE EXCEPTION 'Notes are required for Journal Entries.';
+  END IF;
+  
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'gltransInsertTrigger');
+CREATE TRIGGER gltransInsertTrigger BEFORE INSERT ON gltrans FOR EACH ROW EXECUTE PROCEDURE _gltransInsertTrigger();
+
+CREATE OR REPLACE FUNCTION _gltransAlterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _externalCompany      BOOLEAN := false;
+  _updated BOOLEAN := false;
+BEGIN
+  IF(TG_OP='DELETE') THEN
+    RAISE EXCEPTION 'You may not delete G/L Transactions once they have been created.';
+  ELSIF (TG_OP = 'UPDATE') THEN
+    SELECT company_external INTO _externalCompany
+    FROM company JOIN accnt ON (company_number=accnt_company)
+    WHERE (accnt_id=NEW.gltrans_accnt_id);
+    IF (_externalCompany) THEN
+      RAISE EXCEPTION 'Transactions are not allowed for G/L Accounts with External Company segments.';
+    END IF;
+
+    IF(OLD.gltrans_id != NEW.gltrans_id) THEN
+      _updated := true;
+    ELSIF(OLD.gltrans_date != NEW.gltrans_date) THEN
+      _updated := true;
+    ELSIF(OLD.gltrans_accnt_id != NEW.gltrans_accnt_id) THEN
+      _updated := true;
+    ELSIF(OLD.gltrans_amount != NEW.gltrans_amount) THEN
+      _updated := true;
+    ELSIF(OLD.gltrans_username != NEW.gltrans_username) THEN
+      _updated := true;
+    ELSIF( (OLD.gltrans_sequence IS NULL     AND NEW.gltrans_sequence IS NOT NULL)
+        OR (OLD.gltrans_sequence IS NOT NULL AND NEW.gltrans_sequence IS NULL)
+        OR (COALESCE(OLD.gltrans_sequence,0) != COALESCE(NEW.gltrans_sequence,0)) ) THEN
+      _updated := true;
+    ELSIF( (OLD.gltrans_created IS NULL     AND NEW.gltrans_created IS NOT NULL)
+        OR (OLD.gltrans_created IS NOT NULL AND NEW.gltrans_created IS NULL)
+        OR (COALESCE(OLD.gltrans_created,now()) != COALESCE(NEW.gltrans_created,now())) ) THEN
+      _updated := true;
+    ELSIF( (OLD.gltrans_source IS NULL     AND NEW.gltrans_source IS NOT NULL)
+        OR (OLD.gltrans_source IS NOT NULL AND NEW.gltrans_source IS NULL)
+        OR (COALESCE(OLD.gltrans_source,'') != COALESCE(NEW.gltrans_source,'')) ) THEN
+      _updated := true;
+    ELSIF( (OLD.gltrans_docnumber IS NULL     AND NEW.gltrans_docnumber IS NOT NULL)
+        OR (OLD.gltrans_docnumber IS NOT NULL AND NEW.gltrans_docnumber IS NULL)
+        OR (COALESCE(OLD.gltrans_docnumber,'') != COALESCE(NEW.gltrans_docnumber,'')) ) THEN
+      _updated := true;
+    ELSIF( (OLD.gltrans_doctype IS NULL     AND NEW.gltrans_doctype IS NOT NULL)
+        OR (OLD.gltrans_doctype IS NOT NULL AND NEW.gltrans_doctype IS NULL)
+        OR (COALESCE(OLD.gltrans_doctype,'') != COALESCE(NEW.gltrans_doctype,'')) ) THEN
+      _updated := true;
+    END IF;
+
+    IF(_updated) THEN
+      RAISE EXCEPTION 'You may not alter some G/L Transaction fields once they have been created.';
+    END IF;
+  ELSE
+    RAISE EXCEPTION 'trigger for gltrans table called in unexpected state.';
+  END IF;
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'gltransAlterTrigger');
+CREATE TRIGGER gltransAlterTrigger BEFORE UPDATE OR DELETE ON gltrans FOR EACH ROW EXECUTE PROCEDURE _gltransAlterTrigger();
diff --git a/foundation-database/public/trigger_functions/grppriv.sql b/foundation-database/public/trigger_functions/grppriv.sql
new file mode 100644 (file)
index 0000000..47d6ec4
--- /dev/null
@@ -0,0 +1,28 @@
+CREATE OR REPLACE FUNCTION _grpprivTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _check BOOLEAN;
+  _returnVal INTEGER;
+BEGIN
+  -- This looks like a candidate for a foreign key but isn't.
+  -- fkeys don't work if the foreign key value resides in a child of the 
+  -- table and not the table itself.
+  IF ((TG_OP = 'UPDATE' OR TG_OP = 'INSERT') AND
+      (NOT EXISTS(SELECT priv_id
+                  FROM priv
+                  WHERE (priv_id=NEW.grppriv_priv_id)))) THEN
+    RAISE EXCEPTION 'Privilege id % does not exist or is part of a disabled package.',
+                NEW.grppriv_priv_id;
+    RETURN OLD;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('trigger', 'grpprivTrigger');
+CREATE TRIGGER grpprivTrigger BEFORE INSERT OR UPDATE ON grppriv FOR EACH ROW EXECUTE PROCEDURE _grpprivTrigger();
diff --git a/foundation-database/public/trigger_functions/imageass.sql b/foundation-database/public/trigger_functions/imageass.sql
new file mode 100644 (file)
index 0000000..ee23e3e
--- /dev/null
@@ -0,0 +1,14 @@
+CREATE OR REPLACE FUNCTION _imageassTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (NEW.imageass_source = 'INCDT') THEN
+    UPDATE incdt SET incdt_updated = now() WHERE incdt_id = NEW.imageass_source_id;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropifexists('TRIGGER' ,'imageassTrigger');
+CREATE TRIGGER imageassTrigger AFTER INSERT OR UPDATE ON imageass FOR EACH ROW EXECUTE PROCEDURE _imageassTrigger();
diff --git a/foundation-database/public/trigger_functions/incdt.sql b/foundation-database/public/trigger_functions/incdt.sql
new file mode 100644 (file)
index 0000000..7a50ce2
--- /dev/null
@@ -0,0 +1,329 @@
+CREATE OR REPLACE FUNCTION _incdtBeforeTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _rec          RECORD;
+  _check        BOOLEAN;
+  _crmacct      INTEGER;
+
+BEGIN
+
+  IF(TG_OP = 'DELETE') THEN
+    _rec := OLD;
+  ELSE
+    _rec := NEW;
+  END IF;
+
+  -- Set the incident number if blank
+  IF (TG_OP = 'INSERT') THEN
+    IF (NEW.incdt_number IS NULL) THEN
+      SELECT fetchIncidentNumber() INTO NEW.incdt_number;
+    END IF;
+
+    --- clear the number from the issue cache
+    PERFORM clearNumberIssue('IncidentNumber', NEW.incdt_number);
+  END IF;
+
+  -- Description is required
+  IF (LENGTH(COALESCE(NEW.incdt_summary,''))=0) THEN
+    RAISE EXCEPTION 'You must supply a valid Incident Description.';
+  END IF;
+  
+  -- CRM Account is required
+  IF (NEW.incdt_crmacct_id IS NULL) THEN
+    RAISE EXCEPTION 'You must supply a valid CRM Account.';
+  END IF;
+
+  -- Contact is required
+  IF (NEW.incdt_cntct_id IS NULL) THEN
+    RAISE EXCEPTION 'You must supply a valid Contact.';
+  END IF;
+
+  NEW.incdt_updated := now();
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'incdtbeforetrigger');
+CREATE TRIGGER incdtbeforetrigger
+  BEFORE INSERT OR UPDATE
+  ON incdt
+  FOR EACH ROW
+  EXECUTE PROCEDURE _incdtBeforeTrigger();
+
+CREATE OR REPLACE FUNCTION _incdtBeforeDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _recurid     INTEGER;
+  _newparentid INTEGER;
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    SELECT recur_id INTO _recurid
+      FROM recur
+     WHERE ((recur_parent_id=OLD.incdt_id)
+        AND (recur_parent_type='INCDT'));
+
+     IF (_recurid IS NOT NULL) THEN
+       SELECT MIN(incdt_id) INTO _newparentid
+         FROM incdt
+        WHERE ((incdt_recurring_incdt_id=OLD.inctd_id)
+           AND (incdt_id!=OLD.incdt_id));
+
+      -- client is responsible for warning about deleting a recurring incdt
+      IF (_newparentid IS NULL) THEN
+        DELETE FROM recur WHERE recur_id=_recurid;
+      ELSE
+        UPDATE recur SET recur_parent_id=_newparentid
+         WHERE recur_id=_recurid;
+      END IF;
+    END IF;
+
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'incdtbeforedeletetrigger');
+CREATE TRIGGER incdtbeforedeletetrigger
+  BEFORE DELETE
+  ON incdt
+  FOR EACH ROW
+  EXECUTE PROCEDURE _incdtBeforeDeleteTrigger();
+
+CREATE OR REPLACE FUNCTION _incdttrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _r           RECORD;
+  _counter     INTEGER :=  0;
+  _whsId       INTEGER := -1;
+  _evntType    TEXT;
+  _cmnttypeid   INTEGER := -1;
+  _cmntid       INTEGER := -1;
+BEGIN
+
+  SELECT cmnttype_id INTO _cmnttypeid
+    FROM cmnttype
+    WHERE (cmnttype_name='Notes to Comment');
+  IF NOT FOUND OR _cmnttypeid IS NULL THEN
+    _cmnttypeid := -1;
+  END IF;
+
+  IF (TG_OP = 'DELETE') THEN
+--  This should never happen
+    RETURN OLD;
+  ELSIF (TG_OP = 'INSERT') THEN
+    INSERT INTO incdthist
+         (incdthist_incdt_id,
+          incdthist_change, incdthist_target_id,
+          incdthist_descrip)
+    VALUES(NEW.incdt_id,
+          'N', NULL,
+          'Incident Added');
+
+    _evntType = 'NewIncident';
+
+    IF (_cmnttypeid <> -1 AND COALESCE(NEW.incdt_descrip, '') <> '') THEN
+      PERFORM postComment(_cmnttypeid, 'INCDT', NEW.incdt_id, NEW.incdt_descrip);
+    END IF;
+  ELSIF (TG_OP = 'UPDATE') THEN
+    _evntType = 'UpdatedIncident';
+
+    IF (COALESCE(NEW.incdt_cntct_id,-1) <> COALESCE(OLD.incdt_cntct_id,-1)) THEN
+      INSERT INTO incdthist
+           (incdthist_incdt_id,
+            incdthist_change, incdthist_target_id,
+            incdthist_descrip)
+      VALUES(NEW.incdt_id,
+            'C', NEW.incdt_cntct_id,
+            ('Contact Changed: "' ||
+              COALESCE((SELECT cntct_first_name || ' ' || cntct_last_name
+                          FROM cntct
+                         WHERE (cntct_id=OLD.incdt_cntct_id)), '')
+             || '" -> "' ||
+              COALESCE((SELECT cntct_first_name || ' ' || cntct_last_name
+                          FROM cntct
+                         WHERE (cntct_id=NEW.incdt_cntct_id)), '')
+             || '"') );
+    END IF;
+
+    IF (COALESCE(NEW.incdt_summary,'') <> COALESCE(OLD.incdt_summary,'')) THEN
+      INSERT INTO incdthist
+           (incdthist_incdt_id,
+            incdthist_descrip)
+      VALUES(NEW.incdt_id,
+            ('Description Updated: "' ||
+              COALESCE(OLD.incdt_summary, '') ||
+             '" -> "' ||
+              COALESCE(NEW.incdt_summary, '') ||
+             '"') );
+    END IF;
+
+    IF (COALESCE(NEW.incdt_descrip,'') <> COALESCE(OLD.incdt_descrip,'')) THEN
+      INSERT INTO incdthist
+           (incdthist_incdt_id,
+            incdthist_descrip)
+      VALUES(NEW.incdt_id,
+            ('Notes Updated: "' ||
+              substr(COALESCE(OLD.incdt_descrip, ''), 1, 20) ||
+             '..." -> "' ||
+              substr(COALESCE(NEW.incdt_descrip, ''), 1, 20) ||
+             '..."') );
+
+      IF (_cmnttypeid <> -1) THEN
+        -- find an existing comment
+        SELECT comment_id
+          INTO _cmntid
+          FROM comment
+         WHERE comment_source = 'INCDT'
+           AND comment_source_id = NEW.incdt_id
+           -- back out change for 21068
+           -- AND comment_user = getEffectiveXtUser()
+           AND comment_cmnttype_id = _cmnttypeid;
+        IF FOUND THEN
+          UPDATE comment SET comment_text = NEW.incdt_descrip
+          WHERE comment_id = _cmntid;
+        ELSE
+          PERFORM postComment(_cmnttypeid, 'INCDT', NEW.incdt_id, NEW.incdt_descrip);
+        END IF;
+      END IF;
+    END IF;
+
+    IF (NEW.incdt_status <> OLD.incdt_status) THEN
+      INSERT INTO incdthist
+           (incdthist_incdt_id,
+            incdthist_change, incdthist_target_id,
+            incdthist_descrip)
+      VALUES(NEW.incdt_id,
+            'S', NULL,
+            ('Status Changed: ' ||
+             CASE WHEN(OLD.incdt_status='N') THEN 'New'
+                  WHEN(OLD.incdt_status='F') THEN 'Feedback'
+                  WHEN(OLD.incdt_status='C') THEN 'Confirmed'
+                  WHEN(OLD.incdt_status='A') THEN 'Assigned'
+                  WHEN(OLD.incdt_status='R') THEN 'Resolved'
+                  WHEN(OLD.incdt_status='L') THEN 'Closed'
+                  ELSE OLD.incdt_status
+             END
+             || ' -> ' ||
+             CASE WHEN(NEW.incdt_status='N') THEN 'New'
+                  WHEN(NEW.incdt_status='F') THEN 'Feedback'
+                  WHEN(NEW.incdt_status='C') THEN 'Confirmed'
+                  WHEN(NEW.incdt_status='A') THEN 'Assigned'
+                  WHEN(NEW.incdt_status='R') THEN 'Resolved'
+                  WHEN(NEW.incdt_status='L') THEN 'Closed'
+                  ELSE NEW.incdt_status
+             END
+             ) );
+      IF (NEW.incdt_status = 'L') THEN
+       _evntType = 'ClosedIncident';
+      ELSIF (OLD.incdt_status = 'L') THEN
+       _evntType = 'ReopenedIncident';
+      END IF;
+    END IF;
+
+    IF (COALESCE(NEW.incdt_assigned_username,'') <> COALESCE(OLD.incdt_assigned_username,'')) THEN
+      INSERT INTO incdthist
+           (incdthist_incdt_id,
+            incdthist_change, incdthist_target_id,
+            incdthist_descrip)
+      VALUES(NEW.incdt_id,
+            'A', NULL,
+            ('Assigned to: "' ||
+              COALESCE(OLD.incdt_assigned_username, '') ||
+             '" -> "' ||
+              COALESCE(NEW.incdt_assigned_username, '') ||
+             '"') );
+    END IF;
+
+    IF (COALESCE(NEW.incdt_incdtcat_id,-1) <> COALESCE(OLD.incdt_incdtcat_id,-1)) THEN
+      INSERT INTO incdthist
+           (incdthist_incdt_id,
+            incdthist_change, incdthist_target_id,
+            incdthist_descrip)
+      VALUES(NEW.incdt_id,
+            'T', NEW.incdt_incdtcat_id,
+            ('Category Changed: ' ||
+              COALESCE((SELECT incdtcat_name
+                          FROM incdtcat
+                         WHERE (incdtcat_id=OLD.incdt_incdtcat_id)), '')
+             || ' -> ' ||
+              COALESCE((SELECT incdtcat_name
+                          FROM incdtcat
+                         WHERE (incdtcat_id=NEW.incdt_incdtcat_id)), '')
+             || '') );
+    END IF;
+
+    IF (COALESCE(NEW.incdt_incdtseverity_id,-1) <> COALESCE(OLD.incdt_incdtseverity_id,-1)) THEN
+      INSERT INTO incdthist
+           (incdthist_incdt_id,
+            incdthist_change, incdthist_target_id,
+            incdthist_descrip)
+      VALUES(NEW.incdt_id,
+            'V', NEW.incdt_incdtseverity_id,
+            ('Severity Changed: ' ||
+              COALESCE((SELECT incdtseverity_name
+                          FROM incdtseverity
+                         WHERE (incdtseverity_id=OLD.incdt_incdtseverity_id)), '')
+             || ' -> ' ||
+              COALESCE((SELECT incdtseverity_name
+                          FROM incdtseverity
+                         WHERE (incdtseverity_id=NEW.incdt_incdtseverity_id)), '')
+             || '') );
+    END IF;
+
+    IF (COALESCE(NEW.incdt_incdtpriority_id,-1) <> COALESCE(OLD.incdt_incdtpriority_id,-1)) THEN
+      INSERT INTO incdthist
+           (incdthist_incdt_id,
+            incdthist_change, incdthist_target_id,
+            incdthist_descrip)
+      VALUES(NEW.incdt_id,
+            'P', NEW.incdt_incdtpriority_id,
+            ('Priority Changed: ' ||
+              COALESCE((SELECT incdtpriority_name
+                          FROM incdtpriority
+                         WHERE (incdtpriority_id=OLD.incdt_incdtpriority_id)), '')
+             || ' -> ' ||
+              COALESCE((SELECT incdtpriority_name
+                          FROM incdtpriority
+                         WHERE (incdtpriority_id=NEW.incdt_incdtpriority_id)), '')
+             || '') );
+    END IF;
+
+    IF (COALESCE(NEW.incdt_incdtresolution_id,-1) <> COALESCE(OLD.incdt_incdtresolution_id,-1)) THEN
+      INSERT INTO incdthist
+           (incdthist_incdt_id,
+            incdthist_change, incdthist_target_id,
+            incdthist_descrip)
+      VALUES(NEW.incdt_id,
+            'E', NEW.incdt_incdtresolution_id,
+            ('Resolution Changed: ' ||
+              COALESCE((SELECT incdtresolution_name
+                          FROM incdtresolution
+                         WHERE (incdtresolution_id=OLD.incdt_incdtresolution_id)), '')
+             || ' -> ' ||
+              COALESCE((SELECT incdtresolution_name
+                          FROM incdtresolution
+                         WHERE (incdtresolution_id=NEW.incdt_incdtresolution_id)), '')
+             || '') );
+    END IF;
+  END IF;
+
+    PERFORM postEvent(_evntType, 'IC', NEW.incdt_id,
+                      NULL, NEW.incdt_number::TEXT,
+                      NULL, NULL, NULL, NULL);
+
+  RETURN NEW;
+  END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'incdttrigger');
+CREATE TRIGGER incdttrigger
+  AFTER INSERT OR UPDATE OR DELETE
+  ON incdt
+  FOR EACH ROW
+  EXECUTE PROCEDURE _incdttrigger();
diff --git a/foundation-database/public/trigger_functions/invchead.sql b/foundation-database/public/trigger_functions/invchead.sql
new file mode 100644 (file)
index 0000000..49bfe1f
--- /dev/null
@@ -0,0 +1,188 @@
+CREATE OR REPLACE FUNCTION _invcheadBeforeTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _recurid     INTEGER;
+  _newparentid INTEGER;
+
+BEGIN
+  IF (TG_OP = 'UPDATE') THEN
+    IF (OLD.invchead_posted
+      AND ((OLD.invchead_invcnumber != NEW.invchead_invcnumber)
+        OR (OLD.invchead_invcdate != NEW.invchead_invcdate)
+        OR (OLD.invchead_terms_id != NEW.invchead_terms_id)
+        OR (OLD.invchead_salesrep_id != NEW.invchead_salesrep_id)
+        OR (OLD.invchead_commission != NEW.invchead_commission)
+        OR (OLD.invchead_taxzone_id != NEW.invchead_taxzone_id)
+        OR (OLD.invchead_shipchrg_id != NEW.invchead_shipchrg_id)
+        OR (OLD.invchead_prj_id != NEW.invchead_prj_id)
+        OR (OLD.invchead_misc_accnt_id != NEW.invchead_misc_accnt_id)
+        OR (OLD.invchead_misc_amount != NEW.invchead_misc_amount)
+        OR (OLD.invchead_freight != NEW.invchead_freight))) THEN
+      RAISE EXCEPTION 'Edit not allow on Posted Invoice.';
+    END IF;
+  END IF;
+  
+  IF (TG_OP = 'DELETE') THEN
+    DELETE FROM invcheadtax
+    WHERE (taxhist_parent_id=OLD.invchead_id);
+
+    SELECT recur_id INTO _recurid
+      FROM recur
+     WHERE ((recur_parent_id=OLD.invchead_id)
+        AND (recur_parent_type='I'));
+    IF (_recurid IS NOT NULL) THEN
+      SELECT invchead_id INTO _newparentid
+        FROM invchead
+       WHERE ((invchead_recurring_invchead_id=OLD.invchead_id)
+          AND (invchead_id!=OLD.invchead_id))
+       ORDER BY invchead_invcdate
+       LIMIT 1;
+
+      IF (_newparentid IS NULL) THEN
+        DELETE FROM recur WHERE recur_id=_recurid;
+      ELSE
+        UPDATE recur SET recur_parent_id=_newparentid
+         WHERE recur_id=_recurid;
+        UPDATE invchead SET invchead_recurring_invchead_id=_newparentid
+         WHERE invchead_recurring_invchead_id=OLD.invchead_id
+           AND invchead_id!=OLD.invchead_id;
+      END IF;
+    END IF;
+
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'invcheadBeforeTrigger');
+CREATE TRIGGER invcheadBeforeTrigger
+  BEFORE INSERT OR UPDATE OR DELETE
+  ON invchead
+  FOR EACH ROW
+  EXECUTE PROCEDURE _invcheadBeforeTrigger();
+
+CREATE OR REPLACE FUNCTION _invcheadTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    -- Something can go here
+    RETURN OLD;
+  END IF;
+
+-- Insert new row
+  IF (TG_OP = 'INSERT') THEN
+
+  -- Calculate Freight Tax
+    IF (NEW.invchead_freight <> 0) THEN
+      PERFORM calculateTaxHist( 'invcheadtax',
+                                NEW.invchead_id,
+                                NEW.invchead_taxzone_id,
+                                getFreightTaxtypeId(),
+                                NEW.invchead_invcdate,
+                                NEW.invchead_curr_id,
+                                NEW.invchead_freight );
+    END IF;
+
+    --- clear the number from the issue cache
+    PERFORM clearNumberIssue('InvcNumber', NEW.invchead_invcnumber);
+  END IF;
+
+-- Update row
+  IF (TG_OP = 'UPDATE') THEN
+
+    IF ( (NEW.invchead_freight <> OLD.invchead_freight) OR
+         (COALESCE(NEW.invchead_taxzone_id,-1) <> COALESCE(OLD.invchead_taxzone_id,-1)) OR
+         (NEW.invchead_invcdate <> OLD.invchead_invcdate) OR
+         (NEW.invchead_curr_id <> OLD.invchead_curr_id) ) THEN
+  -- Calculate invchead Tax
+      PERFORM calculateTaxHist( 'invcheadtax',
+                                NEW.invchead_id,
+                                NEW.invchead_taxzone_id,
+                                getFreightTaxtypeId(),
+                                NEW.invchead_invcdate,
+                                NEW.invchead_curr_id,
+                                NEW.invchead_freight );
+    END IF;
+
+    IF ( (COALESCE(NEW.invchead_taxzone_id,-1) <> COALESCE(OLD.invchead_taxzone_id,-1)) OR
+         (NEW.invchead_invcdate <> OLD.invchead_invcdate) OR
+         (NEW.invchead_curr_id <> OLD.invchead_curr_id) ) THEN
+  -- Calculate invcitem Tax
+      IF (COALESCE(NEW.invchead_taxzone_id,-1) <> COALESCE(OLD.invchead_taxzone_id,-1)) THEN
+
+        UPDATE invcitem SET invcitem_taxtype_id=getItemTaxType(invcitem_item_id,NEW.invchead_taxzone_id)
+        WHERE (invcitem_invchead_id=NEW.invchead_id);
+
+        PERFORM calculateTaxHist( 'invcitemtax',
+                                  invcitem_id,
+                                  NEW.invchead_taxzone_id,
+                                  invcitem_taxtype_id,
+                                  NEW.invchead_invcdate,
+                                  NEW.invchead_curr_id,
+                                  (invcitem_billed * invcitem_qty_invuomratio) *
+                                  (invcitem_price / invcitem_price_invuomratio) )
+        FROM invcitem
+        WHERE (invcitem_invchead_id = NEW.invchead_id);
+      END IF;
+    END IF;
+
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'invcheadtrigger');
+CREATE TRIGGER invcheadtrigger
+  AFTER INSERT OR UPDATE OR DELETE
+  ON invchead
+  FOR EACH ROW
+  EXECUTE PROCEDURE _invcheadTrigger();
+
+
+CREATE OR REPLACE FUNCTION _invcheadaftertrigger()
+  RETURNS trigger AS
+$BODY$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+  DECLARE
+    _cmnttypeid INTEGER;
+    _cohead_id INTEGER;
+
+  BEGIN
+--  Create a comment entry when on a Sales Order when an Invoice is Posted for that order
+
+--  Cache the cmnttype_id for ChangeLog
+    SELECT cmnttype_id INTO _cmnttypeid
+    FROM cmnttype
+    WHERE (cmnttype_name='ChangeLog');
+    IF (FOUND) THEN
+      IF (TG_OP = 'UPDATE') THEN
+       IF ((OLD.invchead_posted != NEW.invchead_posted) AND NEW.invchead_posted) THEN
+         SELECT cohead_id INTO _cohead_id
+         FROM cohead
+         WHERE (cohead_number = OLD.invchead_ordernumber);
+         IF (FOUND) THEN
+            PERFORM postComment( _cmnttypeid, 'S', _cohead_id,
+                                 ('Invoice, ' || NEW.invchead_invcnumber || ', posted for this order') );
+          END IF;
+       END IF;
+      END IF;
+    END IF;
+  RETURN NEW;
+  END;
+$BODY$
+  LANGUAGE 'plpgsql' VOLATILE
+  COST 100;
+
+SELECT dropIfExists('TRIGGER', 'invcheadaftertrigger');
+CREATE TRIGGER invcheadaftertrigger
+  AFTER UPDATE
+  ON invchead
+  FOR EACH ROW
+  EXECUTE PROCEDURE _invcheadaftertrigger();
+
diff --git a/foundation-database/public/trigger_functions/invcitem.sql b/foundation-database/public/trigger_functions/invcitem.sql
new file mode 100644 (file)
index 0000000..0cbc3be
--- /dev/null
@@ -0,0 +1,110 @@
+CREATE OR REPLACE FUNCTION _invcitemBeforeTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _itemfractional BOOLEAN;
+
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    DELETE FROM invcitemtax
+    WHERE (taxhist_parent_id=OLD.invcitem_id);
+
+    RETURN OLD;
+  END IF;
+
+  IF (TG_OP IN ('UPDATE','DELETE')) THEN
+    IF (SELECT COUNT(invchead_id) > 0
+        FROM invchead
+        WHERE ((invchead_id=OLD.invcitem_invchead_id)
+          AND (invchead_posted))) THEN
+      RAISE EXCEPTION 'Edit not allowed on Posted Invoices.';
+    END IF;
+  END IF;
+
+  -- If regular Item then enforce item_fractional
+  IF (COALESCE(NEW.invcitem_item_id, -1) <> -1) THEN
+    SELECT itemuomfractionalbyuom(NEW.invcitem_item_id, NEW.invcitem_qty_uom_id) INTO _itemfractional;
+    IF (NOT _itemfractional) THEN
+      IF (TRUNC(NEW.invcitem_ordered) <> NEW.invcitem_ordered) THEN
+        RAISE EXCEPTION 'Item does not support fractional quantities';
+      END IF;
+      IF (TRUNC(NEW.invcitem_billed) <> NEW.invcitem_billed) THEN
+        RAISE EXCEPTION 'Item does not support fractional quantities';
+      END IF;
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'invcitemBeforeTrigger');
+CREATE TRIGGER invcitemBeforeTrigger
+  BEFORE INSERT OR UPDATE OR DELETE
+  ON invcitem
+  FOR EACH ROW
+  EXECUTE PROCEDURE _invcitemBeforeTrigger();
+
+CREATE OR REPLACE FUNCTION _invcitemTrigger() RETURNS "trigger" AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _r RECORD;
+
+BEGIN
+  IF (TG_OP = ''DELETE'') THEN
+    RETURN OLD;
+  END IF;
+
+-- Cache Invoice Head
+  SELECT * INTO _r
+  FROM invchead
+  WHERE (invchead_id=NEW.invcitem_invchead_id);
+  IF (NOT FOUND) THEN
+    RAISE EXCEPTION ''Invoice head not found'';
+  END IF;
+
+-- Insert new row
+  IF (TG_OP = ''INSERT'') THEN
+
+  -- Calculate Tax
+      PERFORM calculateTaxHist( ''invcitemtax'',
+                                NEW.invcitem_id,
+                                COALESCE(_r.invchead_taxzone_id, -1),
+                                NEW.invcitem_taxtype_id,
+                                COALESCE(_r.invchead_invcdate, CURRENT_DATE),
+                                COALESCE(_r.invchead_curr_id, -1),
+                                (NEW.invcitem_billed * NEW.invcitem_qty_invuomratio) *
+                                (NEW.invcitem_price / NEW.invcitem_price_invuomratio) );
+  END IF;
+
+-- Update row
+  IF (TG_OP = ''UPDATE'') THEN
+
+  -- Calculate Tax
+    IF ( (NEW.invcitem_billed <> OLD.invcitem_billed) OR
+         (NEW.invcitem_qty_invuomratio <> OLD.invcitem_qty_invuomratio) OR
+         (NEW.invcitem_price <> OLD.invcitem_price) OR
+         (NEW.invcitem_price_invuomratio <> OLD.invcitem_price_invuomratio) OR
+         (COALESCE(NEW.invcitem_taxtype_id, -1) <> COALESCE(OLD.invcitem_taxtype_id, -1)) ) THEN
+      PERFORM calculateTaxHist( ''invcitemtax'',
+                                NEW.invcitem_id,
+                                COALESCE(_r.invchead_taxzone_id, -1),
+                                NEW.invcitem_taxtype_id,
+                                COALESCE(_r.invchead_invcdate, CURRENT_DATE),
+                                COALESCE(_r.invchead_curr_id, -1),
+                                (NEW.invcitem_billed * NEW.invcitem_qty_invuomratio) *
+                                (NEW.invcitem_price / NEW.invcitem_price_invuomratio) );
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+' LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'invcitemtrigger');
+CREATE TRIGGER invcitemtrigger
+  AFTER INSERT OR UPDATE OR DELETE
+  ON invcitem
+  FOR EACH ROW
+  EXECUTE PROCEDURE _invcitemTrigger();
diff --git a/foundation-database/public/trigger_functions/invhist.sql b/foundation-database/public/trigger_functions/invhist.sql
new file mode 100644 (file)
index 0000000..ed1ed31
--- /dev/null
@@ -0,0 +1,35 @@
+CREATE OR REPLACE FUNCTION invhistTrig() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+--  Need to allow 'temporary' negative for average costed item that has been frozen.
+--  Check at itemsite after all of the transactions have been thawed will ensure
+--  that final Qty On Hand is positive. 
+--  IF (NEW.invhist_qoh_after < 0 AND NEW.invhist_costmethod = 'A') THEN
+--    RAISE EXCEPTION 'Invhist (%) is recording with average costing and is not allowed to have a negative quantity on hand.', NEW.invhist_id;
+--  END IF;
+
+  IF ( ( SELECT itemsite_freeze
+         FROM itemsite
+         WHERE (itemsite_id=NEW.invhist_itemsite_id) ) ) THEN
+    NEW.invhist_posted = FALSE;
+  END IF;
+
+  -- never change the created timestamp, which defaults to CURRENT_TIMESTAMP
+  IF (TG_OP != 'INSERT') THEN
+    NEW.invhist_created = OLD.invhist_created;
+  ELSE
+    -- Always need a series id for distribution posting
+    IF (NEW.invhist_series IS NULL) THEN
+      RAISE EXCEPTION 'Column invhist_series may not be null.';
+    END IF;
+  END IF;
+
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'invhistTrigger');
+CREATE TRIGGER invhistTrigger BEFORE INSERT OR UPDATE ON invhist FOR EACH ROW EXECUTE PROCEDURE invhistTrig();
diff --git a/foundation-database/public/trigger_functions/ipsass.sql b/foundation-database/public/trigger_functions/ipsass.sql
new file mode 100644 (file)
index 0000000..c2dbb87
--- /dev/null
@@ -0,0 +1,43 @@
+CREATE OR REPLACE FUNCTION _ipsassBeforeTrigger () RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+  --  Checks
+  IF NOT (checkPrivilege(''MaintainPricingSchedules'')) THEN
+    RAISE EXCEPTION ''You do not have privileges to maintain Price Schedules.'';
+  END IF;
+
+  -- Business logic, disallow invalid combinations
+  IF (TG_OP IN (''INSERT'',''UPDATE'')) THEN
+    IF (LENGTH(COALESCE(NEW.ipsass_custtype_pattern,'''')) != 0) THEN
+      new.ipsass_cust_id               =       -1;
+      new.ipsass_custtype_id           =       -1;
+      new.ipsass_shipto_id             =       -1;
+      new.ipsass_shipto_pattern        =       '''';
+    ELSIF (COALESCE(NEW.ipsass_custtype_id,-1) > -1) THEN
+      new.ipsass_cust_id               =       -1;
+      new.ipsass_shipto_id             =       -1;
+      new.ipsass_shipto_pattern        =       '''';
+      new.ipsass_custtype_pattern      =       '''';
+    ELSIF (LENGTH(COALESCE(NEW.ipsass_shipto_pattern,'''')) != 0) THEN
+      new.ipsass_custtype_id           =       -1;
+      new.ipsass_shipto_id             =       -1;
+      new.ipsass_custtype_pattern      =       '''';
+    ELSE
+      new.ipsass_shipto_id             =       COALESCE(NEW.ipsass_shipto_id,-1);
+      new.ipsass_custtype_id           =       -1;
+      new.ipsass_shipto_pattern        =       '''';
+      new.ipsass_custtype_pattern      =       '''';
+    END IF;
+
+    RETURN NEW;
+  ELSE
+    RETURN OLD;
+  END IF;
+  
+END;
+' LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'ipsassBeforeTrigger');
+CREATE TRIGGER ipsassBeforeTrigger BEFORE INSERT OR UPDATE OR DELETE ON ipsass FOR EACH ROW EXECUTE PROCEDURE _ipsassBeforeTrigger();
diff --git a/foundation-database/public/trigger_functions/ipshead.sql b/foundation-database/public/trigger_functions/ipshead.sql
new file mode 100644 (file)
index 0000000..3db9227
--- /dev/null
@@ -0,0 +1,20 @@
+CREATE OR REPLACE FUNCTION _ipsheadBeforeTrigger () RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+  --  Checks
+  IF NOT (checkPrivilege(''MaintainPricingSchedules'')) THEN
+    RAISE EXCEPTION ''You do not have privileges to maintain Price Schedules.'';
+  END IF;
+
+  IF (TG_OP IN (''INSERT'',''UPDATE'')) THEN
+    RETURN NEW;
+  ELSE
+    RETURN OLD;
+  END IF;
+END;
+' LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'ipsheadBeforeTrigger');
+CREATE TRIGGER ipsheadBeforeTrigger BEFORE INSERT OR UPDATE OR DELETE ON ipshead FOR EACH ROW EXECUTE PROCEDURE _ipsheadBeforeTrigger();
diff --git a/foundation-database/public/trigger_functions/ipsitemchar.sql b/foundation-database/public/trigger_functions/ipsitemchar.sql
new file mode 100644 (file)
index 0000000..191d8d1
--- /dev/null
@@ -0,0 +1,33 @@
+CREATE OR REPLACE FUNCTION _ipsitemcharBeforeTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+  --  Checks
+  IF NOT (checkPrivilege('MaintainPricingSchedules')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Price Schedules.';
+  END IF;
+  
+  IF (TG_OP IN ('INSERT','UPDATE')) THEN
+    IF (SELECT (COUNT(item_id)=0)
+        FROM ipsiteminfo JOIN item ON (item_id=ipsitem_item_id) 
+        WHERE ((ipsitem_id=NEW.ipsitemchar_ipsitem_id)
+        AND (item_config))) THEN
+      RAISE EXCEPTION 'Characteristic prices may only be set on configured items.';
+    ELSIF (SELECT (COUNT(item_id)=0)
+        FROM ipsiteminfo JOIN item ON (item_id=ipsitem_item_id)
+                         JOIN charass ON (charass_target_id=item_id AND charass_target_type='I') 
+        WHERE ((ipsitem_id=NEW.ipsitemchar_ipsitem_id)
+        AND (charass_char_id=NEW.ipsitemchar_char_id)
+        AND (charass_value=NEW.ipsitemchar_value))) THEN
+      RAISE EXCEPTION 'No characteristic with matching value exists for this item.';
+    END IF;
+    RETURN NEW;
+  ELSE
+    RETURN OLD;
+  END IF;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'ipsitemcharBeforeTrigger');
+CREATE TRIGGER ipsitemcharBeforeTrigger BEFORE INSERT OR UPDATE OR DELETE ON ipsitemchar FOR EACH ROW EXECUTE PROCEDURE _ipsitemcharBeforeTrigger();
diff --git a/foundation-database/public/trigger_functions/ipsiteminfo.sql b/foundation-database/public/trigger_functions/ipsiteminfo.sql
new file mode 100644 (file)
index 0000000..e747f48
--- /dev/null
@@ -0,0 +1,18 @@
+CREATE OR REPLACE FUNCTION _ipsiteminfoBeforeTrigger () RETURNS TRIGGER AS $$
+BEGIN
+
+  --  Checks
+  IF NOT (checkPrivilege('MaintainPricingSchedules')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Price Schedules.';
+  END IF;
+  
+  IF (TG_OP IN ('INSERT','UPDATE')) THEN
+    RETURN NEW;
+  ELSE
+    RETURN OLD;
+  END IF;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'ipsiteminfoBeforeTrigger');
+CREATE TRIGGER ipsiteminfoBeforeTrigger BEFORE INSERT OR UPDATE OR DELETE ON ipsiteminfo FOR EACH ROW EXECUTE PROCEDURE _ipsiteminfoBeforeTrigger();
diff --git a/foundation-database/public/trigger_functions/item.sql b/foundation-database/public/trigger_functions/item.sql
new file mode 100644 (file)
index 0000000..ea2f0d2
--- /dev/null
@@ -0,0 +1,255 @@
+CREATE OR REPLACE FUNCTION _itemTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+-- Override values to avoid invalid data combinations
+  IF (NEW.item_type IN ('R','S','O','L','B')) THEN
+    NEW.item_picklist := FALSE;
+  END IF;
+
+  IF (NEW.item_type IN ('F','S','O','L','B')) THEN
+    NEW.item_picklist := FALSE;
+    NEW.item_sold := FALSE;
+    NEW.item_prodcat_id := -1;
+    NEW.item_exclusive := false;
+    NEW.item_listprice := 0;
+    NEW.item_upccode := '';
+    NEW.item_prodweight := 0;
+    NEW.item_packweight := 0;
+  END IF;
+
+  IF (NEW.item_type NOT IN ('M','R')) THEN
+    NEW.item_config := false;
+  END IF;
+
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER itemTrigger ON item;
+CREATE TRIGGER itemTrigger BEFORE INSERT OR UPDATE ON item FOR EACH ROW EXECUTE PROCEDURE _itemTrigger();
+
+CREATE OR REPLACE FUNCTION _itemAfterTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid INTEGER;
+
+BEGIN
+-- Privilege Checks
+   IF (NOT checkPrivilege('MaintainItemMasters')) THEN
+     RAISE EXCEPTION 'You do not have privileges to maintain Items.';
+   END IF;
+   
+-- Integrity checks
+  IF (TG_OP = 'UPDATE') THEN
+    IF ((OLD.item_type <> NEW.item_type) AND (NEW.item_type = 'L')) THEN
+      IF (SELECT COUNT(*) != 0 FROM bomitem WHERE (bomitem_item_id = OLD.item_id)) THEN
+        RAISE EXCEPTION 'This item is part of one or more Bills of Materials and cannot be a Planning Item.';
+      END IF;
+    END IF;
+
+    IF ((OLD.item_type <> NEW.item_type) AND
+       (NEW.item_type IN ('R','S','T'))) THEN
+      IF (SELECT COUNT(*) != 0
+        FROM itemsite
+        WHERE ((itemsite_item_id=OLD.item_id)
+        AND (itemsite_qtyonhand + qtyallocated(itemsite_id,startoftime(),endoftime()) +
+          qtyordered(itemsite_id,startoftime(),endoftime()) > 0 ))) THEN
+          RAISE EXCEPTION 'Item type not allowed when there are itemsites with quantities with on hand quantities or pending inventory activity for this item.';
+      END IF;
+    END IF;
+-- If type changed remove costs and deactivate item sites
+    IF (NEW.item_type <> OLD.item_type) THEN
+      PERFORM updateCost(itemcost_id, 0) FROM itemcost WHERE (itemcost_item_id=OLD.item_id);
+      UPDATE itemsite SET itemsite_active=false WHERE (itemsite_item_id=OLD.item_id);
+      IF (NEW.item_type = 'R') THEN
+        UPDATE itemsite SET itemsite_controlmethod='N' WHERE (itemsite_item_id=OLD.item_id);
+      END IF;
+    END IF;
+  END IF;
+
+  IF ( SELECT (metric_value='t')
+       FROM metric
+       WHERE (metric_name='ItemChangeLog') ) THEN
+
+--  Cache the cmnttype_id for ChangeLog
+    SELECT cmnttype_id INTO _cmnttypeid
+    FROM cmnttype
+    WHERE (cmnttype_name='ChangeLog');
+    IF (FOUND) THEN
+      IF (TG_OP = 'INSERT') THEN
+        PERFORM postComment(_cmnttypeid, 'I', NEW.item_id, 'Created');
+
+      ELSIF (TG_OP = 'UPDATE') THEN
+        IF (OLD.item_active <> NEW.item_active) THEN
+          IF (NEW.item_active) THEN
+            PERFORM postComment(_cmnttypeid, 'I', NEW.item_id, 'Activated');
+          ELSE
+            PERFORM postComment(_cmnttypeid, 'I', NEW.item_id, 'Deactivated');
+          END IF;
+        END IF;
+
+        IF (OLD.item_descrip1 <> NEW.item_descrip1) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               ( 'Description 1 Changed from "' || OLD.item_descrip1 ||
+                                 '" to "' || NEW.item_descrip1 || '"' ) );
+        END IF;
+
+        IF (OLD.item_descrip2 <> NEW.item_descrip2) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               ( 'Description 2 Changed from "' || OLD.item_descrip2 ||
+                                 '" to "' || NEW.item_descrip2 || '"' ) );
+        END IF;
+
+        IF (OLD.item_inv_uom_id <> NEW.item_inv_uom_id) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               ( 'Inventory UOM Changed from "' ||
+                                 (SELECT uom_name FROM uom WHERE uom_id=OLD.item_inv_uom_id) ||
+                                 '" (' || CAST(OLD.item_inv_uom_id AS TEXT) ||
+                                 ') to "' ||
+                                 (SELECT uom_name FROM uom WHERE uom_id=NEW.item_inv_uom_id) ||
+                                 '" (' || CAST(NEW.item_inv_uom_id AS TEXT) || ')' ) );
+        END IF;
+
+        IF (OLD.item_sold <> NEW.item_sold) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               CASE WHEN (NEW.item_sold) THEN 'Sold Changed from FALSE to TRUE'
+                                    ELSE 'Sold Changed from TRUE to FALSE'
+                               END );
+        END IF;
+
+        IF (OLD.item_picklist <> NEW.item_picklist) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               CASE WHEN (NEW.item_picklist) THEN 'Pick List Changed from FALSE to TRUE'
+                                    ELSE 'Pick List Changed from TRUE to FALSE'
+                               END );
+        END IF;
+
+        IF (OLD.item_fractional <> NEW.item_fractional) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               CASE WHEN (NEW.item_fractional) THEN 'Fractional Changed from FALSE to TRUE'
+                                    ELSE 'Fractional Changed from TRUE to FALSE'
+                               END );
+        END IF;
+
+        IF (OLD.item_exclusive <> NEW.item_exclusive) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               CASE WHEN (NEW.item_exclusive) THEN 'Exclusive Changed from FALSE to TRUE'
+                                    ELSE 'Exclusive Changed from TRUE to FALSE'
+                               END );
+        END IF;
+        IF (OLD.item_config <> NEW.item_config) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               CASE WHEN (NEW.item_config) THEN 'Configured Changed from FALSE to TRUE'
+                                    ELSE 'Configured Changed from TRUE to FALSE'
+                               END );
+        END IF;
+
+        IF (OLD.item_listprice <> NEW.item_listprice) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               ( 'List Price Changed from "' || formatSalesPrice(OLD.item_listprice) ||
+                                 '" to "' || formatSalesPrice(NEW.item_listprice) || '"' ) );
+        END IF;
+
+-- Add New stuff
+
+        IF (OLD.item_type <> NEW.item_type) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               ( 'Type Changed from "' || OLD.item_type ||
+                                 '" to "' || NEW.item_type || '"' ) );
+        END IF;
+
+        IF (OLD.item_price_uom_id <> NEW.item_price_uom_id) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               ( 'Price UOM Changed from "' ||
+                                 (SELECT uom_name FROM uom WHERE uom_id=OLD.item_price_uom_id) ||
+                                 '" (' || CAST(OLD.item_price_uom_id AS TEXT) ||
+                                 ') to "' ||
+                                 (SELECT uom_name FROM uom WHERE uom_id=NEW.item_price_uom_id) ||
+                                 '" (' || CAST(NEW.item_price_uom_id AS TEXT) || ')' ) );
+        END IF;
+
+        IF (OLD.item_classcode_id <> NEW.item_classcode_id) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               ( 'Class Code Changed from "' ||
+                                 (SELECT classcode_code || '-' || classcode_descrip FROM classcode WHERE classcode_id=OLD.item_classcode_id) ||
+                                 '" (' || CAST(OLD.item_classcode_id AS TEXT) ||
+                                 ') to "' ||
+                                 (SELECT classcode_code || '-' || classcode_descrip FROM classcode WHERE classcode_id=NEW.item_classcode_id) ||
+                                 '" (' || CAST(NEW.item_classcode_id AS TEXT) || ')' ) );
+        END IF;
+
+        IF (OLD.item_freightclass_id <> NEW.item_freightclass_id) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               ( 'Freight Class Changed from "' ||
+                                 (SELECT freightclass_code || '-' || freightclass_descrip FROM freightclass WHERE freightclass_id=OLD.item_freightclass_id) ||
+                                 '" (' || CAST(OLD.item_freightclass_id AS TEXT) ||
+                                 ') to "' ||
+                                 (SELECT freightclass_code || '-' || freightclass_descrip FROM freightclass WHERE freightclass_id=NEW.item_freightclass_id) ||
+                                 '" (' || CAST(NEW.item_freightclass_id AS TEXT) || ')' ) );
+        END IF;
+
+        IF (OLD.item_prodcat_id <> NEW.item_prodcat_id) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               ( 'Product Category Changed from "' ||
+                                 (SELECT prodcat_code || '-' || prodcat_descrip FROM prodcat WHERE prodcat_id=OLD.item_prodcat_id) ||
+                                 '" (' || CAST(OLD.item_prodcat_id AS TEXT) ||
+                                 ') to "' ||
+                                 (SELECT prodcat_code || '-' || prodcat_descrip FROM prodcat WHERE prodcat_id=NEW.item_prodcat_id) ||
+                                 '" (' || CAST(NEW.item_prodcat_id AS TEXT) || ')' ) );
+        END IF;
+
+        IF (OLD.item_upccode <> NEW.item_upccode) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               ( 'UPC Code Changed from "' || OLD.item_upccode ||
+                                 '" to "' || NEW.item_upccode || '"' ) );
+        END IF;
+
+        IF (OLD.item_prodweight <> NEW.item_prodweight) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               ( 'Product Weight Changed from "' || formatWeight(OLD.item_prodweight) ||
+                                 '" to "' || formatWeight(NEW.item_prodweight) || '"' ) );
+        END IF;
+
+        IF (OLD.item_packweight <> NEW.item_packweight) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               ( 'Packaging Weight Changed from "' || formatWeight(OLD.item_packweight) ||
+                                 '" to "' || formatWeight(NEW.item_packweight) || '"' ) );
+        END IF;
+
+        IF (OLD.item_maxcost <> NEW.item_maxcost) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               ( 'Maximum Desired Cost Changed from "' || formatCost(OLD.item_maxcost) ||
+                                 '" to "' || formatCost(NEW.item_maxcost) || '"' ) );
+        END IF;
+
+        IF (OLD.item_listcost <> NEW.item_listcost) THEN
+          PERFORM postComment( _cmnttypeid, 'I', NEW.item_id,
+                               ( 'List Cost Changed from "' || formatCost(OLD.item_listcost) ||
+                                 '" to "' || formatCost(NEW.item_listcost) || '"' ) );
+        END IF;
+-- End changes
+
+      END IF;
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'DELETE') THEN
+    DELETE FROM imageass WHERE ((imageass_source_id=OLD.item_id) AND (imageass_source='I'));
+    DELETE FROM url WHERE ((url_source_id=OLD.item_id) AND (url_source='I'));
+    DELETE FROM docass WHERE docass_source_id = OLD.item_id AND docass_source_type = 'I';
+    DELETE FROM docass WHERE docass_target_id = OLD.item_id AND docass_target_type = 'I';
+
+    RETURN OLD;
+  END IF;
+  
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER itemAfterTrigger ON item;
+CREATE TRIGGER itemAfterTrigger AFTER INSERT OR UPDATE OR DELETE ON item FOR EACH ROW EXECUTE PROCEDURE _itemAfterTrigger();
diff --git a/foundation-database/public/trigger_functions/itemcost.sql b/foundation-database/public/trigger_functions/itemcost.sql
new file mode 100644 (file)
index 0000000..9d762af
--- /dev/null
@@ -0,0 +1,182 @@
+CREATE OR REPLACE FUNCTION _itemCostTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+  --Privilege Checks
+  IF ( (TG_OP = 'INSERT') AND (NOT checkPrivilege('CreateCosts')) AND (NOT checkPrivilege('PostVouchers')) ) THEN
+    RAISE EXCEPTION 'You do not have privileges to enter Item Costs.';
+  END IF;
+
+  IF ( (TG_OP = 'UPDATE') AND (NOT checkPrivilege('EnterActualCosts')) AND (NOT checkPrivilege('PostVouchers')) AND (NOT checkPrivilege('UpdateActualCosts')) AND (NOT checkPrivilege('PostActualCosts')) AND (NOT checkPrivilege('PostStandardCosts')) ) THEN
+    RAISE EXCEPTION 'You do not have privileges to update Item Costs.';
+  END IF;
+
+  IF ( (TG_OP = 'DELETE') AND (NOT checkPrivilege('DeleteCosts')) ) THEN
+    RAISE EXCEPTION 'You do not have privileges to delete Item Costs.';
+  END IF;
+
+  IF (TG_OP = 'UPDATE') THEN
+    IF (NEW.itemcost_actcost <> OLD.itemcost_actcost OR
+        NEW.itemcost_curr_id <> OLD.itemcost_curr_id) THEN
+      INSERT INTO costhist
+      ( costhist_item_id, costhist_costelem_id, costhist_type,
+        costhist_lowlevel, costhist_username, costhist_date,
+        costhist_oldcost, costhist_newcost,
+        costhist_oldcurr_id, costhist_newcurr_id )
+      VALUES
+      ( NEW.itemcost_item_id, NEW.itemcost_costelem_id, 'A',
+        NEW.itemcost_lowlevel, getEffectiveXtUser(), CURRENT_TIMESTAMP,
+        OLD.itemcost_actcost, NEW.itemcost_actcost,
+        OLD.itemcost_curr_id, NEW.itemcost_curr_id );
+    END IF;
+
+    IF (NEW.itemcost_stdcost <> OLD.itemcost_stdcost) THEN
+      INSERT INTO costhist
+      ( costhist_item_id, costhist_costelem_id, costhist_type,
+        costhist_lowlevel, costhist_username, costhist_date,
+        costhist_oldcost, costhist_newcost,
+        costhist_oldcurr_id, costhist_newcurr_id )
+      VALUES
+      ( NEW.itemcost_item_id, NEW.itemcost_costelem_id, 'S',
+        NEW.itemcost_lowlevel, getEffectiveXtUser(), CURRENT_TIMESTAMP,
+        OLD.itemcost_stdcost, NEW.itemcost_stdcost,
+        baseCurrId(), baseCurrId() );
+    END IF;
+
+    RETURN NEW;
+
+  ELSIF (TG_OP = 'INSERT') THEN
+    INSERT INTO costhist
+    ( costhist_item_id, costhist_costelem_id, costhist_type,
+      costhist_lowlevel, costhist_username, costhist_date,
+      costhist_oldcost, costhist_newcost,
+      costhist_oldcurr_id, costhist_newcurr_id )
+    VALUES
+    ( NEW.itemcost_item_id, NEW.itemcost_costelem_id, 'N',
+      NEW.itemcost_lowlevel, getEffectiveXtUser(), CURRENT_TIMESTAMP,
+      0, NEW.itemcost_actcost,
+      baseCurrId(), NEW.itemcost_curr_id );
+
+    RETURN NEW;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    INSERT INTO costhist
+    ( costhist_item_id, costhist_costelem_id, costhist_type,
+      costhist_lowlevel, costhist_username, costhist_date,
+      costhist_oldcost, costhist_newcost,
+      costhist_oldcurr_id, costhist_newcurr_id )
+    VALUES
+    ( OLD.itemcost_item_id, OLD.itemcost_costelem_id, 'D',
+      OLD.itemcost_lowlevel, getEffectiveXtUser(), CURRENT_TIMESTAMP,
+      OLD.itemcost_stdcost, 0,
+      OLD.itemcost_curr_id, baseCurrId() );
+
+    RETURN OLD;
+  END IF;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER itemCostTrigger ON itemcost;
+CREATE TRIGGER itemCostTrigger BEFORE INSERT OR UPDATE OR DELETE ON itemcost FOR EACH ROW EXECUTE PROCEDURE _itemCostTrigger();
+
+
+
+CREATE OR REPLACE FUNCTION _itemCostAfterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _itemNumber TEXT;
+  _maxCost NUMERIC;
+  _oldStdCost NUMERIC;
+  _oldActCost NUMERIC;
+  _actualCost NUMERIC;
+  _standardCost NUMERIC;
+  
+BEGIN
+
+--  Create Event if Standard or Actual Cost is greater than Max Cost
+
+IF NOT EXISTS(SELECT 1 
+     FROM evntnot
+       JOIN evnttype ON (evnttype_id = evntnot_evnttype_id)
+       JOIN usrpref ON (evntnot_username = usrpref_username)
+     WHERE
+          evnttype_name = 'CostExceedsMaxDesired'
+          AND usrpref_name = 'active' 
+          AND usrpref_value = 't')     
+   THEN
+     RETURN NEW;     
+END IF; 
+
+  SELECT item_number, item_maxcost, actcost(item_id), stdcost(item_id) INTO _itemNumber, _maxCost, _actualCost, _standardCost
+  FROM item
+  WHERE (item_id=NEW.itemcost_item_id);
+
+  IF (_maxCost > 0.0) THEN
+   -- IF (_standardCost > _maxCost) 
+      IF NOT EXISTS(SELECT 1 --COUNT(evntlog_id) 
+                    FROM
+                      evntlog, evnttype
+                      WHERE evntlog_evnttype_id = evnttype_id 
+                      AND evntlog_number LIKE 
+                          (_itemNumber || ' -Standard- New:' || '%')
+                   
+                      AND (evntlog_dispatched IS NULL)
+                      AND CAST(evntlog_evnttime AS DATE) = current_date
+                     
+                      ) 
+                      AND (_standardCost > _maxCost) THEN
+                               
+                       
+      IF (TG_OP = 'INSERT') THEN
+        _oldStdCost := 0;
+        _oldActCost := 0;
+      ELSE
+        _oldStdCost := OLD.itemcost_stdcost;
+        _oldActCost := OLD.itemcost_stdcost;
+      END IF; 
+      PERFORM postEvent('CostExceedsMaxDesired', NULL, NEW.itemcost_item_id,
+                        itemsite_warehous_id,
+                        (_itemNumber || ' -Standard- ' || 
+                         'New: ' || formatCost(_standardCost) ||
+                         ' Max: '|| formatCost(_MaxCost)),
+                        NEW.itemcost_stdcost, _oldStdCost,
+                        NULL, NULL)
+      FROM itemsite
+      WHERE (itemsite_item_id=NEW.itemcost_item_id);
+    END IF;
+       IF NOT EXISTS(
+                     SELECT 1 FROM
+                      evntlog, evnttype
+                      WHERE evntlog_evnttype_id = evnttype_id 
+                      AND evntlog_number LIKE 
+                          (_itemNumber || ' -Actual- New:' || '%')
+
+                      AND (evntlog_dispatched IS NULL)
+                      AND CAST(evntlog_evnttime AS DATE) = current_date
+                      )
+
+                 AND  (_actualCost > _maxCost)
+          THEN
+                            
+      PERFORM postEvent('CostExceedsMaxDesired', NULL, NEW.itemcost_item_id,
+                        itemsite_warehous_id,
+                        (_itemNumber || ' -Actual- ' || 
+                         'New: ' || formatCost(_actualCost) ||
+                         ' Max: '|| formatCost(_MaxCost)),
+                        NEW.itemcost_actcost, _oldActCost,
+                        NULL, NULL)
+      FROM itemsite
+      WHERE (itemsite_item_id=NEW.itemcost_item_id);
+    END IF;
+  END IF;
+
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER itemCostAfterTrigger ON itemcost;
+CREATE TRIGGER itemCostAfterTrigger AFTER INSERT OR UPDATE ON itemcost FOR EACH ROW EXECUTE PROCEDURE _itemCostAfterTrigger();
diff --git a/foundation-database/public/trigger_functions/itemsite.sql b/foundation-database/public/trigger_functions/itemsite.sql
new file mode 100644 (file)
index 0000000..6a726da
--- /dev/null
@@ -0,0 +1,459 @@
+CREATE OR REPLACE FUNCTION _itemsiteTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid INTEGER;
+  _r RECORD;
+
+BEGIN
+
+  -- Cache some information
+  SELECT item_type INTO _r
+  FROM item
+  WHERE (item_id=NEW.itemsite_item_id);
+-- Override values to avoid invalid data combinations
+  IF (_r.item_type IN ('J','R','S')) THEN
+    NEW.itemsite_planning_type := 'N';
+  END IF;
+
+  IF (_r.item_type = 'L') THEN
+    NEW.itemsite_planning_type := 'S';
+  END IF;
+
+  IF (TG_OP = 'UPDATE') THEN
+    IF ( (NEW.itemsite_qtyonhand <> OLD.itemsite_qtyonhand) ) THEN
+      IF (OLD.itemsite_freeze) THEN
+        NEW.itemsite_qtyonhand := OLD.itemsite_qtyonhand;
+      ELSE
+        NEW.itemsite_datelastused := CURRENT_DATE;
+      END IF;
+
+      IF ( (NEW.itemsite_qtyonhand < 0) AND (OLD.itemsite_qtyonhand >= 0) AND (NEW.itemsite_eventfence > 0) ) THEN
+        PERFORM postEvent('QOHBelowZero', 'I', NEW.itemsite_id,
+                          warehous_id,
+                          (item_number || '/' || warehous_code),
+                          NULL, NULL, NULL, NULL)
+        FROM item, whsinfo
+        WHERE (item_id=NEW.itemsite_item_id)
+          AND (warehous_id=NEW.itemsite_warehous_id);
+      END IF;
+    END IF;
+    IF ( (NEW.itemsite_value <> OLD.itemsite_value) AND (OLD.itemsite_freeze) ) THEN
+      NEW.itemsite_value := OLD.itemsite_value;
+    END IF;
+  END IF;
+
+  IF (NEW.itemsite_qtyonhand < 0 AND NEW.itemsite_costmethod = 'A') THEN
+    RAISE EXCEPTION 'Itemsite (%) is set to use average costing and is not allowed to have a negative quantity on hand.', NEW.itemsite_id;
+  ELSIF (NEW.itemsite_value < 0 AND NEW.itemsite_costmethod = 'A') THEN
+    RAISE EXCEPTION 'This transaction results in a negative itemsite value.  Itemsite (%) is set to use average costing and is not allowed to have a negative value.', NEW.itemsite_id;
+  END IF;
+
+--  Handle the ChangeLog
+  IF ( SELECT (metric_value='t')
+       FROM metric
+       WHERE (metric_name='ItemSiteChangeLog') ) THEN
+
+--  Cache the cmnttype_id for ChangeLog
+    SELECT cmnttype_id INTO _cmnttypeid
+    FROM cmnttype
+    WHERE (cmnttype_name='ChangeLog');
+    IF (FOUND) THEN
+      IF (TG_OP = 'INSERT') THEN
+        PERFORM postComment(_cmnttypeid, 'IS', NEW.itemsite_id, 'Created');
+
+      ELSIF (TG_OP = 'UPDATE') THEN
+
+        IF (OLD.itemsite_plancode_id <> NEW.itemsite_plancode_id) THEN
+          PERFORM postComment( _cmnttypeid, 'IS', NEW.itemsite_id,
+                               ( 'Planner Code Changed from "' || oldplancode.plancode_code ||
+                                 '" to "' || newplancode.plancode_code || '"' ) )
+          FROM plancode AS oldplancode, plancode AS newplancode
+          WHERE ( (oldplancode.plancode_id=OLD.itemsite_plancode_id)
+           AND (newplancode.plancode_id=NEW.itemsite_plancode_id) );
+        END IF;
+
+        IF (NEW.itemsite_reorderlevel <> OLD.itemsite_reorderlevel) THEN
+          PERFORM postComment( _cmnttypeid, 'IS', NEW.itemsite_id,
+                               ( 'Reorder Level Changed from ' || formatQty(OLD.itemsite_reorderlevel) ||
+                                 ' to ' || formatQty(NEW.itemsite_reorderlevel ) ) );
+        END IF;
+
+        IF (NEW.itemsite_ordertoqty <> OLD.itemsite_ordertoqty) THEN
+          PERFORM postComment( _cmnttypeid, 'IS', NEW.itemsite_id,
+                               ( 'Order Up To Changed from ' || formatQty(OLD.itemsite_ordertoqty) ||
+                                 ' to ' || formatQty(NEW.itemsite_ordertoqty ) ) );
+        END IF;
+
+        IF (NEW.itemsite_leadtime <> OLD.itemsite_leadtime) THEN
+          PERFORM postComment( _cmnttypeid, 'IS', NEW.itemsite_id,
+                               ( 'Itemsite Leadtime Changed from ' || formatQty(OLD.itemsite_leadtime) ||
+                                 ' to ' || formatQty(NEW.itemsite_leadtime ) ) );
+        END IF;
+
+        IF (NEW.itemsite_abcclass <> OLD.itemsite_abcclass) THEN
+          PERFORM postComment( _cmnttypeid, 'IS', NEW.itemsite_id,
+                               ( 'Itemsite ABC Class Changed from ' || COALESCE(OLD.itemsite_abcclass, 'None') ||
+                                 ' to ' || COALESCE(NEW.itemsite_abcclass,'None') ) );
+        END IF;
+
+        IF (NEW.itemsite_controlmethod <> OLD.itemsite_controlmethod) THEN
+          PERFORM postComment( _cmnttypeid, 'IS', NEW.itemsite_id,
+                               ( 'Itemsite Control Method Changed from ' || COALESCE(OLD.itemsite_controlmethod,'None') ||
+                                 ' to ' || COALESCE(NEW.itemsite_controlmethod,'None') ) );
+        END IF;
+
+        IF (OLD.itemsite_sold <> NEW.itemsite_sold) THEN
+          PERFORM postComment( _cmnttypeid, 'IS', NEW.itemsite_id,
+            CASE WHEN (NEW.itemsite_sold) THEN 'Sold Changed from FALSE to TRUE'
+                                          ELSE 'Sold Changed from TRUE to FALSE'
+            END );
+        END IF;
+
+        IF (OLD.itemsite_active <> NEW.itemsite_active) THEN
+          IF (NEW.itemsite_active) THEN
+            PERFORM postComment(_cmnttypeid, 'IS', NEW.itemsite_id, 'Activated');
+          ELSE
+            PERFORM postComment(_cmnttypeid, 'IS', NEW.itemsite_id, 'Deactivated');
+          END IF;
+        END IF;
+
+      END IF;
+    END IF;
+  END IF;
+
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('trigger', 'itemsiteTrigger');
+CREATE TRIGGER itemsiteTrigger BEFORE INSERT OR UPDATE ON itemsite FOR EACH ROW EXECUTE PROCEDURE _itemsiteTrigger();
+
+CREATE OR REPLACE FUNCTION _itemsiteAfterTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _state INTEGER;
+  _wasLocationControl BOOLEAN;
+  _isLocationControl BOOLEAN;
+  _wasLotSerial BOOLEAN;
+  _isLotSerial BOOLEAN;
+  _wasPerishable BOOLEAN;
+  _isPerishable BOOLEAN;
+  _qty NUMERIC;
+  _maint BOOLEAN;
+  _cost NUMERIC;
+  _variance NUMERIC;
+  _application TEXT;
+
+BEGIN
+-- Cache Application
+  SELECT fetchMetricText('Application') INTO _application;
+
+-- Check if we are doing maintenance
+  IF (TG_OP = 'INSERT') THEN
+    _maint := TRUE;
+  ELSIF (TG_OP = 'UPDATE') THEN
+    IF ((OLD.itemsite_item_id           != NEW.itemsite_item_id)
+     OR (OLD.itemsite_warehous_id       != NEW.itemsite_warehous_id)
+     OR (OLD.itemsite_reorderlevel      != NEW.itemsite_reorderlevel)
+     OR (OLD.itemsite_ordertoqty        != NEW.itemsite_ordertoqty)
+     OR (OLD.itemsite_cyclecountfreq    != NEW.itemsite_cyclecountfreq)
+     OR (OLD.itemsite_planning_type     != NEW.itemsite_planning_type)
+     OR (OLD.itemsite_posupply          != NEW.itemsite_posupply)
+     OR (OLD.itemsite_wosupply          != NEW.itemsite_wosupply)
+     OR (OLD.itemsite_loccntrl          != NEW.itemsite_loccntrl)
+     OR (OLD.itemsite_safetystock       != NEW.itemsite_safetystock)
+     OR (OLD.itemsite_minordqty         != NEW.itemsite_minordqty)
+     OR (OLD.itemsite_multordqty        != NEW.itemsite_multordqty)
+     OR (OLD.itemsite_leadtime          != NEW.itemsite_leadtime)
+     OR (OLD.itemsite_abcclass          != NEW.itemsite_abcclass)
+     OR (OLD.itemsite_controlmethod     != NEW.itemsite_controlmethod)
+     OR (OLD.itemsite_active            != NEW.itemsite_active)
+     OR (OLD.itemsite_plancode_id       != NEW.itemsite_plancode_id)
+     OR (OLD.itemsite_costcat_id        != NEW.itemsite_costcat_id)
+     OR (OLD.itemsite_eventfence        != NEW.itemsite_eventfence)
+     OR (OLD.itemsite_sold              != NEW.itemsite_sold)
+     OR (OLD.itemsite_stocked           != NEW.itemsite_stocked)
+     OR (OLD.itemsite_location_id       != NEW.itemsite_location_id)
+     OR (OLD.itemsite_recvlocation_id   != NEW.itemsite_recvlocation_id)
+     OR (OLD.itemsite_issuelocation_id  != NEW.itemsite_issuelocation_id)
+     OR (OLD.itemsite_location_dist     != NEW.itemsite_location_dist)
+     OR (OLD.itemsite_recvlocation_dist != NEW.itemsite_recvlocation_dist)
+     OR (OLD.itemsite_issuelocation_dist != NEW.itemsite_issuelocation_dist)
+     OR (OLD.itemsite_useparams         != NEW.itemsite_useparams)
+     OR (OLD.itemsite_useparamsmanual   != NEW.itemsite_useparamsmanual)
+     OR (OLD.itemsite_soldranking       != NEW.itemsite_soldranking)
+     OR (OLD.itemsite_createpr          != NEW.itemsite_createpr)
+     OR (OLD.itemsite_location          != NEW.itemsite_location)
+     OR (OLD.itemsite_location_comments != NEW.itemsite_location_comments)
+     OR (OLD.itemsite_notes             != NEW.itemsite_notes)
+     OR (OLD.itemsite_perishable        != NEW.itemsite_perishable)
+     OR (OLD.itemsite_autoabcclass      != NEW.itemsite_autoabcclass)
+     OR (OLD.itemsite_ordergroup        != NEW.itemsite_ordergroup)
+     OR (OLD.itemsite_disallowblankwip  != NEW.itemsite_disallowblankwip)
+     OR (OLD.itemsite_maxordqty         != NEW.itemsite_maxordqty)
+     OR (OLD.itemsite_mps_timefence     != NEW.itemsite_mps_timefence)
+     OR (OLD.itemsite_createwo          != NEW.itemsite_createwo)
+     OR (OLD.itemsite_warrpurc          != NEW.itemsite_warrpurc)
+     OR (OLD.itemsite_costmethod        != NEW.itemsite_costmethod)
+     OR (OLD.itemsite_autoreg           != NEW.itemsite_autoreg)
+     OR (OLD.itemsite_lsseq_id          != NEW.itemsite_lsseq_id) ) THEN
+      IF (OLD.itemsite_item_id != NEW.itemsite_item_id) THEN
+        RAISE EXCEPTION 'The item number on an itemsite may not be changed.';
+      ELSIF (OLD.itemsite_warehous_id != NEW.itemsite_warehous_id) THEN
+        RAISE EXCEPTION 'The warehouse code on an itemsite may not be changed.';
+      END IF;
+      _maint := TRUE;
+    END IF;
+  ELSE
+    _maint := FALSE;
+  END IF;
+
+  IF (_maint) THEN -- Begin Maintenance
+-- Privilege Checks
+    IF ( NOT checkPrivilege('MaintainItemSites') ) THEN
+       RAISE EXCEPTION 'You do not have privileges to maintain Item Sites.';
+    END IF;
+    
+-- Override values to avoid invalid data combinations
+    IF (NOT NEW.itemsite_posupply) THEN
+      UPDATE itemsite SET
+        itemsite_createpr = FALSE
+      WHERE (itemsite_id=NEW.itemsite_id);
+    END IF;
+    IF (NOT NEW.itemsite_wosupply) THEN
+      UPDATE itemsite SET
+        itemsite_createwo = FALSE
+      WHERE (itemsite_id=NEW.itemsite_id);
+    END IF;
+
+    IF (NEW.itemsite_controlmethod NOT IN ('S','L')) THEN
+      UPDATE itemsite SET
+        itemsite_perishable = FALSE,
+        itemsite_warrpurc = FALSE,
+        itemsite_autoreg = FALSE,
+        itemsite_lsseq_id = NULL
+      WHERE (itemsite_id=NEW.itemsite_id);
+    END IF;
+
+    IF (NOT NEW.itemsite_loccntrl) THEN
+      UPDATE itemsite SET
+        itemsite_disallowblankwip = FALSE
+      WHERE (itemsite_id=NEW.itemsite_id);
+    END IF;
+
+    IF (NOT NEW.itemsite_useparams) THEN
+      UPDATE itemsite SET
+        itemsite_reorderlevel    = 0,
+        itemsite_ordertoqty      = 0,
+        itemsite_minordqty       = 0,
+        itemsite_maxordqty       = 0,
+        itemsite_multordqty      = 0,
+        itemsite_useparamsmanual = FALSE
+      WHERE (itemsite_id = NEW.itemsite_id);
+    END IF;
+    
+-- Integrity check
+
+    -- Both insert and update
+    IF ( (NEW.itemsite_controlmethod IN ('S', 'L')) AND
+         (NEW.itemsite_location_dist OR NEW.itemsite_recvlocation_dist OR NEW.itemsite_issuelocation_dist) ) THEN
+      RAISE EXCEPTION 'You cannot auto-distribute Lot/Serial controlled Item Sites.';
+    END IF;
+
+    IF (TG_OP = 'INSERT') THEN
+      -- Handle MLC logic
+      IF ( (NEW.itemsite_loccntrl) AND (NEW.itemsite_warehous_id IS NOT NULL) ) THEN
+        IF (SELECT count(*)=0
+            FROM location
+            WHERE ((location_warehous_id=NEW.itemsite_warehous_id)
+            AND ( (NOT location_restrict) OR
+                ( (location_restrict) AND
+                (location_id IN ( SELECT locitem_location_id
+                                  FROM locitem
+                                  WHERE (locitem_item_id=NEW.itemsite_item_id) ) ) ) ))) THEN
+          RAISE EXCEPTION 'You must first create at least one valid
+                         Location for this Item Site before it may be
+                         multiply located.';
+        END IF;
+      END IF;
+
+      --This could be made a table constraint later, but do not want to create a big problem
+      --for users with problematic legacy data over a relatively trivial problem for now,
+      --so we will just check moving forword.
+      IF (NEW.itemsite_stocked AND NEW.itemsite_reorderlevel<=0) THEN
+        RAISE EXCEPTION 'Stocked items must have postive reorder level specified.';
+      END IF;
+    END IF;
+
+    IF (TG_OP = 'UPDATE') THEN
+      --This could be made a table constraint later, but do not want to create a big problem
+      --for users with problematic legacy data over a relatively trivial problem for now,
+      --so we will just check moving forword.
+      IF ((NEW.itemsite_stocked)
+        AND (NEW.itemsite_stocked != OLD.itemsite_stocked) --Avoid checking unless explicitly changed
+        AND (NEW.itemsite_reorderlevel<=0)) THEN
+        RAISE EXCEPTION 'Stocked items must have postive reorder level specified.';
+      END IF;
+    END IF;
+  
+    IF (TG_OP = 'UPDATE') THEN
+  
+-- Integrity check
+      IF (NOT OLD.itemsite_loccntrl AND NEW.itemsite_loccntrl) THEN
+        IF (SELECT count(*)=0
+          FROM location
+          WHERE ((location_warehous_id=NEW.itemsite_warehous_id)
+          AND ( (NOT location_restrict) OR
+              ( (location_restrict) AND
+              (location_id IN ( SELECT locitem_location_id
+                                FROM locitem
+                                WHERE (locitem_item_id=NEW.itemsite_item_id) ) ) ) ))) THEN
+           RAISE EXCEPTION 'You must first create at least one valid
+                         Location for this Item Site before it may be
+                         multiply located.';
+        END IF;
+      END IF;
+   
+-- Update detail records based on control method changes 
+      _wasLocationControl := OLD.itemsite_loccntrl;
+      _isLocationControl := NEW.itemsite_loccntrl;
+      _wasLotSerial := OLD.itemsite_controlmethod IN ('S','L');
+      _isLotSerial := NEW.itemsite_controlmethod IN ('S','L'); 
+      _wasPerishable := OLD.itemsite_perishable;
+      _isPerishable := NEW.itemsite_perishable;
+      _state := 0;
+    
+      IF ( (_wasLocationControl) AND (_isLocationControl) ) THEN
+        _state := 10;
+      ELSIF ( (NOT _wasLocationControl) AND (NOT _isLocationControl) ) THEN
+        _state := 20;
+      ELSIF ( (NOT _wasLocationControl) AND (_isLocationControl) ) THEN
+        _state := 30;
+      ELSIF ( (_wasLocationControl) AND (NOT _isLocationControl) ) THEN
+        _state := 40;
+      END IF;
+
+      IF ( (_wasLotSerial) AND (_isLotSerial) ) THEN
+        _state := _state + 1;
+      ELSIF ( (NOT _wasLotSerial) AND (NOT _isLotSerial) ) THEN
+        _state := _state + 2;
+      ELSIF ( (NOT _wasLotSerial) AND (_isLotSerial) ) THEN
+        _state := _state + 3;
+      ELSIF ( (_wasLotSerial) AND (NOT _isLotSerial) ) THEN
+        _state := _state + 4;
+      END IF;
+
+      IF ( (_application = 'Standard') AND (_state IN (41, 43, 14, 34, 24, 42, 44)) ) THEN
+        -- Check for Reservations
+        IF (SELECT COUNT(*) > 0
+            FROM itemloc JOIN reserve ON (reserve_supply_id=itemloc_id AND reserve_supply_type='I')
+            WHERE (itemloc_itemsite_id=OLD.itemsite_id)) THEN
+          RAISE EXCEPTION 'Sales Order Reservations by Location exist for this Item Site';
+        END IF;
+      END IF;
+
+      IF (_state IN (41, 43)) THEN
+        PERFORM consolidateLotSerial(OLD.itemsite_id);
+      ELSIF (_state IN (14, 34)) THEN
+        PERFORM consolidateLocations(OLD.itemsite_id);
+      ELSIF (_state IN (24, 42, 44)) THEN
+
+        RAISE NOTICE 'Deleting item site detail records,';
+
+        SELECT SUM(itemloc_qty) INTO _qty
+        FROM itemloc, location
+        WHERE ((itemloc_location_id=location_id)
+        AND (NOT location_netable) 
+        AND (itemloc_itemsite_id=OLD.itemsite_id));
+
+        IF (_qty != 0) THEN
+          UPDATE itemsite
+          SET itemsite_qtyonhand = itemsite_qtyonhand + _qty,
+            itemsite_nnqoh = itemsite_nnqoh - _qty
+          WHERE (itemsite_id=OLD.itemsite_id);
+        END IF;
+
+        DELETE FROM itemloc
+        WHERE (itemloc_itemsite_id=OLD.itemsite_id);
+      END IF;
+
+     IF (NEW.itemsite_qtyonhand != 0) THEN
+--  Handle detail creation
+--  Create itemloc records if they do not exist
+       IF (_state IN (23, 32, 33)) THEN
+          INSERT INTO itemloc 
+            ( itemloc_itemsite_id, itemloc_location_id,
+              itemloc_expiration, itemloc_qty )
+            VALUES
+            ( NEW.itemsite_id, -1,
+              endOfTime(), NEW.itemsite_qtyonhand );
+        END IF;
+
+--  Handle Location distribution
+        IF (_state IN (31, 32, 33, 34)) THEN
+          IF (SELECT (COUNT(*)=1)
+              FROM location
+              WHERE ((location_id=NEW.itemsite_location_id)
+              AND (location_warehous_id=NEW.itemsite_warehous_id)
+              AND ( (NOT location_restrict) OR
+                  ( (location_restrict) AND
+                  (location_id IN ( SELECT locitem_location_id
+                                    FROM locitem
+                                    WHERE (locitem_item_id=NEW.itemsite_item_id) ) ) ) ))) THEN
+           PERFORM initialDistribution(NEW.itemsite_id, NEW.itemsite_location_id);
+          ELSE
+            RAISE EXCEPTION 'A valid default location must be selected to distribute existing inventory to.';
+          END IF;
+        END IF;
+
+--  Handle Lot/Serial distribution
+        IF ( (_state = 13) OR (_state = 23) OR (_state = 33) OR (_state = 43) ) THEN
+          RAISE NOTICE 'You should now use the Reassign Lot/Serial # window to assign Lot/Serial #s.';
+        END IF;
+      END IF;  
+      IF (OLD.itemsite_costmethod='A' AND NEW.itemsite_costmethod='S') THEN
+        -- TODO: Average costing cost method change
+        SELECT stdcost(NEW.itemsite_item_id) * NEW.itemsite_qtyonhand
+          INTO _cost;
+        _variance := _cost - NEW.itemsite_value;
+        NEW.itemsite_value := _cost;
+        IF(_variance <> 0.0) THEN
+          PERFORM insertGLTransaction( 'P/D', '', '', 'Itemsite converted from Average to Standard cost.',
+                                       costcat_invcost_accnt_id, costcat_asset_accnt_id, NEW.itemsite_id,
+                                      _variance, CURRENT_DATE )
+             FROM costcat
+            WHERE(costcat_id=NEW.itemsite_costcat_id);
+          UPDATE itemsite SET itemsite_value = _cost WHERE (itemsite_id = NEW.itemsite_id);
+        END IF;
+      END IF;
+    END IF;
+
+--  Handle Perishable
+    IF ( (_application = 'Standard') AND (_wasPerishable) AND (NOT _isPerishable) ) THEN
+      UPDATE itemloc SET itemloc_expiration = endOfTime()
+      WHERE (itemloc_itemsite_id = OLD.itemsite_id);
+      PERFORM consolidateLotSerial(OLD.itemsite_id);
+    END IF;
+
+--  If Planning Type changed to None then delete all Planned Orders
+    IF ( (_application = 'Standard') AND (TG_OP = 'UPDATE') ) THEN
+      IF (NEW.itemsite_planning_type = 'N' AND OLD.itemsite_planning_type <> 'N') THEN
+        PERFORM deletePlannedOrder(planord_id, TRUE)
+        FROM planord
+        WHERE (planord_itemsite_id=NEW.itemsite_id);
+      END IF;
+    END IF;
+    
+  END IF;  -- End Maintenance
+
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('trigger', 'itemsiteAfterTrigger');
+CREATE TRIGGER itemsiteAfterTrigger AFTER INSERT OR UPDATE ON itemsite FOR EACH ROW EXECUTE PROCEDURE _itemsiteAfterTrigger();
diff --git a/foundation-database/public/trigger_functions/itemsrc.sql b/foundation-database/public/trigger_functions/itemsrc.sql
new file mode 100644 (file)
index 0000000..f610061
--- /dev/null
@@ -0,0 +1,48 @@
+CREATE OR REPLACE FUNCTION _itemsrcTrigger () RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+-- Privilege Checks
+   IF (NOT checkPrivilege(''MaintainItemSources'')) THEN
+     RAISE EXCEPTION ''You do not have privileges to maintain Item Sources.'';
+   END IF;
+
+-- Set defaults
+   NEW.itemsrc_invvendoruomratio       := COALESCE(NEW.itemsrc_invvendoruomratio,1);
+   NEW.itemsrc_minordqty               := COALESCE(NEW.itemsrc_minordqty,0);
+   NEW.itemsrc_multordqty              := COALESCE(NEW.itemsrc_multordqty,0);
+   NEW.itemsrc_active                  := COALESCE(NEW.itemsrc_active,true);
+   NEW.itemsrc_leadtime                        := COALESCE(NEW.itemsrc_leadtime,0);
+   NEW.itemsrc_ranking                 := COALESCE(NEW.itemsrc_ranking,1);
+  
+  RETURN NEW;
+END;
+' LANGUAGE 'plpgsql';
+
+SELECT dropifexists('TRIGGER', 'itemsrcTrigger');
+CREATE TRIGGER itemsrcTrigger BEFORE INSERT OR UPDATE ON itemsrc FOR EACH ROW EXECUTE PROCEDURE _itemsrcTrigger();
+
+CREATE OR REPLACE FUNCTION _itemsrcAfterTrigger () RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+-- Privilege Checks
+  IF (NOT checkPrivilege(''MaintainItemSources'')) THEN
+    RAISE EXCEPTION ''You do not have privileges to maintain Item Sources.'';
+  END IF;
+
+-- Set default to false for other item sources of this item
+  IF (COALESCE(NEW.itemsrc_default, FALSE) = TRUE) THEN
+    UPDATE itemsrc SET itemsrc_default = FALSE
+    WHERE ( (itemsrc_item_id = NEW.itemsrc_item_id)
+      AND (itemsrc_id <> NEW.itemsrc_id) );
+  END IF;
+
+  RETURN NEW;
+END;
+' LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('trigger', 'itemsrcAfterTrigger');
+CREATE TRIGGER itemsrcAfterTrigger AFTER INSERT OR UPDATE ON itemsrc FOR EACH ROW EXECUTE PROCEDURE _itemsrcAfterTrigger();
diff --git a/foundation-database/public/trigger_functions/itemsrcp.sql b/foundation-database/public/trigger_functions/itemsrcp.sql
new file mode 100644 (file)
index 0000000..06f264c
--- /dev/null
@@ -0,0 +1,19 @@
+CREATE OR REPLACE FUNCTION _itemsrcpTrigger () RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+-- Privilege Checks
+   IF (NOT checkPrivilege(''MaintainItemSources'')) THEN
+     RAISE EXCEPTION ''You do not have privileges to maintain Item Sources.'';
+   END IF;
+
+-- Set defaults
+   NEW.itemsrcp_curr_id        := COALESCE(NEW.itemsrcp_curr_id,basecurrid());
+  
+  RETURN NEW;
+END;
+' LANGUAGE 'plpgsql';
+
+SELECT dropifexists('TRIGGER', 'itemsrcpTrigger');
+CREATE TRIGGER itemsrcpTrigger BEFORE INSERT OR UPDATE ON itemsrcp FOR EACH ROW EXECUTE PROCEDURE _itemsrcpTrigger();
diff --git a/foundation-database/public/trigger_functions/itemsub.sql b/foundation-database/public/trigger_functions/itemsub.sql
new file mode 100644 (file)
index 0000000..1fe6361
--- /dev/null
@@ -0,0 +1,16 @@
+CREATE OR REPLACE FUNCTION _itemsubTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+-- Privilege Checks
+   IF (NOT checkPrivilege('MaintainItemMasters')) THEN
+     RAISE EXCEPTION 'You do not have privileges to maintain Item Substitutes.';
+   END IF;
+  
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER itemsubTrigger ON itemsub;
+CREATE TRIGGER itemsubTrigger AFTER INSERT OR UPDATE ON itemsub FOR EACH ROW EXECUTE PROCEDURE _itemsubTrigger();
diff --git a/foundation-database/public/trigger_functions/itemtax.sql b/foundation-database/public/trigger_functions/itemtax.sql
new file mode 100644 (file)
index 0000000..264d575
--- /dev/null
@@ -0,0 +1,16 @@
+CREATE OR REPLACE FUNCTION _itemtaxTrigger () RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+-- Privilege Checks
+   IF (NOT checkPrivilege(''MaintainItemMasters'')) THEN
+     RAISE EXCEPTION ''You do not have privileges to maintain Items.'';
+   END IF;
+  
+  RETURN NEW;
+END;
+' LANGUAGE 'plpgsql';
+
+DROP TRIGGER itemtaxTrigger ON itemtax;
+CREATE TRIGGER itemtaxTrigger AFTER INSERT OR UPDATE ON itemtax FOR EACH ROW EXECUTE PROCEDURE _itemtaxTrigger();
diff --git a/foundation-database/public/trigger_functions/itemuomconv.sql b/foundation-database/public/trigger_functions/itemuomconv.sql
new file mode 100644 (file)
index 0000000..2350510
--- /dev/null
@@ -0,0 +1,16 @@
+CREATE OR REPLACE FUNCTION _itemuomconvTrigger () RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+-- Privilege Checks
+   IF (NOT checkPrivilege(''MaintainItemMasters'')) THEN
+     RAISE EXCEPTION ''You do not have privileges to maintain Items.'';
+   END IF;
+  
+  RETURN NEW;
+END;
+' LANGUAGE 'plpgsql';
+
+DROP TRIGGER itemuomconvTrigger ON itemuomconv;
+CREATE TRIGGER itemuomconvTrigger AFTER INSERT OR UPDATE ON itemuomconv FOR EACH ROW EXECUTE PROCEDURE _itemuomconvTrigger();
diff --git a/foundation-database/public/trigger_functions/location.sql b/foundation-database/public/trigger_functions/location.sql
new file mode 100644 (file)
index 0000000..99fe3b0
--- /dev/null
@@ -0,0 +1,89 @@
+CREATE OR REPLACE FUNCTION _locationTrigger () RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _check      BOOLEAN;
+  _checkId    INTEGER;
+
+BEGIN
+
+  -- Checks
+  -- Start with privileges
+  IF (TG_OP = ''INSERT'') THEN
+    SELECT checkPrivilege(''MaintainLocations'') INTO _check;
+    IF NOT (_check) THEN
+      RAISE EXCEPTION ''You do not have privileges to add new Locations.'';
+    END IF;
+  ELSE
+    SELECT checkPrivilege(''MaintainLocations'') INTO _check;
+    IF NOT (_check) THEN
+      RAISE EXCEPTION ''You do not have privileges to alter a Location.'';
+    END IF;
+  END IF;
+
+  -- Code is required
+  IF ( (LENGTH(COALESCE(NEW.location_name,''''))=0) AND
+       (LENGTH(COALESCE(NEW.location_aisle,''''))=0) AND
+       (LENGTH(COALESCE(NEW.location_rack,''''))=0) AND
+       (LENGTH(COALESCE(NEW.location_bin,''''))=0) ) THEN
+    RAISE EXCEPTION ''You must supply a valid Location Identifier.'';
+  END IF;
+  
+  -- Site is required
+  IF (NEW.location_warehous_id IS NULL) THEN
+    RAISE EXCEPTION ''You must supply a valid Site.'';
+  END IF;
+
+  -- Location Identifier must be unique
+  SELECT location_id INTO _checkId
+  FROM location
+  WHERE ( (UPPER(location_name)=UPPER(NEW.location_name))
+    AND   (UPPER(location_aisle)=UPPER(NEW.location_aisle))
+    AND   (UPPER(location_rack)=UPPER(NEW.location_rack))
+    AND   (UPPER(location_bin)=UPPER(NEW.location_bin))
+    AND   (location_warehous_id=NEW.location_warehous_id)
+    AND   (location_id<>NEW.location_id) );
+  IF (FOUND) THEN
+    RAISE EXCEPTION ''You must supply a unique Location Identifier for this Site.'';
+  END IF;
+  
+  RETURN NEW;
+
+END;
+' LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'locationTrigger');
+CREATE TRIGGER locationTrigger BEFORE INSERT OR UPDATE ON location FOR EACH ROW EXECUTE PROCEDURE _locationTrigger();
+
+CREATE OR REPLACE FUNCTION _locationAfterTrigger () RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _itemloc    RECORD;
+
+BEGIN
+
+  -- Maintain itemsite_qtyonhand and itemsite_nnqoh when location_netable changes
+  IF (TG_OP = ''UPDATE'') THEN
+    IF (OLD.location_netable <> NEW.location_netable) THEN
+      FOR _itemloc IN SELECT * FROM itemloc WHERE (itemloc_location_id=NEW.location_id) LOOP
+        IF (NEW.location_netable) THEN
+          UPDATE itemsite SET itemsite_qtyonhand = itemsite_qtyonhand + _itemloc.itemloc_qty,
+                              itemsite_nnqoh = itemsite_nnqoh - _itemloc.itemloc_qty
+          WHERE (itemsite_id=_itemloc.itemloc_itemsite_id);
+        ELSE
+          UPDATE itemsite SET itemsite_qtyonhand = itemsite_qtyonhand - _itemloc.itemloc_qty,
+                              itemsite_nnqoh = itemsite_nnqoh + _itemloc.itemloc_qty
+          WHERE (itemsite_id=_itemloc.itemloc_itemsite_id);
+        END IF;
+      END LOOP;
+    END IF;
+  END IF;
+  
+  RETURN NEW;
+
+END;
+' LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'locationAfterTrigger');
+CREATE TRIGGER locationAfterTrigger AFTER INSERT OR UPDATE ON location FOR EACH ROW EXECUTE PROCEDURE _locationAfterTrigger();
diff --git a/foundation-database/public/trigger_functions/metasql.sql b/foundation-database/public/trigger_functions/metasql.sql
new file mode 100644 (file)
index 0000000..7f6d90f
--- /dev/null
@@ -0,0 +1,42 @@
+CREATE OR REPLACE FUNCTION _metasqlTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+  NEW.metasql_lastuser                 := getEffectiveXtUser();
+  NEW.metasql_lastupdate       := current_date;
+  RETURN NEW;
+
+END;
+
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropifexists( 'TRIGGER', 'metasqlTrigger','PUBLIC');
+CREATE TRIGGER metasqlTrigger BEFORE INSERT OR UPDATE ON metasql FOR EACH ROW EXECUTE PROCEDURE _metasqlTrigger();
+
+CREATE OR REPLACE FUNCTION _metasqlalterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (NOT (isDBA() OR checkPrivilege('MaintainMetaSQL'))) THEN
+    RAISE EXCEPTION '% does not have privileges to maintain MetaSQL statements in %.%',
+                getEffectiveXtUser(), TG_TABLE_SCHEMA, TG_TABLE_NAME;
+  END IF;
+
+  IF ((TG_OP = 'UPDATE' OR TG_OP = 'DELETE')
+      AND NEW.metasql_grade <= 0
+      AND NOT isDBA()) THEN
+    RAISE EXCEPTION 'You may not alter grade 0 metasql queries except using the xTuple Updater utility';
+  END IF;
+
+  IF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropifexists( 'TRIGGER', 'metasqlAlterTrigger','PUBLIC');
+CREATE TRIGGER metasqlAlterTrigger BEFORE INSERT OR UPDATE ON metasql FOR EACH ROW EXECUTE PROCEDURE _metasqlAlterTrigger();
diff --git a/foundation-database/public/trigger_functions/ophead.sql b/foundation-database/public/trigger_functions/ophead.sql
new file mode 100644 (file)
index 0000000..2bd7b80
--- /dev/null
@@ -0,0 +1,167 @@
+CREATE OR REPLACE FUNCTION _opheadBeforeTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _rec record;
+  _check boolean;
+  _test text;
+BEGIN
+
+  IF(TG_OP = 'DELETE') THEN
+    _rec := OLD;
+  ELSE
+    _rec := NEW;
+  END IF;
+
+  --  Auto inactivate
+  IF (TG_OP = 'UPDATE') THEN
+    IF ( (NEW.ophead_opstage_id != OLD.ophead_opstage_id) AND
+         (SELECT opstage_opinactive FROM opstage WHERE opstage_id=NEW.ophead_opstage_id) ) THEN
+      NEW.ophead_active := FALSE;
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    IF (SELECT opstage_opinactive FROM opstage WHERE opstage_id=NEW.ophead_opstage_id) THEN
+      NEW.ophead_active := FALSE;
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'opheadBeforeTrigger');
+CREATE TRIGGER opheadBeforeTrigger BEFORE INSERT OR UPDATE ON ophead 
+FOR EACH ROW EXECUTE PROCEDURE _opheadBeforeTrigger();
+
+CREATE OR REPLACE FUNCTION _opheadAfterTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid INTEGER;
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    DELETE FROM docass WHERE docass_source_id = OLD.ophead_id AND docass_source_type = 'OPP';
+    DELETE FROM docass WHERE docass_target_id = OLD.ophead_id AND docass_target_type = 'OPP';
+  END IF;
+  
+  --  Comments
+  IF ( SELECT (metric_value='t') FROM metric WHERE (metric_name='OpportunityChangeLog') ) THEN
+
+    --  Cache the cmnttype_id for ChangeLog
+    SELECT cmnttype_id INTO _cmnttypeid
+    FROM cmnttype
+    WHERE (cmnttype_name='ChangeLog');
+    IF (FOUND) THEN
+      IF (TG_OP = 'INSERT') THEN
+        PERFORM postComment(_cmnttypeid, 'OPP', NEW.ophead_id, 'Created');
+
+        --- clear the number from the issue cache
+        PERFORM clearNumberIssue('OpportunityNumber', NEW.ophead_number);
+      ELSIF (TG_OP = 'UPDATE') THEN
+        IF (OLD.ophead_active <> NEW.ophead_active) THEN
+          IF (NEW.ophead_active) THEN
+            PERFORM postComment(_cmnttypeid, 'OPP', NEW.ophead_id, 'Activated');
+          ELSE
+            PERFORM postComment(_cmnttypeid, 'OPP', NEW.ophead_id, 'Deactivated');
+          END IF;
+        END IF;
+
+        IF (OLD.ophead_name <> NEW.ophead_name) THEN
+          PERFORM postComment( _cmnttypeid, 'OPP', NEW.ophead_id,
+                               ( 'Name Changed from "' || OLD.ophead_name ||
+                                 '" to "' || NEW.ophead_name || '"' ) );
+        END IF;
+
+        IF (OLD.ophead_owner_username <> NEW.ophead_owner_username) THEN
+          PERFORM postComment( _cmnttypeid, 'OPP', NEW.ophead_id,
+                               ( 'Owner Name Changed from "' || OLD.ophead_owner_username ||
+                                 '" to "' || NEW.ophead_owner_username || '"' ) );
+        END IF;
+
+        IF (OLD.ophead_probability_prcnt <> NEW.ophead_probability_prcnt) THEN
+          PERFORM postComment( _cmnttypeid, 'OPP', NEW.ophead_id,
+                               ( 'Probability % Changed from "' || OLD.ophead_probability_prcnt ||
+                                 '" to "' || NEW.ophead_probability_prcnt || '"' ) );
+        END IF;
+
+        IF (OLD.ophead_amount <> NEW.ophead_amount) THEN
+          PERFORM postComment( _cmnttypeid, 'OPP', NEW.ophead_id,
+                               ( 'Amount Changed from "' || OLD.ophead_amount ||
+                                 '" to "' || NEW.ophead_amount || '"' ) );
+        END IF;
+
+        IF (OLD.ophead_target_date <> NEW.ophead_target_date) THEN
+          PERFORM postComment( _cmnttypeid, 'OPP', NEW.ophead_id,
+                               ( 'Target Date Changed from "' || OLD.ophead_target_date ||
+                                 '" to "' || NEW.ophead_target_date || '"' ) );
+        END IF;
+
+        IF (OLD.ophead_actual_date <> NEW.ophead_actual_date) THEN
+          PERFORM postComment( _cmnttypeid, 'OPP', NEW.ophead_id,
+                               ( 'Actual Date Changed from "' || OLD.ophead_actual_date ||
+                                 '" to "' || NEW.ophead_actual_date || '"' ) );
+        END IF;
+
+        IF (OLD.ophead_crmacct_id <> NEW.ophead_crmacct_id) THEN
+          PERFORM postComment( _cmnttypeid, 'OPP', NEW.ophead_id,
+                               ( 'CRM Account Changed from "' ||
+                                 (SELECT crmacct_name FROM crmacct WHERE crmacct_id=OLD.ophead_crmacct_id) ||
+                                 '" (' || OLD.ophead_crmacct_id ||
+                                 ') to "' ||
+                                 (SELECT crmacct_name FROM crmacct WHERE crmacct_id=NEW.ophead_crmacct_id) ||
+                                 '" (' || NEW.ophead_crmacct_id || ')' ) );
+        END IF;
+
+        IF (OLD.ophead_curr_id <> NEW.ophead_curr_id) THEN
+          PERFORM postComment( _cmnttypeid, 'OPP', NEW.ophead_id,
+                               ( 'Currency Changed from "' ||
+                                 (SELECT curr_name FROM curr_symbol WHERE curr_id=OLD.ophead_curr_id) ||
+                                 '" (' || OLD.ophead_curr_id ||
+                                 ') to "' ||
+                                 (SELECT curr_name FROM curr_symbol WHERE curr_id=NEW.ophead_curr_id) ||
+                                 '" (' || NEW.ophead_curr_id || ')' ) );
+        END IF;
+
+        IF (OLD.ophead_opstage_id <> NEW.ophead_opstage_id) THEN
+          PERFORM postComment( _cmnttypeid, 'OPP', NEW.ophead_id,
+                               ( 'Stage Changed from "' ||
+                                 (SELECT opstage_name FROM opstage WHERE opstage_id=OLD.ophead_opstage_id) ||
+                                 '" (' || OLD.ophead_opstage_id ||
+                                 ') to "' ||
+                                 (SELECT opstage_name FROM opstage WHERE opstage_id=NEW.ophead_opstage_id) ||
+                                 '" (' || NEW.ophead_opstage_id || ')' ) );
+        END IF;
+
+        IF (OLD.ophead_opsource_id <> NEW.ophead_opsource_id) THEN
+          PERFORM postComment( _cmnttypeid, 'OPP', NEW.ophead_id,
+                               ( 'Source Changed from "' ||
+                                 (SELECT opsource_name FROM opsource WHERE opsource_id=OLD.ophead_opsource_id) ||
+                                 '" (' || OLD.ophead_opsource_id ||
+                                 ') to "' ||
+                                 (SELECT opsource_name FROM opsource WHERE opsource_id=NEW.ophead_opsource_id) ||
+                                 '" (' || NEW.ophead_opsource_id || ')' ) );
+        END IF;
+
+        IF (OLD.ophead_optype_id <> NEW.ophead_optype_id) THEN
+          PERFORM postComment( _cmnttypeid, 'OPP', NEW.ophead_id,
+                               ( 'Type Changed from "' ||
+                                 (SELECT optype_name FROM optype WHERE optype_id=OLD.ophead_optype_id) ||
+                                 '" (' || OLD.ophead_optype_id ||
+                                 ') to "' ||
+                                 (SELECT optype_name FROM optype WHERE optype_id=NEW.ophead_optype_id) ||
+                                 '" (' || NEW.ophead_optype_id || ')' ) );
+        END IF;
+
+      END IF;
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'opheadAfterTrigger');
+CREATE TRIGGER opheadAfterTrigger AFTER INSERT OR UPDATE OR DELETE ON ophead 
+FOR EACH ROW EXECUTE PROCEDURE _opheadAfterTrigger();
diff --git a/foundation-database/public/trigger_functions/pack.sql b/foundation-database/public/trigger_functions/pack.sql
new file mode 100644 (file)
index 0000000..f6d6397
--- /dev/null
@@ -0,0 +1,50 @@
+
+CREATE OR REPLACE FUNCTION _packBeforeTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid INTEGER;
+BEGIN
+  SELECT cmnttype_id INTO _cmnttypeid
+    FROM cmnttype
+    WHERE (cmnttype_name='ChangeLog');
+  IF (FOUND) THEN
+    IF ((TG_OP = 'INSERT') AND (NEW.pack_head_id) IS NOT NULL)THEN
+      PERFORM postComment(_cmnttypeid, 'S', NEW.pack_head_id, 'Added to Packing List Batch');
+    END IF;
+  END IF;
+  IF ((TG_OP = 'INSERT') OR (TG_OP = 'UPDATE')) THEN
+    IF (NEW.pack_shiphead_id IS NOT NULL
+        AND NEW.pack_shiphead_id NOT IN (SELECT shiphead_id
+                              FROM shiphead
+                              WHERE (shiphead_order_id=NEW.pack_head_id)
+                                AND (shiphead_order_type=NEW.pack_head_type))) THEN
+      RAISE EXCEPTION 'Shipment does not exist for % id %',
+                     NEW.pack_head_type, NEW.pack_head_id;
+      RETURN OLD;
+    END IF;
+
+    IF (NEW.pack_head_type = 'SO'
+       AND NEW.pack_head_id   IN (SELECT cohead_id FROM cohead)) THEN
+      RETURN NEW;
+
+    ELSEIF (NEW.pack_head_type = 'TO') THEN
+      IF (NOT fetchMetricBool('MultiWhs')) THEN
+       RAISE EXCEPTION 'Transfer Orders are not supported by this version of the application';
+      ELSEIF (NEW.pack_head_id IN (SELECT tohead_id FROM tohead)) THEN
+       RETURN NEW;
+      END IF;
+    END IF;
+
+    RAISE EXCEPTION '% with id % does not exist',
+                   NEW.pack_head_type, NEW.pack_head_id;
+    RETURN OLD;
+
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER packBeforeTrigger ON pack;
+CREATE TRIGGER packBeforeTrigger BEFORE INSERT OR UPDATE ON pack FOR EACH ROW EXECUTE PROCEDURE _packBeforeTrigger();
diff --git a/foundation-database/public/trigger_functions/period.sql b/foundation-database/public/trigger_functions/period.sql
new file mode 100644 (file)
index 0000000..e7f1f83
--- /dev/null
@@ -0,0 +1,58 @@
+
+CREATE OR REPLACE FUNCTION _periodAfterTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _idoffirst INTEGER;
+  _test      INTEGER;
+BEGIN
+  -- This trigger can easily cause an infinite loop
+  -- because of this we have to be very careful to not
+  -- do an update on the period table if no updates
+  -- are absolutely needed so we don't just keep
+  -- trigger ourselves again and again
+
+  -- Figure out which period is the first one
+  SELECT period_id
+    INTO _idoffirst
+    FROM period
+   ORDER BY period_start
+   LIMIT 1;
+
+  -- If we didn't find anything there is nothing to do
+  IF( NOT FOUND ) THEN
+    RETURN NEW;
+  END IF;
+
+  -- do a select to see if there is at least one record that needs to be
+  -- updated. If we do not find any then we can just leave without
+  -- causing a retrigger of ourselves
+  SELECT period_id
+    INTO _test
+    FROM period
+   WHERE((COALESCE(period_initial, true) AND (NOT period_id=_idoffirst))
+      OR ((NOT COALESCE(period_initial, false)) AND (period_id=_idoffirst)))
+   LIMIT 1;
+
+  -- Nothing to update - get out of here
+  IF( NOT FOUND ) THEN
+    RETURN NEW;
+  END IF;
+
+  -- Update all the period records that already have the initial flag
+  -- set and the one that we know should be the first.
+  -- We don't have to be as careful here since we have already ruled
+  -- out if don't need to update already.
+  UPDATE period
+     SET period_initial = (_idoffirst=period_id)
+   WHERE((COALESCE(period_initial, true))
+      OR (period_id=_idoffirst));
+
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'periodAfterTrigger');
+CREATE TRIGGER periodAfterTrigger AFTER INSERT OR UPDATE OR DELETE ON period FOR EACH STATEMENT EXECUTE PROCEDURE _periodAfterTrigger();
+
diff --git a/foundation-database/public/trigger_functions/pkgcmd.sql b/foundation-database/public/trigger_functions/pkgcmd.sql
new file mode 100644 (file)
index 0000000..3905379
--- /dev/null
@@ -0,0 +1,82 @@
+-- NO create trigger statements here. the updater will create them.
+
+SELECT dropIfExists('TRIGGER', 'pkgcmdbeforetrigger');
+CREATE OR REPLACE FUNCTION _pkgcmdbeforetrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmdid       INTEGER;
+  _debug        BOOL := false;
+
+BEGIN
+    IF (TG_OP = 'UPDATE') THEN
+      IF (_debug) THEN
+        RAISE NOTICE 'OLD.cmd_name %, NEW.cmd_name %',
+                     OLD.cmd_name, NEW.cmd_name;
+      END IF;
+
+      IF (NEW.cmd_name != OLD.cmd_name) THEN
+        SELECT cmd_id INTO _cmdid FROM cmd WHERE cmd_name=NEW.cmd_name;
+        IF (FOUND) THEN
+          RAISE EXCEPTION 'Cannot change command name % because another command with that name already exists.', NEW.cmd_name;
+        END IF;
+      END IF;
+
+    ELSIF (TG_OP = 'INSERT') THEN
+      IF (_debug) THEN
+        RAISE NOTICE 'inserting NEW.cmd_name %', NEW.cmd_name;
+      END IF;
+      SELECT cmd_id INTO _cmdid FROM cmd WHERE cmd_name=NEW.cmd_name;
+      IF (FOUND) THEN
+        RAISE EXCEPTION 'Cannot create new command % because another command with that name already exists.', NEW.cmd_name;
+      END IF;
+
+    ELSIF (TG_OP = 'DELETE') THEN
+      DELETE FROM cmdarg WHERE cmdarg_cmd_id=OLD.cmd_id;
+
+      RETURN OLD;
+    END IF;
+
+    RETURN NEW;
+  END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION _pkgcmdalterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (pkgMayBeModified(TG_TABLE_SCHEMA)) THEN
+    IF (TG_OP = 'DELETE') THEN
+      RETURN OLD;
+    ELSE
+      RETURN NEW;
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    RAISE EXCEPTION 'You may not create custom commands in packages except using the xTuple Updater utility';
+
+  ELSIF (TG_OP = 'UPDATE') THEN
+    RAISE EXCEPTION 'You may not alter custom commands in packages except using the xTuple Updater utility';
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    RAISE EXCEPTION 'You may not delete custom commands from packages. Try deleting or disabling the package.';
+
+  END IF;
+
+  RETURN NEW;
+END;
+
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION _pkgcmdaftertrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
diff --git a/foundation-database/public/trigger_functions/pkgcmdarg.sql b/foundation-database/public/trigger_functions/pkgcmdarg.sql
new file mode 100644 (file)
index 0000000..8eb9cb7
--- /dev/null
@@ -0,0 +1,63 @@
+-- NO create trigger statements. the updater will create them.
+
+SELECT dropIfExists('TRIGGER', 'pkgcmdargbeforetrigger');
+CREATE OR REPLACE FUNCTION _pkgcmdargbeforetrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmdargid     INTEGER;
+  _debug        BOOL := false;
+
+BEGIN
+  IF (TG_OP = 'UPDATE') THEN
+    RETURN NEW;
+
+  ELSIF (TG_OP = 'INSERT') THEN
+    RETURN NEW;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION _pkgcmdargalterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (pkgMayBeModified(TG_TABLE_SCHEMA)) THEN
+    IF (TG_OP = 'DELETE') THEN
+      RETURN OLD;
+    ELSE
+      RETURN NEW;
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    RAISE EXCEPTION 'You may not create command arguments in packages except using the xTuple Updater utility';
+
+  ELSIF (TG_OP = 'UPDATE') THEN
+    RAISE EXCEPTION 'You may not alter command arguments in packages except using the xTuple Updater utility';
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    RAISE EXCEPTION 'You may not delete command arguments from packages. Try deleting or disabling the package.';
+
+  END IF;
+
+  RETURN NEW;
+END;
+
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION _pkgcmdargaftertrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
diff --git a/foundation-database/public/trigger_functions/pkghead.sql b/foundation-database/public/trigger_functions/pkghead.sql
new file mode 100644 (file)
index 0000000..0b3f942
--- /dev/null
@@ -0,0 +1,41 @@
+SELECT dropIfExists('TRIGGER', 'pkgheadbeforetrigger');
+CREATE OR REPLACE FUNCTION _pkgheadbeforetrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple.
+-- See www.xtuple.com/CPAL for the full text of the software license.
+  DECLARE
+    _r    RECORD;
+
+  BEGIN
+    IF (TG_OP = 'UPDATE') THEN
+      NEW.pkghead_created := OLD.pkghead_created;
+      NEW.pkghead_updated := CURRENT_TIMESTAMP;
+      IF (NEW.pkghead_indev AND NOT userCanCreateUsers(getEffectiveXtUser())) THEN
+        NEW.pkghead_indev = FALSE;
+      END IF;
+
+    ELSIF (TG_OP = 'INSERT') THEN
+      NEW.pkghead_created := CURRENT_TIMESTAMP;
+      NEW.pkghead_updated := NEW.pkghead_created;
+      IF (NEW.pkghead_indev AND NOT userCanCreateUsers(getEffectiveXtUser())) THEN
+        NEW.pkghead_indev = FALSE;
+      END IF;
+
+    ELSIF (TG_OP = 'DELETE') THEN
+      DELETE FROM pkgdep WHERE pkgdep_pkghead_id=OLD.pkghead_id;
+
+      EXECUTE 'DROP SCHEMA ' || OLD.pkghead_name || ' CASCADE';
+
+      RETURN OLD;
+    END IF;
+
+    RETURN NEW;
+  END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE TRIGGER pkgheadbeforetrigger
+  BEFORE  INSERT OR
+         UPDATE OR
+          DELETE
+  ON pkghead
+  FOR EACH ROW
+  EXECUTE PROCEDURE _pkgheadbeforetrigger();
diff --git a/foundation-database/public/trigger_functions/pkgimage.sql b/foundation-database/public/trigger_functions/pkgimage.sql
new file mode 100644 (file)
index 0000000..1d51cb1
--- /dev/null
@@ -0,0 +1,79 @@
+-- NO create trigger statements. the updater will create them.
+SELECT dropIfExists('TRIGGER', 'pkgimagebeforetrigger');
+CREATE OR REPLACE FUNCTION _pkgimagebeforetrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _imageid     INTEGER;
+  _debug       BOOL := false;
+
+BEGIN
+  IF (TG_OP = 'UPDATE') THEN
+    IF (_debug) THEN
+      RAISE NOTICE 'OLD.image_name %, NEW.image_name %',
+                   OLD.image_name, NEW.image_name;
+    END IF;
+
+    IF (NEW.image_name != OLD.image_name) THEN
+      SELECT image_id INTO _imageid FROM image WHERE image_name=NEW.image_name;
+      IF (FOUND) THEN
+        RAISE EXCEPTION 'Cannot change image named % because another image with that name already exists.', NEW.image_name;
+      END IF;
+    END IF;
+
+  ELSIF (TG_OP = 'INSERT') THEN
+    IF (_debug) THEN
+      RAISE NOTICE 'inserting NEW.image_name %', NEW.image_name;
+    END IF;
+    SELECT image_id INTO _imageid FROM image WHERE image_name=NEW.image_name;
+    IF (FOUND) THEN
+      RAISE EXCEPTION 'Cannot create new image % because another image with that name already exists.', NEW.image_name;
+    END IF;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION _pkgimagealterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (pkgMayBeModified(TG_TABLE_SCHEMA)) THEN
+    IF (TG_OP = 'DELETE') THEN
+      RETURN OLD;
+    ELSE
+      RETURN NEW;
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    RAISE EXCEPTION 'You may not create images in packages except using the xTuple Updater utility';
+
+  ELSIF (TG_OP = 'UPDATE') THEN
+    RAISE EXCEPTION 'You may not alter images in packages except using the xTuple Updater utility';
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    RAISE EXCEPTION 'You may not delete images from packages. Try deleting or disabling the package.';
+
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION _pkgimageaftertrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
diff --git a/foundation-database/public/trigger_functions/pkgitem.sql b/foundation-database/public/trigger_functions/pkgitem.sql
new file mode 100644 (file)
index 0000000..66cf6fc
--- /dev/null
@@ -0,0 +1,245 @@
+SELECT dropIfExists('TRIGGER', 'pkgitembeforetrigger', 'public');
+CREATE OR REPLACE FUNCTION _pkgitembeforetrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple.
+-- See www.xtuple.com/CPAL for the full text of the software license.
+  DECLARE
+    _functionargs TEXT;
+    _group        TEXT;
+    _object       TEXT;
+    _schema       TEXT;
+    _debug        BOOL := false;
+  BEGIN
+    IF (TG_OP = 'INSERT' OR TG_OP = 'UPDATE') THEN
+      _object = NEW.pkgitem_name;
+
+      SELECT LOWER(pkghead_name) INTO _schema
+      FROM pkghead
+      WHERE (pkghead_id=NEW.pkgitem_pkghead_id);
+      IF (NOT FOUND) THEN
+        _schema := 'public';
+      END IF;
+
+      IF (NEW.pkgitem_type = 'F') THEN
+        _object := SPLIT_PART(_object, '(', 1);
+      ELSIF (NEW.pkgitem_type = 'M') THEN
+        _group  := SPLIT_PART(_object, '-', 1);
+        _object := SPLIT_PART(_object, '-', 2);
+      END IF;
+      IF _debug THEN
+        RAISE NOTICE '_schema % and _object %', _schema, _object;
+      END IF;
+
+      IF (NEW.pkgitem_type = 'C') THEN
+        IF (NOT EXISTS(SELECT script_id
+                       FROM script
+                       WHERE ((script_id=NEW.pkgitem_item_id)
+                          AND (script_name=NEW.pkgitem_name)))) THEN
+          RAISE EXCEPTION 'Cannot create Script % as a Package Item without a corresponding script record.',
+            NEW.pkgitem_name;
+        END IF;
+
+      ELSIF (NEW.pkgitem_type = 'D') THEN
+        IF (NOT EXISTS(SELECT cmd_id
+                       FROM cmd
+                       WHERE ((cmd_id=NEW.pkgitem_item_id)
+                          AND (cmd_name=NEW.pkgitem_name)))) THEN
+          RAISE EXCEPTION 'Cannot create Custom Command % as a Package Item without a corresponding cmd record.',
+            NEW.pkgitem_name;
+        END IF;
+
+      ELSIF (NEW.pkgitem_type = 'F') THEN
+        IF (NOT EXISTS(SELECT pg_proc.oid
+                       FROM pg_proc, pg_namespace
+                       WHERE ((pg_proc.oid=NEW.pkgitem_item_id)
+                          AND (proname = (_object))
+                          AND (pronamespace=pg_namespace.oid)
+                          AND (nspname=_schema)) )) THEN
+          RAISE EXCEPTION 'Cannot create Function % (oid %) as a Package Item without a corresponding function in the database.',
+                          NEW.pkgitem_name, NEW.pkgitem_item_id;
+        END IF;
+
+      ELSIF (NEW.pkgitem_type = 'G') THEN
+        IF (NOT EXISTS(SELECT pg_class.oid
+                     FROM pg_trigger, pg_class, pg_namespace
+                     WHERE ((tgname=_object)
+                        AND (tgrelid=pg_class.oid)
+                        AND (relnamespace=pg_namespace.oid)
+                        AND (nspname=_schema)))) THEN
+          RAISE EXCEPTION 'Cannot create Trigger % as a Package Item without a corresponding trigger in the database.',
+            NEW.pkgitem_name;
+        END IF;
+
+      ELSIF (NEW.pkgitem_type = 'I') THEN
+        IF (NOT EXISTS(SELECT image_id
+                       FROM image
+                       WHERE ((image_id=NEW.pkgitem_item_id)
+                          AND (image_name=NEW.pkgitem_name)))) THEN
+          RAISE EXCEPTION 'Cannot create Image % as a Package Item without a corresponding image record.',
+            NEW.pkgitem_name;
+        END IF;
+
+      ELSIF (NEW.pkgitem_type = 'M') THEN
+        IF (NOT EXISTS(SELECT metasql_id
+                       FROM metasql
+                       WHERE ((metasql_id=NEW.pkgitem_item_id)
+                          AND (metasql_group=_group)
+                          AND (metasql_name=_object)))) THEN
+          RAISE EXCEPTION 'Cannot create MetaSQL statement % as a Package Item without a corresponding metasql record.',
+            NEW.pkgitem_name;
+        END IF;
+
+      ELSIF (NEW.pkgitem_type = 'P') THEN
+        IF (NOT EXISTS(SELECT priv_id
+                       FROM priv
+                       WHERE ((priv_id=NEW.pkgitem_item_id)
+                          AND (priv_name=NEW.pkgitem_name)))) THEN
+          RAISE EXCEPTION 'Cannot create Privilege % as a Package Item without a corresponding priv record.',
+            NEW.pkgitem_name;
+        END IF;
+
+      ELSIF (NEW.pkgitem_type = 'R') THEN
+        IF (NOT EXISTS(SELECT report_id
+                       FROM report
+                       WHERE ((report_id=NEW.pkgitem_item_id)
+                          AND (report_name=NEW.pkgitem_name)))) THEN
+          RAISE EXCEPTION 'Cannot create Report % as a Package Item without a corresponding report record.',
+            NEW.pkgitem_name;
+        END IF;
+
+      ELSIF (NEW.pkgitem_type = 'S') THEN
+        IF (NOT EXISTS(SELECT oid
+                       FROM pg_namespace
+                       WHERE (LOWER(nspname)=LOWER(NEW.pkgitem_name)))) THEN
+          RAISE EXCEPTION 'Cannot create Schema % as a Package Item without a corresponding schema in the database.',
+            NEW.pkgitem_name;
+        END IF;
+
+      ELSIF (NEW.pkgitem_type = 'T') THEN
+        IF (NOT EXISTS(SELECT pg_class.oid
+                     FROM pg_class, pg_namespace
+                     WHERE ((relname=_object)
+                        AND (relnamespace=pg_namespace.oid)
+                        AND (relkind='r')
+                        AND (nspname=_schema)))) THEN
+          RAISE EXCEPTION 'Cannot create Table % as a Package Item without a corresponding table in the database.',
+            NEW.pkgitem_name;
+        END IF;
+
+      ELSIF (NEW.pkgitem_type = 'U') THEN
+        IF (NOT EXISTS(SELECT uiform_id
+                       FROM uiform
+                       WHERE ((uiform_id=NEW.pkgitem_item_id)
+                          AND (uiform_name=NEW.pkgitem_name)))) THEN
+          RAISE EXCEPTION 'Cannot create User Interface Form % as a Package Item without a corresponding uiform record.',
+            NEW.pkgitem_name;
+        END IF;
+
+      ELSIF (NEW.pkgitem_type = 'V') THEN
+        IF (NOT EXISTS(SELECT pg_class.oid
+                     FROM pg_class, pg_namespace
+                     WHERE ((relname=_object)
+                        AND (relnamespace=pg_namespace.oid)
+                        AND (relkind='v')
+                        AND (nspname=_schema)))) THEN
+          RAISE EXCEPTION 'Cannot create View % as a Package Item without a corresponding view in the database.',
+            NEW.pkgitem_name;
+        END IF;
+
+      ELSE
+        RAISE EXCEPTION '"%" is not a valid type of package item.',
+          NEW.pkgitem_type;
+      END IF;
+
+    ELSIF (TG_OP = 'DELETE') THEN
+      IF _debug THEN RAISE NOTICE 'Deleting % % %', OLD.pkgitem_item_id, OLD.pkgitem_name, OLD.pkgitem_type; END IF;
+
+      _object = OLD.pkgitem_name;
+
+      SELECT pkghead_name INTO _schema
+      FROM pkghead
+      WHERE (pkghead_id=OLD.pkgitem_pkghead_id);
+      IF (NOT FOUND) THEN
+        _schema := 'public';
+      END IF;
+
+      IF (OLD.pkgitem_type = 'F') THEN
+        _object := SPLIT_PART(_object, '(', 1);
+      ELSIF (OLD.pkgitem_type = 'M') THEN
+        _group  := SPLIT_PART(_object, '-', 1);
+        _object := SPLIT_PART(_object, '-', 2);
+      END IF;
+      IF _debug THEN
+        RAISE NOTICE '_schema % and _object %', _schema, _object;
+      END IF;
+
+      IF (OLD.pkgitem_type = 'C') THEN
+        DELETE FROM script WHERE ((script_id=OLD.pkgitem_item_id)
+                              AND (script_name=OLD.pkgitem_name));
+
+      ELSIF (OLD.pkgitem_type = 'D') THEN
+        DELETE FROM cmd
+          WHERE ((cmd_id=OLD.pkgitem_item_id)
+            AND  (cmd_name=OLD.pkgitem_name));
+
+      ELSIF (OLD.pkgitem_type = 'F') THEN
+        -- SELECT dropIfExists('FUNCTION', CAST (oid::regprocedure AS TEXT), _schema)
+        PERFORM dropIfExists('FUNCTION',
+                            proname || '(' ||
+                            oidvectortypes(proargtypes) || ')',
+                            _schema)
+        FROM pg_proc
+        WHERE (oid=OLD.pkgitem_item_id);
+
+      ELSIF (OLD.pkgitem_type = 'G') THEN
+        PERFORM dropIfExists('TRIGGER', _object, _schema);
+
+      ELSIF (OLD.pkgitem_type = 'I') THEN
+        DELETE FROM image WHERE ((image_id=OLD.pkgitem_item_id)
+                             AND (image_name=OLD.pkgitem_name));
+
+      ELSIF (OLD.pkgitem_type = 'M') THEN
+        DELETE FROM metasql WHERE ((metasql_id=OLD.pkgitem_item_id)
+                               AND (metasql_group=_group)
+                               AND (metasql_name=_object));
+
+      ELSIF (OLD.pkgitem_type = 'P') THEN
+        DELETE FROM priv
+        WHERE ((priv_id=OLD.pkgitem_item_id) 
+           AND (priv_name=OLD.pkgitem_name));
+
+      ELSIF (OLD.pkgitem_type = 'R') THEN
+        DELETE FROM report
+        WHERE ((report_id=OLD.pkgitem_item_id)
+           AND (report_name=OLD.pkgitem_name));
+
+      ELSIF (OLD.pkgitem_type = 'S') THEN
+        PERFORM dropIfExists('SCHEMA', OLD.pkgitem_name, OLD.pkgitem_name);
+
+      ELSIF (OLD.pkgitem_type = 'T') THEN
+        PERFORM dropIfExists('TABLE', _object, _schema, true);
+
+      ELSIF (OLD.pkgitem_type = 'U') THEN
+        DELETE FROM uiform
+        WHERE ((uiform_id=OLD.pkgitem_item_id)
+           AND (uiform_name=OLD.pkgitem_name));
+
+      ELSIF (OLD.pkgitem_type = 'V') THEN
+        PERFORM dropIfExists('VIEW', _object, _schema, true);
+
+      ELSE
+        RAISE EXCEPTION '"%" is not a valid type of package item.',
+          OLD.pkgitem_type;
+      END IF;
+      RETURN OLD;
+    END IF;
+
+    RETURN NEW;
+  END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE TRIGGER pkgitembeforetrigger
+  BEFORE  INSERT OR
+         UPDATE OR DELETE
+  ON pkgitem
+  FOR EACH ROW
+  EXECUTE PROCEDURE _pkgitembeforetrigger();
diff --git a/foundation-database/public/trigger_functions/pkgmetasql.sql b/foundation-database/public/trigger_functions/pkgmetasql.sql
new file mode 100644 (file)
index 0000000..10f7f07
--- /dev/null
@@ -0,0 +1,103 @@
+-- NO create trigger statements. the updater will create them.
+
+SELECT dropIfExists('TRIGGER', 'pkgmetasqlbeforetrigger');
+CREATE OR REPLACE FUNCTION _pkgmetasqlbeforetrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _metasqlid    INTEGER;
+  _isdba        BOOLEAN := false;
+
+BEGIN
+  SELECT rolsuper INTO _isdba FROM pg_roles WHERE (rolname=getEffectiveXtUser());
+
+  IF (NOT (_isdba OR checkPrivilege('MaintainMetaSQL'))) THEN
+    RAISE EXCEPTION '% does not have privileges to maintain MetaSQL statements in %.% (DBA=%)',
+                getEffectiveXtUser(), TG_TABLE_SCHEMA, TG_TABLE_NAME, _isdba;
+  END IF;
+
+  IF (TG_OP = 'UPDATE') THEN
+    RAISE DEBUG 'update OLD %-%-%, NEW %-%-%',
+                 OLD.metasql_group, OLD.metasql_name, OLD.metasql_grade,
+                 NEW.metasql_group, NEW.metasql_name, NEW.metasql_grade;
+
+    IF (NEW.metasql_name != OLD.metasql_name OR NEW.metasql_group != OLD.metasql_group OR NEW.metasql_grade != OLD.metasql_grade) THEN
+      SELECT metasql_id INTO _metasqlid
+      FROM metasql
+      WHERE metasql_name=NEW.metasql_name AND metasql_group=NEW.metasql_group AND metasql_grade=NEW.metasql_grade;
+      IF (FOUND) THEN
+        RAISE EXCEPTION 'Cannot change the MetaSQL statement named %-%-% because another MetaSQL statement with that group, name and grade already exists.', NEW.metasql_group, NEW.metasql_name, NEW.metasql_grade;
+      END IF;
+    END IF;
+
+  ELSIF (TG_OP = 'INSERT') THEN
+    RAISE DEBUG 'insert NEW %-% %',
+                 NEW.metasql_group, NEW.metasql_name, NEW.metasql_grade;
+    SELECT metasql_id INTO _metasqlid
+    FROM metasql
+    WHERE metasql_name=NEW.metasql_name AND metasql_group=NEW.metasql_group AND metasql_grade=NEW.metasql_grade;
+    IF (FOUND) THEN
+      RAISE EXCEPTION 'The new MetaSQL statement %-% % conflicts with an existing statement.',
+                      NEW.metasql_group, NEW.metasql_name, NEW.metasql_grade;
+    END IF;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION _pkgmetasqlalterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _isdba        BOOLEAN := false;
+
+BEGIN
+  SELECT rolsuper INTO _isdba FROM pg_roles WHERE (rolname=getEffectiveXtUser());
+
+  IF (pkgMayBeModified(TG_TABLE_SCHEMA)) THEN
+    IF (TG_OP = 'DELETE') THEN
+      RETURN OLD;
+    ELSE
+      RETURN NEW;
+    END IF;
+  END IF;
+
+  -- cannot combine IF's because plpgsql does not always evaluate left-to-right
+  IF (TG_OP = 'INSERT') THEN
+    IF (NEW.metasql_grade <= 0 AND NOT _isdba) THEN
+      RAISE EXCEPTION 'You may not create grade 0 MetaSQL statements in packages except using the xTuple Updater utility';
+    END IF;
+
+  ELSIF (TG_OP = 'UPDATE') THEN
+    IF (NEW.metasql_grade <= 0 AND NOT _isdba) THEN
+      RAISE EXCEPTION 'You may not alter grade 0 MetaSQL statements in packages except using the xTuple Updater utility';
+    END IF;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    IF (OLD.metasql_grade <= 0 AND NOT _isdba) THEN
+      RAISE EXCEPTION 'You may not delete grade 0 MetaSQL statements from packages. Try deleting or disabling the package.';
+    ELSE
+      RETURN OLD;
+    END IF;
+
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION _pkgmetasqlaftertrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
diff --git a/foundation-database/public/trigger_functions/pkgpriv.sql b/foundation-database/public/trigger_functions/pkgpriv.sql
new file mode 100644 (file)
index 0000000..edb8f63
--- /dev/null
@@ -0,0 +1,84 @@
+-- NO create trigger statements. the updater will create them.
+
+SELECT dropIfExists('TRIGGER', 'pkgprivbeforetrigger');
+CREATE OR REPLACE FUNCTION _pkgprivbeforetrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _privid       INTEGER;
+  _debug        BOOL := false;
+
+BEGIN
+  IF (TG_OP = 'UPDATE') THEN
+    IF (_debug) THEN
+      RAISE NOTICE 'OLD.priv_name %, NEW.priv_name %',
+                   OLD.priv_name, NEW.priv_name;
+    END IF;
+
+    IF (NEW.priv_name != OLD.priv_name) THEN
+      SELECT priv_id INTO _privid FROM priv WHERE priv_name=NEW.priv_name;
+      IF (FOUND) THEN
+        RAISE EXCEPTION 'Cannot change privilege name % because another privilege with that name already exists.', NEW.priv_name;
+      END IF;
+    END IF;
+
+  ELSIF (TG_OP = 'INSERT') THEN
+    IF (_debug) THEN
+      RAISE NOTICE 'inserting NEW.priv_name %', NEW.priv_name;
+    END IF;
+    SELECT priv_id INTO _privid FROM priv WHERE priv_name=NEW.priv_name;
+    IF (FOUND) THEN
+      RAISE EXCEPTION 'Cannot create new privilege % because another privilege with that name already exists.', NEW.priv_name;
+    END IF;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    IF (_debug) THEN RAISE NOTICE 'deleting pkgpriv_id %', OLD.priv_id; END IF;
+    DELETE FROM usrpriv WHERE usrpriv_priv_id=OLD.priv_id;
+    DELETE FROM grppriv WHERE grppriv_priv_id=OLD.priv_id;
+
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION _pkgprivalterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (pkgMayBeModified(TG_TABLE_SCHEMA)) THEN
+    IF (TG_OP = 'DELETE') THEN
+      RETURN OLD;
+    ELSE
+      RETURN NEW;
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    RAISE EXCEPTION 'You may not create privileges in packages except using the xTuple Updater utility';
+
+  ELSIF (TG_OP = 'UPDATE') THEN
+    RAISE EXCEPTION 'You may not alter privileges in packages except using the xTuple Updater utility';
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    RAISE EXCEPTION 'You may not delete privileges from packages. Try deleting or disabling the package.';
+
+  END IF;
+
+  RETURN NEW;
+END;
+
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION _pkgprivaftertrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
diff --git a/foundation-database/public/trigger_functions/pkgreport.sql b/foundation-database/public/trigger_functions/pkgreport.sql
new file mode 100644 (file)
index 0000000..94f9c4b
--- /dev/null
@@ -0,0 +1,86 @@
+-- NO create trigger statements. the updater will create them.
+
+SELECT dropIfExists('TRIGGER', 'pkgreportbeforetrigger');
+CREATE OR REPLACE FUNCTION _pkgreportbeforetrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _reportid     INTEGER;
+  _debug        BOOL := false;
+
+BEGIN
+  IF (TG_OP = 'UPDATE') THEN
+    IF (_debug) THEN
+      RAISE NOTICE 'update OLD % %, NEW % %',
+                   OLD.report_name, OLD.report_grade, NEW.report_name, NEW.report_grade;
+    END IF;
+
+    IF (NEW.report_name != OLD.report_name) THEN
+      SELECT report_id INTO _reportid
+      FROM report
+      WHERE ((report_name=NEW.report_name)
+        AND  (report_grade=NEW.report_grade));
+      IF (FOUND) THEN
+        RAISE EXCEPTION 'Cannot change report % % because another report with that name and grade already exists.', NEW.report_name, NEW.report_grade;
+      END IF;
+    END IF;
+
+  ELSIF (TG_OP = 'INSERT') THEN
+    IF (_debug) THEN
+      RAISE NOTICE 'insert NEW % %', NEW.report_name, NEW.report_grade;
+    END IF;
+    SELECT report_id INTO _reportid
+    FROM report
+    WHERE ((report_name=NEW.report_name)
+      AND  (report_grade=NEW.report_grade));
+    IF (FOUND) THEN
+      RAISE EXCEPTION 'Cannot create new report % % because another report with that name and grade already exists.', NEW.report_name, NEW.report_grade;
+    END IF;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION _pkgreportalterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (pkgMayBeModified(TG_TABLE_SCHEMA)) THEN
+    IF (TG_OP = 'DELETE') THEN
+      RETURN OLD;
+    ELSE
+      RETURN NEW;
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    RAISE EXCEPTION 'You may not create report definitions in packages except using the xTuple Updater utility';
+
+  ELSIF (TG_OP = 'UPDATE') THEN
+    RAISE EXCEPTION 'You may not alter report definitions in packages except using the xTuple Updater utility';
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    RAISE EXCEPTION 'You may not delete report definitions from packages. Try deleting or disabling the package.';
+
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION _pkgreportaftertrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
diff --git a/foundation-database/public/trigger_functions/pkgscript.sql b/foundation-database/public/trigger_functions/pkgscript.sql
new file mode 100644 (file)
index 0000000..954418c
--- /dev/null
@@ -0,0 +1,63 @@
+-- NO create trigger statements. the updater will create them.
+
+SELECT dropIfExists('TRIGGER', 'pkgscriptbeforetrigger');
+CREATE OR REPLACE FUNCTION _pkgscriptbeforetrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _scriptid     INTEGER;
+  _debug        BOOL := false;
+
+BEGIN
+  IF (TG_OP = 'UPDATE') THEN
+    RETURN NEW;
+
+  ELSIF (TG_OP = 'INSERT') THEN
+    RETURN NEW;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION _pkgscriptalterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (pkgMayBeModified(TG_TABLE_SCHEMA)) THEN
+    IF (TG_OP = 'DELETE') THEN
+      RETURN OLD;
+    ELSE
+      RETURN NEW;
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    RAISE EXCEPTION 'You may not create scripts in packages except using the xTuple Updater utility';
+
+  ELSIF (TG_OP = 'UPDATE') THEN
+    RAISE EXCEPTION 'You may not alter scripts in packages except using the xTuple Updater utility';
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    RAISE EXCEPTION 'You may not delete scripts from packages. Try deleting or disabling the package.';
+
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION _pkgscriptaftertrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
diff --git a/foundation-database/public/trigger_functions/pkguiform.sql b/foundation-database/public/trigger_functions/pkguiform.sql
new file mode 100644 (file)
index 0000000..a5f1a92
--- /dev/null
@@ -0,0 +1,64 @@
+-- NO create trigger statements here. the updater will create them.
+
+SELECT dropIfExists('TRIGGER', 'pkguiformbeforetrigger');
+CREATE OR REPLACE FUNCTION _pkguiformbeforetrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _uiformid     INTEGER;
+  _debug        BOOL := false;
+
+BEGIN
+  IF (TG_OP = 'UPDATE') THEN
+    RETURN NEW;
+
+  ELSIF (TG_OP = 'INSERT') THEN
+    RETURN NEW;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION _pkguiformalterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (pkgMayBeModified(TG_TABLE_SCHEMA)) THEN
+    IF (TG_OP = 'DELETE') THEN
+      RETURN OLD;
+    ELSE
+      RETURN NEW;
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    RAISE EXCEPTION 'You may not create forms in packages except using the xTuple Updater utility';
+
+  ELSIF (TG_OP = 'UPDATE') THEN
+    RAISE EXCEPTION 'You may not alter forms in packages except using the xTuple Updater utility';
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    RAISE EXCEPTION 'You may not delete forms from packages. Try deleting or disabling the package.';
+
+  END IF;
+
+  RETURN NEW;
+END;
+
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION _pkguiformaftertrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
diff --git a/foundation-database/public/trigger_functions/pohead.sql b/foundation-database/public/trigger_functions/pohead.sql
new file mode 100644 (file)
index 0000000..3786437
--- /dev/null
@@ -0,0 +1,112 @@
+CREATE OR REPLACE FUNCTION _poheadTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid  INTEGER;
+  _check       BOOLEAN;
+  _maint        BOOLEAN := TRUE;
+
+BEGIN
+
+-- Check if we are doing maintenance
+  IF (TG_OP = 'UPDATE') THEN
+    IF ( (OLD.pohead_status           != NEW.pohead_status) OR
+         (OLD.pohead_printed          != NEW.pohead_printed) ) THEN
+      _maint := FALSE;
+    END IF;
+  END IF;
+
+  -- Check
+  IF ( (NOT _maint) AND (NOT checkPrivilege('MaintainPurchaseOrders'))
+                    AND (NOT checkPrivilege('PostPurchaseOrders'))
+                    AND (NOT checkPrivilege('PrintPurchaseOrders'))
+                    AND (NOT checkPrivilege('PostVouchers')) ) THEN
+    RAISE EXCEPTION 'You do not have privileges to alter a Purchase Order.';
+  END IF;
+
+  IF ( _maint AND (NOT checkPrivilege('MaintainPurchaseOrders')) ) THEN
+    RAISE EXCEPTION 'You do not have privileges to alter a Purchase Order.';
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    --- clear the number from the issue cache
+    PERFORM clearNumberIssue('PoNumber', NEW.pohead_number);
+  END IF;
+
+  IF ( (TG_OP = 'INSERT') OR (TG_op = 'UPDATE') ) THEN
+    IF (NOT ISNUMERIC(NEW.pohead_number) AND NEW.pohead_saved) THEN
+      RAISE EXCEPTION 'Purchase Order Number must be numeric.';
+    END IF;
+  END IF;
+
+  IF ( SELECT (metric_value='t')
+       FROM metric
+       WHERE (metric_name='POChangeLog') ) THEN
+
+--  Cache the cmnttype_id for ChangeLog
+    SELECT cmnttype_id INTO _cmnttypeid
+    FROM cmnttype
+    WHERE (cmnttype_name='ChangeLog');
+    IF (FOUND) THEN
+      IF (TG_OP = 'INSERT') THEN
+        PERFORM postComment(_cmnttypeid, 'P', NEW.pohead_id, 'Created');
+
+      ELSIF (TG_OP = 'UPDATE') THEN
+        IF (OLD.pohead_terms_id <> NEW.pohead_terms_id) THEN
+          PERFORM postComment( _cmnttypeid, 'P', NEW.pohead_id,
+                               ('Terms Changed from "' || oldterms.terms_code || '" to "' || newterms.terms_code || '"') )
+          FROM terms AS oldterms, terms AS newterms
+          WHERE ( (oldterms.terms_id=OLD.pohead_terms_id)
+           AND (newterms.terms_id=NEW.pohead_terms_id) );
+        END IF;
+
+      ELSIF (TG_OP = 'DELETE') THEN
+        DELETE FROM docass WHERE docass_source_id = OLD.pohead_id AND docass_source_type = 'P';
+        DELETE FROM docass WHERE docass_target_id = OLD.pohead_id AND docass_target_type = 'P';
+        
+        DELETE FROM comment
+        WHERE ( (comment_source='P')
+         AND (comment_source_id=OLD.pohead_id) );
+      END IF;
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  ELSE
+    RETURN NEW;
+  END IF;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER poheadTrigger ON pohead;
+CREATE TRIGGER poheadTrigger BEFORE INSERT OR UPDATE OR DELETE ON pohead FOR EACH ROW EXECUTE PROCEDURE _poheadTrigger();
+
+CREATE OR REPLACE FUNCTION _poheadTriggerAfter() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (COALESCE(NEW.pohead_taxzone_id,-1) <> COALESCE(OLD.pohead_taxzone_id,-1)) THEN
+    UPDATE poitem SET poitem_taxtype_id=getItemTaxType(itemsite_item_id,NEW.pohead_taxzone_id)
+    FROM itemsite 
+    WHERE ((itemsite_id=poitem_itemsite_id)
+     AND (poitem_pohead_id=NEW.pohead_id));
+  END IF;
+
+  -- Do not update closed poitems
+  IF (TG_OP = 'UPDATE') THEN
+    IF (OLD.pohead_status != NEW.pohead_status) THEN
+      UPDATE poitem
+      SET poitem_status=NEW.pohead_status
+      WHERE ( (poitem_pohead_id=NEW.pohead_id)
+        AND   (poitem_status <> 'C') );
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropifexists('TRIGGER','poheadTriggerAfter');
+CREATE TRIGGER poheadTriggerAfter AFTER UPDATE ON pohead FOR EACH ROW EXECUTE PROCEDURE _poheadTriggerAfter();
diff --git a/foundation-database/public/trigger_functions/poitem.sql b/foundation-database/public/trigger_functions/poitem.sql
new file mode 100644 (file)
index 0000000..9b8ea5d
--- /dev/null
@@ -0,0 +1,324 @@
+CREATE OR REPLACE FUNCTION _poitemTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid  INTEGER;
+  _status              CHAR(1);
+  _check       BOOLEAN;
+  _cnt         INTEGER;
+  _s           RECORD;
+BEGIN
+
+  -- Check
+  IF ( (TG_OP = 'UPDATE') AND
+       (NOT checkPrivilege('MaintainPurchaseOrders')) AND
+       (NOT checkPrivilege('ChangePurchaseOrderQty')) AND
+       (NOT checkPrivilege('EnterReceipts')) AND
+       (NOT checkPrivilege('PostVouchers')) ) THEN
+    RAISE EXCEPTION 'You do not have privileges to alter a Purchase Order.';
+  END IF;
+  IF ( (TG_OP = 'INSERT') AND (NOT checkPrivilege('MaintainPurchaseOrders')) ) THEN
+    RAISE EXCEPTION 'You do not have privileges to alter a Purchase Order.';
+  END IF;
+
+  IF (TG_OP = 'INSERT' OR TG_OP = 'UPDATE') THEN
+    SELECT pohead_status INTO _status
+    FROM pohead
+    WHERE (pohead_id=NEW.poitem_pohead_id);
+
+    IF (NEW.poitem_itemsite_id=-1) THEN
+      NEW.poitem_itemsite_id := NULL;
+    END IF;
+    IF (NEW.poitem_expcat_id=-1) THEN
+      NEW.poitem_expcat_id := NULL;
+    END IF;
+
+    IF (NEW.poitem_itemsite_id IS NOT NULL AND NEW.poitem_expcat_id IS NOT NULL) THEN
+      RAISE EXCEPTION 'A purchase order line may not include both an inventory and non-inventory item';
+    ELSIF (NEW.poitem_itemsite_id IS NULL AND NEW.poitem_expcat_id IS NULL) THEN
+      RAISE EXCEPTION 'A purchase order line must specify either an inventory item or a non-inventory expense category';
+    ELSIF (NEW.poitem_qty_ordered IS NULL) THEN
+      RAISE EXCEPTION 'A purchase order line must specify a quantity';
+    ELSIF (COALESCE(NEW.poitem_itemsite_id,-1) != -1) THEN
+      SELECT (COUNT(item_id)=1) INTO _check
+      FROM itemsite, item
+      WHERE ((itemsite_id=NEW.poitem_itemsite_id)
+      AND (itemsite_item_id=item_id)
+      AND (item_type IN ('P','O','M','T')));
+      IF NOT (_check) THEN
+        RAISE EXCEPTION 'The item is not a purchasable item type';
+      END IF;
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    IF (_status='C') THEN
+      RAISE EXCEPTION 'New lines may not be inserted into a closed purchase order';
+    END IF;
+    
+    --Fetch and apply default item source data if applicable    
+    IF ((NEW.poitem_itemsrc_id IS NULL) AND (NEW.poitem_itemsite_id IS NOT NULL)) THEN
+      IF (NEW.poitem_itemsrc_id IS NULL) THEN
+        SELECT COUNT(itemsrc_id)  INTO _cnt
+        FROM pohead,itemsrc,itemsite
+        WHERE ((pohead_id=NEW.poitem_pohead_id)
+        AND (pohead_vend_id=itemsrc_vend_id)
+        AND (itemsite_id=NEW.poitem_itemsite_id)
+        AND (itemsite_item_id=itemsrc_item_id));
+
+        IF (_cnt = 1) THEN
+          -- We found the one and only item source, so populate data for it
+          SELECT itemsrc.* INTO _s
+          FROM pohead,itemsrc,itemsite
+          WHERE ((pohead_id=NEW.poitem_pohead_id)
+          AND (pohead_vend_id=itemsrc_vend_id)
+          AND (itemsite_id=NEW.poitem_itemsite_id)
+          AND (itemsite_item_id=itemsrc_item_id));
+          IF (FOUND) THEN
+            NEW.poitem_itemsrc_id              := _s.itemsrc_id;
+            NEW.poitem_vend_uom                := _s.itemsrc_vend_uom;
+            NEW.poitem_invvenduomratio         := _s.itemsrc_invvendoruomratio;
+            NEW.poitem_duedate                 := COALESCE(NEW.poitem_duedate, CURRENT_DATE + _s.itemsrc_leadtime);
+            NEW.poitem_vend_item_number        := COALESCE(NEW.poitem_vend_item_number,_s.itemsrc_vend_item_number);
+            NEW.poitem_vend_item_descrip       := COALESCE(NEW.poitem_vend_item_descrip,_s.itemsrc_vend_item_descrip);
+            NEW.poitem_manuf_name              := COALESCE(NEW.poitem_manuf_name,_s.itemsrc_manuf_name);
+            NEW.poitem_manuf_item_number       := COALESCE(NEW.poitem_manuf_item_number, _s.itemsrc_manuf_item_number);
+            NEW.poitem_manuf_item_descrip      := COALESCE(NEW.poitem_manuf_item_descrip, _s.itemsrc_manuf_item_descrip);
+          END IF;
+        ELSIF (_cnt > 1) THEN
+          -- There are multiple sources, see if there is an exact match with provided vendor info.
+          SELECT itemsrc.* INTO _s
+          FROM pohead,itemsrc,itemsite
+          WHERE ((pohead_id=NEW.poitem_pohead_id)
+          AND (pohead_vend_id=itemsrc_vend_id)
+          AND (itemsite_id=NEW.poitem_itemsite_id)
+          AND (itemsite_item_id=itemsrc_item_id)
+          AND (NEW.poitem_vend_item_number=itemsrc_vend_item_number)
+          AND (COALESCE(NEW.poitem_manuf_name,'')=COALESCE(itemsrc_manuf_name,''))
+          AND (COALESCE(NEW.poitem_manuf_item_number,'')=COALESCE(itemsrc_manuf_item_number,'')));
+          IF (FOUND) THEN
+            NEW.poitem_itemsrc_id              := _s.itemsrc_id;
+            NEW.poitem_vend_uom                := _s.itemsrc_vend_uom;
+            NEW.poitem_invvenduomratio         := _s.itemsrc_invvendoruomratio;
+            NEW.poitem_duedate                 := COALESCE(NEW.poitem_duedate, CURRENT_DATE + _s.itemsrc_leadtime);
+            NEW.poitem_vend_item_descrip       := COALESCE(NEW.poitem_vend_item_descrip,_s.itemsrc_vend_item_descrip);
+            NEW.poitem_manuf_item_descrip      := COALESCE(NEW.poitem_manuf_item_descrip, _s.itemsrc_manuf_item_descrip);
+          END IF;
+        END IF;
+      END IF;
+    END IF;
+
+    IF (NEW.poitem_duedate IS NULL) THEN
+      RAISE EXCEPTION  'A due date is required';
+    END IF;
+    
+    --Set defaults
+    NEW.poitem_linenumber              := COALESCE(NEW.poitem_linenumber,(
+                                               SELECT COALESCE(MAX(poitem_linenumber),0) + 1
+                                               FROM poitem
+                                               WHERE (poitem_pohead_id=NEW.poitem_pohead_id)));
+    NEW.poitem_status                  := _status;
+    NEW.poitem_invvenduomratio         := COALESCE(NEW.poitem_invvenduomratio,1);
+    IF (NEW.poitem_invvenduomratio = 0.0) THEN
+      NEW.poitem_invvenduomratio = 1.0;
+    END IF;
+    NEW.poitem_vend_item_number        := COALESCE(NEW.poitem_vend_item_number,'');
+    NEW.poitem_vend_item_descrip       := COALESCE(NEW.poitem_vend_item_descrip,'');
+    NEW.poitem_unitprice               := COALESCE(NEW.poitem_unitprice,(
+                                                SELECT itemsrcPrice(NEW.poitem_itemsrc_id, COALESCE(itemsite_warehous_id, -1), pohead_dropship,
+                                                       NEW.poitem_qty_ordered, pohead_curr_id, CURRENT_DATE)
+                                                FROM itemsite, pohead
+                                                WHERE ( (itemsite_id=NEW.poitem_itemsite_id)
+                                                AND (pohead_id=NEW.poitem_pohead_id) )), 0.0);
+    NEW.poitem_stdcost                 := COALESCE(NEW.poitem_stdcost,(
+                                               SELECT stdcost(itemsite_item_id)
+                                               FROM itemsite
+                                               WHERE (itemsite_id=NEW.poitem_itemsite_id)));
+    NEW.poitem_bom_rev_id              := COALESCE(NEW.poitem_bom_rev_id,(
+                                               SELECT getActiveRevId('BOM',itemsite_item_id)
+                                               FROM itemsite
+                                               WHERE (itemsite_id=NEW.poitem_itemsite_id)));
+    NEW.poitem_boo_rev_id              := COALESCE(NEW.poitem_boo_rev_id,(
+                                               SELECT getActiveRevId('BOO',itemsite_item_id)
+                                               FROM itemsite
+                                               WHERE (itemsite_id=NEW.poitem_itemsite_id)));
+    NEW.poitem_comments                := COALESCE(NEW.poitem_comments,'');
+    NEW.poitem_freight                 := COALESCE(NEW.poitem_freight,0);
+    NEW.poitem_qty_received            := 0;
+    NEW.poitem_qty_returned            := 0;
+    NEW.poitem_qty_vouchered           := 0;
+      
+  END IF;
+
+  IF (TG_OP = 'UPDATE') THEN
+    IF (NEW.poitem_itemsite_id != OLD.poitem_itemsite_id) THEN
+      RAISE EXCEPTION 'You may not change the item site for a line item.';
+    ELSIF (NEW.poitem_expcat_id != OLD.poitem_expcat_id) THEN
+      RAISE EXCEPTION 'You may not change the expense category for a line item.';
+    END IF;
+  END IF;
+
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropifexists('TRIGGER', 'poitemTrigger');
+CREATE TRIGGER poitemTrigger BEFORE INSERT OR UPDATE ON poitem FOR EACH ROW EXECUTE PROCEDURE _poitemTrigger();
+
+CREATE OR REPLACE FUNCTION _poitemAfterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _changelog BOOLEAN := FALSE;
+BEGIN
+
+  IF (TG_OP = 'UPDATE') THEN
+    IF (OLD.poitem_status <> NEW.poitem_status) THEN
+      IF ( (SELECT (count(*) < 1)
+              FROM poitem
+             WHERE ((poitem_pohead_id=NEW.poitem_pohead_id)
+               AND  (poitem_id != NEW.poitem_id)
+               AND  (poitem_status<>'C')) ) AND (NEW.poitem_status='C') ) THEN
+        UPDATE pohead SET pohead_status = 'C'
+         WHERE ((pohead_id=NEW.poitem_pohead_id)
+           AND  (pohead_status='O'));
+      ELSE
+        UPDATE pohead SET pohead_status = 'O'
+         WHERE ((pohead_id=NEW.poitem_pohead_id)
+           AND  (pohead_status='C'));
+      END IF;
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    PERFORM postEvent('POitemCreate', 'P', NEW.poitem_id,
+                      itemsite_warehous_id,
+                      (pohead_number || '-' || NEW.poitem_linenumber || ': ' || item_number),
+                      NULL, NULL, NULL, NULL)
+    FROM pohead JOIN itemsite ON (itemsite_id=NEW.poitem_itemsite_id)
+                JOIN item ON (item_id=itemsite_item_id)
+    WHERE (pohead_id=NEW.poitem_pohead_id)
+      AND (NEW.poitem_duedate <= (CURRENT_DATE + itemsite_eventfence));
+  END IF;
+
+  IF ( SELECT fetchMetricBool('POChangeLog') ) THEN
+    _changelog := TRUE;
+  END IF;
+
+  IF ( _changelog ) THEN
+    IF (TG_OP = 'INSERT') THEN
+      PERFORM postComment('ChangeLog', 'P', NEW.poitem_pohead_id, ('Created Line #' || NEW.poitem_linenumber::TEXT));
+      PERFORM postComment('ChangeLog', 'PI', NEW.poitem_id, 'Created');
+
+    ELSIF (TG_OP = 'UPDATE') THEN
+      IF (NEW.poitem_qty_ordered <> OLD.poitem_qty_ordered) THEN
+        PERFORM postComment( 'ChangeLog', 'PI', NEW.poitem_id,
+                             ( 'Qty. Ordered Changed from ' || formatQty(OLD.poitem_qty_ordered) ||
+                               ' to ' || formatQty(NEW.poitem_qty_ordered ) ) );
+      END IF;
+      IF (NEW.poitem_unitprice <> OLD.poitem_unitprice) THEN
+        PERFORM postComment( 'ChangeLog', 'PI', NEW.poitem_id,
+                             ( 'Unit Price Changed from ' || formatPurchPrice(OLD.poitem_unitprice) ||
+                               ' to ' || formatPurchPrice(NEW.poitem_unitprice ) ) );
+      END IF;
+      IF (NEW.poitem_duedate <> OLD.poitem_duedate) THEN
+        PERFORM postComment( 'ChangeLog', 'PI', NEW.poitem_id,
+                             ( 'Due Date Changed from ' || formatDate(OLD.poitem_duedate) ||
+                               ' to ' || formatDate(NEW.poitem_duedate ) ) );
+      END IF;
+      IF (COALESCE(OLD.poitem_taxtype_id, -1) <> COALESCE(NEW.poitem_taxtype_id, -1)) THEN
+        PERFORM postComment( 'ChangeLog', 'PI', NEW.poitem_id,
+                             ( 'Tax Type Changed from "' ||
+                               COALESCE((SELECT taxtype_name FROM taxtype WHERE taxtype_id=OLD.poitem_taxtype_id), 'None') ||
+                               '" (' || COALESCE(OLD.poitem_taxtype_id, 0) ||
+                               ') to "' ||
+                               COALESCE((SELECT taxtype_name FROM taxtype WHERE taxtype_id=NEW.poitem_taxtype_id), 'None') ||
+                               '" (' || COALESCE(NEW.poitem_taxtype_id, 0) || ')' ) );
+      END IF;
+      IF (NEW.poitem_status <> OLD.poitem_status) THEN
+        IF (NEW.poitem_status = 'C') THEN
+          PERFORM postComment('ChangeLog', 'PI', NEW.poitem_id, 'Closed');
+        ELSIF (NEW.poitem_status = 'O') THEN
+          PERFORM postComment('ChangeLog', 'PI', NEW.poitem_id, 'Opened');
+        END IF;
+      END IF;
+
+    END IF;
+  END IF;
+
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropifexists('TRIGGER', 'poitemAfterTrigger');
+CREATE TRIGGER poitemAfterTrigger AFTER INSERT OR UPDATE ON poitem FOR EACH ROW EXECUTE PROCEDURE _poitemAfterTrigger();
+
+CREATE OR REPLACE FUNCTION _poitemDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+BEGIN
+
+  IF (NOT checkPrivilege('MaintainPurchaseOrders')) THEN
+    RAISE EXCEPTION 'You do not have privileges to alter a Purchase Order.';
+  END IF;
+
+  IF (EXISTS(SELECT recv_id
+             FROM recv
+             WHERE ((recv_order_type='PO')
+                AND (recv_orderitem_id=OLD.poitem_id)
+                AND (recv_qty>0)))) THEN
+    RAISE EXCEPTION 'Cannot delete an P/O Item which has been received';
+  END IF;
+
+  DELETE FROM comment
+   WHERE ( (comment_source='PI')
+     AND   (comment_source_id=OLD.poitem_id) );
+
+  DELETE FROM charass
+   WHERE ((charass_target_type='PI')
+     AND  (charass_target_id=OLD.poitem_id));
+
+  RETURN OLD;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropifexists('TRIGGER', 'poitemDeleteTrigger');
+CREATE TRIGGER poitemDeleteTrigger BEFORE DELETE ON poitem FOR EACH ROW EXECUTE PROCEDURE _poitemDeleteTrigger();
+
+CREATE OR REPLACE FUNCTION _poitemAfterDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _changelog BOOLEAN := FALSE;
+BEGIN
+
+  IF (OLD.poitem_status = 'O') THEN
+    IF ( (SELECT (count(*) < 1)
+            FROM poitem
+           WHERE ((poitem_pohead_id=OLD.poitem_pohead_id)
+             AND  (poitem_id != OLD.poitem_id)
+             AND  (poitem_status <> 'C')) ) ) THEN
+      UPDATE pohead SET pohead_status = 'C'
+       WHERE ((pohead_id=OLD.poitem_pohead_id)
+         AND  (pohead_status='O'));
+    END IF;
+  END IF;
+
+  IF ( SELECT fetchMetricBool('POChangeLog') ) THEN
+    _changelog := TRUE;
+  END IF;
+
+  IF ( _changelog ) THEN
+    PERFORM postComment('ChangeLog', 'P', OLD.poitem_pohead_id, ('Deleted Line #' || OLD.poitem_linenumber::TEXT));
+  END IF;
+
+  RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropifexists('TRIGGER', 'poitemAfterDeleteTrigger');
+CREATE TRIGGER poitemAfterDeleteTrigger AFTER DELETE ON poitem FOR EACH ROW EXECUTE PROCEDURE _poitemAfterDeleteTrigger();
diff --git a/foundation-database/public/trigger_functions/pr.sql b/foundation-database/public/trigger_functions/pr.sql
new file mode 100644 (file)
index 0000000..f92df97
--- /dev/null
@@ -0,0 +1,14 @@
+SELECT dropIfExists('TRIGGER', 'prTrigger');
+
+CREATE OR REPLACE FUNCTION _prTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/EULA for the full text of the software license.
+BEGIN
+  --- clear the number from the issue cache
+  PERFORM clearNumberIssue('PrNumber', NEW.pr_number);
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE TRIGGER prTrigger AFTER INSERT ON pr FOR EACH ROW EXECUTE PROCEDURE _prTrigger();
diff --git a/foundation-database/public/trigger_functions/prj.sql b/foundation-database/public/trigger_functions/prj.sql
new file mode 100644 (file)
index 0000000..0cb8170
--- /dev/null
@@ -0,0 +1,94 @@
+CREATE OR REPLACE FUNCTION _prjBeforeDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _recurid     INTEGER;
+  _newparentid INTEGER;
+BEGIN
+
+  IF (TG_OP = 'DELETE') THEN
+    DELETE FROM docass WHERE docass_source_id = OLD.prj_id AND docass_source_type = 'J';
+    DELETE FROM docass WHERE docass_target_id = OLD.prj_id AND docass_target_type = 'J';
+    
+    SELECT recur_id INTO _recurid
+      FROM recur
+     WHERE ((recur_parent_id=OLD.prj_id)
+        AND (recur_parent_type='J'));
+
+    IF (_recurid IS NOT NULL) THEN
+      SELECT MIN(prj_id) INTO _newparentid
+        FROM prj
+       WHERE ((prj_recurring_prj_id=OLD.prj_id)
+          AND (prj_id!=OLD.prj_id));
+
+      -- client is responsible for warning about deleting a recurring prj
+      IF (_newparentid IS NULL) THEN
+        DELETE FROM recur WHERE recur_id=_recurid;
+      ELSE
+        UPDATE recur SET recur_parent_id=_newparentid
+         WHERE recur_id=_recurid;
+      END IF;
+
+    END IF;
+
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'prjbeforedeletetrigger');
+CREATE TRIGGER prjbeforedeletetrigger
+  BEFORE DELETE
+  ON prj
+  FOR EACH ROW
+  EXECUTE PROCEDURE _prjBeforeDeleteTrigger();
+
+CREATE OR REPLACE FUNCTION _prjAfterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid INTEGER;
+BEGIN
+
+--  Cache the cmnttype_id for ChangeLog
+  SELECT cmnttype_id INTO _cmnttypeid
+  FROM cmnttype
+  WHERE (cmnttype_name='ChangeLog');
+  IF (NOT FOUND) THEN
+    RAISE EXCEPTION 'Comment type ChangeLog not found';
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    PERFORM postComment(_cmnttypeid, 'J', NEW.prj_id, 'Created');
+  ELSIF (TG_OP = 'UPDATE') THEN
+    IF (OLD.prj_start_date <> NEW.prj_start_date) THEN
+      PERFORM postComment( _cmnttypeid, 'J', NEW.prj_id,
+                           ('Start Date Changed from ' || formatDate(OLD.prj_start_date) || ' to ' || formatDate(NEW.prj_start_date)) );
+    END IF;
+    IF (OLD.prj_due_date <> NEW.prj_due_date) THEN
+      PERFORM postComment( _cmnttypeid, 'J', NEW.prj_id,
+                           ('Due Date Changed from ' || formatDate(OLD.prj_due_date) || ' to ' || formatDate(NEW.prj_due_date)) );
+    END IF;
+    IF (OLD.prj_assigned_date <> NEW.prj_assigned_date) THEN
+      PERFORM postComment( _cmnttypeid, 'J', NEW.prj_id,
+                           ('Assigned Date Changed from ' || formatDate(OLD.prj_assigned_date) || ' to ' || formatDate(NEW.prj_assigned_date)) );
+    END IF;
+    IF (OLD.prj_completed_date <> NEW.prj_completed_date) THEN
+      PERFORM postComment( _cmnttypeid, 'J', NEW.prj_id,
+                           ('Completed Date Changed from ' || formatDate(OLD.prj_completed_date) || ' to ' || formatDate(NEW.prj_completed_date)) );
+    END IF;
+
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'prjaftertrigger');
+CREATE TRIGGER prjaftertrigger
+  AFTER INSERT OR UPDATE
+  ON prj
+  FOR EACH ROW
+  EXECUTE PROCEDURE _prjAfterTrigger();
diff --git a/foundation-database/public/trigger_functions/prjtask.sql b/foundation-database/public/trigger_functions/prjtask.sql
new file mode 100644 (file)
index 0000000..bc92191
--- /dev/null
@@ -0,0 +1,76 @@
+CREATE OR REPLACE FUNCTION _prjtaskTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+  --  Checks
+  IF (NEW.prjtask_owner_username=getEffectiveXtUser()) THEN
+    IF (NOT checkPrivilege('MaintainAllProjects') AND NOT checkPrivilege('MaintainPersonalProjects')) THEN
+      RAISE EXCEPTION 'You do not have privileges to maintain Projects.';
+    END IF;
+  ELSIF (NOT checkPrivilege('MaintainAllProjects')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Projects.';
+  ELSIF (LENGTH(COALESCE(NEW.prjtask_number,'')) = 0) THEN
+    RAISE EXCEPTION 'You must ender a valid number.';
+  ELSIF (LENGTH(COALESCE(NEW.prjtask_name,'')) = 0) THEN
+    RAISE EXCEPTION 'You must ender a valid name.';    
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'prjtaskTrigger');
+CREATE TRIGGER prjtaskTrigger BEFORE INSERT OR UPDATE ON prjtask FOR EACH ROW EXECUTE PROCEDURE _prjtaskTrigger();
+
+CREATE OR REPLACE FUNCTION _prjtaskAfterTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid INTEGER;
+BEGIN
+
+  SELECT cmnttype_id INTO _cmnttypeid
+  FROM cmnttype
+  WHERE (cmnttype_name='ChangeLog');
+  IF (NOT FOUND) THEN
+    RAISE EXCEPTION 'Comment type ChangeLog not found';
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    PERFORM postComment(_cmnttypeid, 'TA', NEW.prjtask_id, 'Created');
+
+  ELSIF (TG_OP = 'UPDATE') THEN
+    IF (OLD.prjtask_start_date <> NEW.prjtask_start_date) THEN
+      PERFORM postComment( _cmnttypeid, 'TA', NEW.prjtask_id,
+                           ('Start Date Changed from ' || formatDate(OLD.prjtask_start_date) || ' to ' || formatDate(NEW.prjtask_start_date)) );
+    END IF;
+    IF (OLD.prjtask_due_date <> NEW.prjtask_due_date) THEN
+      PERFORM postComment( _cmnttypeid, 'TA', NEW.prjtask_id,
+                           ('Due Date Changed from ' || formatDate(OLD.prjtask_due_date) || ' to ' || formatDate(NEW.prjtask_due_date)) );
+    END IF;
+    IF (OLD.prjtask_assigned_date <> NEW.prjtask_assigned_date) THEN
+      PERFORM postComment( _cmnttypeid, 'TA', NEW.prjtask_id,
+                           ('Assigned Date Changed from ' || formatDate(OLD.prjtask_assigned_date) || ' to ' || formatDate(NEW.prjtask_assigned_date)) );
+    END IF;
+    IF (OLD.prjtask_completed_date <> NEW.prjtask_completed_date) THEN
+      PERFORM postComment( _cmnttypeid, 'TA', NEW.prjtask_id,
+                           ('Completed Date Changed from ' || formatDate(OLD.prjtask_completed_date) || ' to ' || formatDate(NEW.prjtask_completed_date)) );
+    END IF;
+    IF (OLD.prjtask_hours_actual != NEW.prjtask_hours_actual) THEN
+      PERFORM postComment(_cmnttypeid, 'TA', NEW.prjtask_id, 
+          'Actual Hours changed from ' || formatQty(OLD.prjtask_hours_actual) || ' to ' || formatQty(NEW.prjtask_hours_actual));
+    END IF;
+    IF (OLD.prjtask_exp_actual != NEW.prjtask_exp_actual) THEN
+      PERFORM postComment(_cmnttypeid, 'TA', NEW.prjtask_id, 
+          'Actual Expense changed from ' || formatQty(OLD.prjtask_exp_actual) || ' to ' || formatQty(NEW.prjtask_exp_actual));
+    END IF;
+
+  END IF;
+  
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'prjtaskAfterTrigger');
+CREATE TRIGGER prjtaskAfterTrigger AFTER INSERT OR UPDATE ON prjtask FOR EACH ROW EXECUTE PROCEDURE _prjtaskAfterTrigger();
diff --git a/foundation-database/public/trigger_functions/prospect.sql b/foundation-database/public/trigger_functions/prospect.sql
new file mode 100644 (file)
index 0000000..f3adb8f
--- /dev/null
@@ -0,0 +1,208 @@
+CREATE OR REPLACE FUNCTION _prospectTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple.
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (NOT checkPrivilege('MaintainProspectMasters')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Prospects.';
+  END IF;
+
+  IF (NEW.prospect_number IS NULL) THEN
+    RAISE EXCEPTION 'You must supply a valid Prospect Number.';
+  END IF;
+
+  NEW.prospect_number := UPPER(NEW.prospect_number);
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('trigger', 'prospectTrigger');
+CREATE TRIGGER prospectTrigger BEFORE INSERT OR UPDATE ON prospect
+       FOR EACH ROW EXECUTE PROCEDURE _prospectTrigger();
+
+CREATE OR REPLACE FUNCTION _prospectAfterTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple.
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid   INTEGER;
+  _custid       INTEGER;
+  _prospectid   INTEGER;
+
+BEGIN
+
+  IF (TG_OP = 'INSERT') THEN
+    SELECT crmacct_cust_id, crmacct_prospect_id INTO _custid, _prospectid
+      FROM crmacct
+     WHERE crmacct_number=NEW.prospect_number;
+
+    IF (_custid > 0 AND _custid != _prospectid) THEN
+      RAISE EXCEPTION '[xtuple: createProspect, -2]';
+    END IF;
+
+    IF (_prospectid > 0) THEN
+      RAISE EXCEPTION '[xtuple: createProspect, -3]';
+    END IF;
+
+    -- http://www.postgresql.org/docs/current/static/plpgsql-control-structures.html#PLPGSQL-UPSERT-EXAMPLE
+    LOOP
+      UPDATE crmacct SET crmacct_prospect_id=NEW.prospect_id,
+                         crmacct_cust_id=NULL,
+                         crmacct_name=NEW.prospect_name
+       WHERE crmacct_number=NEW.prospect_number;
+      IF (FOUND) THEN
+        EXIT;
+      END IF;
+      BEGIN
+        INSERT INTO crmacct(crmacct_number,      crmacct_name,
+                            crmacct_active,      crmacct_type,
+                            crmacct_prospect_id, crmacct_cntct_id_1
+                  ) VALUES (NEW.prospect_number, NEW.prospect_name,
+                            NEW.prospect_active, 'O',
+                            NEW.prospect_id,     NEW.prospect_cntct_id);
+        EXIT;
+      EXCEPTION WHEN unique_violation THEN
+            -- do nothing, and loop to try the UPDATE again
+      END;
+    END LOOP;
+
+    /* TODO: default characteristic assignments based on what? */
+
+  ELSIF (TG_OP = 'UPDATE') THEN
+    UPDATE crmacct SET crmacct_number = NEW.prospect_number
+    WHERE ((crmacct_prospect_id=NEW.prospect_id)
+      AND  (crmacct_number!=NEW.prospect_number));
+
+    UPDATE crmacct SET crmacct_name = NEW.prospect_name
+    WHERE ((crmacct_prospect_id=NEW.prospect_id)
+      AND  (crmacct_name!=NEW.prospect_name));
+
+  END IF;
+
+  IF (fetchMetricBool('ProspectChangeLog')) THEN
+    SELECT cmnttype_id INTO _cmnttypeid
+      FROM cmnttype
+     WHERE (cmnttype_name='ChangeLog');
+
+    IF (_cmnttypeid IS NOT NULL) THEN
+      IF (TG_OP = 'INSERT') THEN
+        PERFORM postComment(_cmnttypeid, 'PSPCT', NEW.prospect_id, 'Created');
+
+      ELSIF (TG_OP = 'UPDATE') THEN
+        IF (OLD.prospect_active <> NEW.prospect_active) THEN
+          PERFORM postComment(_cmnttypeid, 'PSPCT', NEW.prospect_id,
+                              CASE WHEN NEW.prospect_active THEN 'Activated'
+                                   ELSE 'Deactivated' END);
+        END IF;
+
+        IF (OLD.prospect_number <> NEW.prospect_number) THEN
+          PERFORM postComment(_cmnttypeid, 'PSPCT', NEW.prospect_id,
+                              'Number changed from "' || OLD.prospect_number ||
+                              '" to "' || NEW.prospect_number || '"');
+        END IF;
+
+        IF (OLD.prospect_name <> NEW.prospect_name) THEN
+          PERFORM postComment(_cmnttypeid, 'PSPCT', NEW.prospect_id,
+                              'Name changed from "' || OLD.prospect_name ||
+                              '" to "' || NEW.prospect_name || '"');
+        END IF;
+
+        IF (OLD.prospect_cntct_id <> NEW.prospect_cntct_id) THEN
+          PERFORM postComment(_cmnttypeid, 'PSPCT', NEW.prospect_id,
+                              'Contact changed from "' ||
+                              formatCntctName(OLD.prospect_cntct_id) || '" to "' ||
+                              formatCntctName(NEW.prospect_cntct_id) || '"');
+        END IF;
+
+        IF (OLD.prospect_taxauth_id <> NEW.prospect_taxauth_id) THEN
+          PERFORM postComment(_cmnttypeid, 'PSPCT', NEW.prospect_id,
+                              'Tax Authority changed from "' ||
+                              (SELECT taxauth_code FROM taxauth
+                                WHERE taxauth_id=OLD.prospect_taxauth_id) ||
+                              '" to "' ||
+                              (SELECT taxauth_code FROM taxauth
+                                WHERE taxauth_id=NEW.prospect_taxauth_id) || '"');
+        END IF;
+
+        IF (OLD.prospect_salesrep_id <> NEW.prospect_salesrep_id) THEN
+          PERFORM postComment(_cmnttypeid, 'PSPCT', NEW.prospect_id,
+                              'Sales Rep changed from "' ||
+                              (SELECT salesrep_number FROM salesrep
+                               WHERE salesrep_id=OLD.prospect_salesrep_id) ||
+                              '" to "' ||
+                              (SELECT salesrep_number FROM salesrep
+                               WHERE salesrep_id=NEW.prospect_salesrep_id) || '"');
+        END IF;
+
+        IF (OLD.prospect_warehous_id <> NEW.prospect_warehous_id) THEN
+          PERFORM postComment(_cmnttypeid, 'PSPCT', NEW.prospect_id,
+                              'Warehouse changed from "' ||
+                              (SELECT warehous_code FROM whsinfo
+                                WHERE warehous_id=OLD.prospect_warehous_id) ||
+                              '" to "' ||
+                              (SELECT warehous_code FROM whsinfo
+                                WHERE warehous_id=NEW.prospect_warehous_id) || '"');
+        END IF;
+
+        IF (OLD.prospect_taxzone_id <> NEW.prospect_taxzone_id) THEN
+          PERFORM postComment(_cmnttypeid, 'PSPCT', NEW.prospect_id,
+                              'Tax Zone changed from "' ||
+                              (SELECT taxzone_code FROM taxzone
+                                WHERE taxzone_id=OLD.prospect_taxzone_id) || '" to "' ||
+                              (SELECT taxzone_code FROM taxzone
+                                WHERE taxzone_id=NEW.prospect_taxzone_id) || '"');
+        END IF;
+
+      END IF;
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'prospectAfterTrigger');
+CREATE TRIGGER prospectAfterTrigger AFTER INSERT OR UPDATE ON prospect
+       FOR EACH ROW EXECUTE PROCEDURE _prospectAfterTrigger();
+
+CREATE OR REPLACE FUNCTION _prospectBeforeDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple.
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (NOT checkPrivilege('MaintainProspectMasters')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Prospects.';
+  END IF;
+
+  UPDATE crmacct SET crmacct_prospect_id = NULL
+   WHERE crmacct_prospect_id = OLD.prospect_id;
+
+  RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('trigger', 'prospectBeforeDeleteTrigger');
+CREATE TRIGGER prospectBeforeDeleteTrigger BEFORE DELETE ON prospect
+       FOR EACH ROW EXECUTE PROCEDURE _prospectBeforeDeleteTrigger();
+
+CREATE OR REPLACE FUNCTION _prospectAfterDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple.
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF EXISTS(SELECT 1 FROM quhead WHERE quhead_cust_id = OLD.prospect_id) AND
+     NOT EXISTS (SELECT 1 FROM custinfo WHERE cust_id = OLD.prospect_id) THEN
+    RAISE EXCEPTION '[xtuple: deleteProspect, -1]';
+  END IF;
+
+  IF (fetchMetricBool('ProspectChangeLog')) THEN
+    PERFORM postComment(cmnttype_id, 'PSPCT', OLD.prospect_id,
+                        'Deleted "' || OLD.prospect_number || '"')
+      FROM cmnttype
+     WHERE (cmnttype_name='ChangeLog');
+  END IF;
+
+  RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'prospectAfterDeleteTrigger');
+CREATE TRIGGER prospectAfterDeleteTrigger AFTER DELETE ON prospect
+       FOR EACH ROW EXECUTE PROCEDURE _prospectAfterDeleteTrigger();
diff --git a/foundation-database/public/trigger_functions/quhead.sql b/foundation-database/public/trigger_functions/quhead.sql
new file mode 100644 (file)
index 0000000..65bd09a
--- /dev/null
@@ -0,0 +1,321 @@
+CREATE OR REPLACE FUNCTION _quheadtrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid INTEGER;
+  _oldHoldType TEXT;
+  _newHoldType TEXT;
+  _p RECORD;
+  _a RECORD;
+  _w RECORD;
+  _shiptoId INTEGER;
+  _addrId INTEGER;
+  _prjId INTEGER;
+  _check BOOLEAN;
+  _numGen CHAR(1);
+
+BEGIN
+
+  --  Checks
+  SELECT checkPrivilege('MaintainQuotes') INTO _check;
+  IF NOT (_check) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Quotes.';
+  END IF;
+
+  -- If this is imported, check the quote number
+  IF (TG_OP = 'INSERT') THEN
+    IF (NEW.quhead_imported) THEN
+      SELECT fetchMetricText('QUNumberGeneration') INTO _numGen;
+      IF ((NEW.quhead_number IS NULL) AND (_numGen='M')) THEN
+        RAISE EXCEPTION 'You must supply a Quote Number.';
+      ELSE
+        IF ((NEW.quhead_number IS NOT NULL) AND (_numGen='A')) THEN
+          RAISE EXCEPTION 'You may not supply a new Quote Number xTuple will generate the number.';
+        ELSE
+          IF ((NEW.quhead_number IS NULL) AND (_numGen='O')) THEN
+            SELECT fetchqunumber() INTO NEW.quhead_number;
+          ELSE
+            IF (NEW.quhead_number IS NULL) THEN
+              SELECT fetchsonumber() INTO NEW.quhead_number;
+            END IF;
+          END IF;
+        END IF;
+      END IF;
+    END IF;
+    
+    IF (fetchMetricText('QUNumberGeneration') IN ('A','O')) THEN
+      --- clear the number from the issue cache
+      PERFORM clearNumberIssue('QuNumber', NEW.quhead_number);
+    ELSIF (fetchMetricText('QUNumberGeneration') = 'S') THEN
+      --- clear the number from the issue cache
+      PERFORM clearNumberIssue('SoNumber', NEW.quhead_number);
+    END IF;
+    
+  ELSE
+    IF (TG_OP = 'UPDATE') THEN
+       IF (NEW.quhead_number <> OLD.quhead_number) THEN
+         RAISE EXCEPTION 'The order number may not be changed.';
+       END IF;
+    END IF;
+  END IF;
+
+  IF (TG_OP IN ('INSERT','UPDATE')) THEN
+    -- Get Customer data
+    IF (NEW.quhead_shipto_id IS NULL) THEN
+      SELECT * INTO _p FROM (
+      SELECT cust_number,cust_usespos,cust_blanketpos,cust_ffbillto,
+            cust_ffshipto,cust_name,cust_salesrep_id,cust_terms_id,cust_shipvia,
+            cust_commprcnt,cust_curr_id,cust_taxzone_id,
+            addr_line1,addr_line2,addr_line3,addr_city,addr_state,addr_postalcode,addr_country,
+            shipto_id,shipto_addr_id,shipto_name,shipto_salesrep_id,shipto_shipvia,
+            shipto_shipchrg_id,shipto_shipform_id,shipto_commission,shipto_taxzone_id
+      FROM custinfo
+        LEFT OUTER JOIN cntct ON (cust_cntct_id=cntct_id)
+        LEFT OUTER JOIN addr ON (cntct_addr_id=addr_id)
+        LEFT OUTER JOIN shiptoinfo ON ((cust_id=shipto_cust_id) AND shipto_default)
+      WHERE (cust_id=NEW.quhead_cust_id)
+      UNION
+      SELECT prospect_number,false,false,true,
+            true,prospect_name,prospect_salesrep_id,null,null,
+            null,null,prospect_taxzone_id,
+            addr_line1,addr_line2,addr_line3,addr_city,addr_state,addr_postalcode,addr_country,
+            null,null,null,null,null,
+            null,null,null,null
+      FROM prospect
+        LEFT OUTER JOIN cntct ON (prospect_cntct_id=cntct_id)
+        LEFT OUTER JOIN addr ON (cntct_addr_id=addr_id)
+      WHERE (prospect_id=NEW.quhead_cust_id)) AS data;
+    ELSE
+      SELECT cust_creditstatus,cust_number,cust_usespos,cust_blanketpos,cust_ffbillto,
+            cust_ffshipto,cust_name,cust_salesrep_id,cust_terms_id,cust_shipvia,
+            cust_shipchrg_id,cust_shipform_id,cust_commprcnt,cust_curr_id,cust_taxzone_id,
+            addr_line1,addr_line2,addr_line3,addr_city,addr_state,addr_postalcode,addr_country,
+            shipto_id,shipto_addr_id,shipto_name,shipto_salesrep_id,shipto_shipvia,
+            shipto_shipchrg_id,shipto_shipform_id,shipto_commission,shipto_taxzone_id INTO _p
+      FROM shiptoinfo,custinfo
+        LEFT OUTER JOIN cntct ON (cust_cntct_id=cntct_id)
+        LEFT OUTER JOIN addr ON (cntct_addr_id=addr_id)
+      WHERE ((cust_id=NEW.quhead_cust_id)
+      AND (shipto_id=shipto_id));
+    END IF;
+
+    -- If there is customer data, then we can get to work
+    IF (FOUND) THEN
+      -- Only check PO number for imports because UI checks when whole quote is saved
+      IF (TG_OP = 'INSERT') THEN
+          -- Set to defaults if values not provided
+          NEW.quhead_shipto_id         := COALESCE(NEW.quhead_shipto_id,_p.shipto_id);
+         NEW.quhead_salesrep_id        := COALESCE(NEW.quhead_salesrep_id,_p.shipto_salesrep_id,_p.cust_salesrep_id);
+          NEW.quhead_terms_id          := COALESCE(NEW.quhead_terms_id,_p.cust_terms_id);
+          NEW.quhead_shipvia           := COALESCE(NEW.quhead_shipvia,_p.shipto_shipvia,_p.cust_shipvia);
+          NEW.quhead_commission                := COALESCE(NEW.quhead_commission,_p.shipto_commission,_p.cust_commprcnt);
+          NEW.quhead_quotedate         := COALESCE(NEW.quhead_quotedate,current_date);
+          NEW.quhead_packdate          := COALESCE(NEW.quhead_packdate,NEW.quhead_quotedate);
+          NEW.quhead_curr_id           := COALESCE(NEW.quhead_curr_id,_p.cust_curr_id,basecurrid());
+          NEW.quhead_taxzone_id                := COALESCE(NEW.quhead_taxzone_id,_p.shipto_taxzone_id,_p.cust_taxzone_id);
+          NEW.quhead_freight           := COALESCE(NEW.quhead_freight,0);
+          NEW.quhead_custponumber      := COALESCE(NEW.quhead_custponumber,'');
+          NEW.quhead_ordercomments     := COALESCE(NEW.quhead_ordercomments,'');
+          NEW.quhead_shipcomments      := COALESCE(NEW.quhead_shipcomments,'');
+          NEW.quhead_shiptophone       := COALESCE(NEW.quhead_shiptophone,'');
+          NEW.quhead_misc              := COALESCE(NEW.quhead_misc,0);
+          NEW.quhead_misc_descrip      := COALESCE(NEW.quhead_misc_descrip,'');
+
+          IF ((NEW.quhead_warehous_id IS NULL) OR (NEW.quhead_fob IS NULL)) THEN
+            IF (NEW.quhead_warehous_id IS NULL) THEN
+              SELECT warehous_id,warehous_fob INTO _w
+              FROM usrpref, whsinfo
+              WHERE ((warehous_id=CAST(usrpref_value AS INTEGER))
+                AND (warehous_shipping)
+                AND (warehous_active)
+                AND (usrpref_username=getEffectiveXtUser())
+                AND (usrpref_name='PreferredWarehouse'));
+            ELSE
+              SELECT warehous_id,warehous_fob INTO _w
+              FROM whsinfo
+              WHERE (warehous_id=NEW.quhead_warehous_id);
+            END IF;
+            
+            IF (FOUND) THEN
+              NEW.quhead_warehous_id   := COALESCE(NEW.quhead_warehous_id,_w.warehous_id);
+              NEW.quhead_fob           := COALESCE(NEW.quhead_fob,_w.warehous_fob);
+            END IF;
+          END IF;
+      END IF;
+      
+      --Auto create project if applicable
+      IF ((TG_OP = 'INSERT') AND (COALESCE(NEW.quhead_prj_id,-1)=-1)) THEN
+        SELECT fetchMetricBool('AutoCreateProjectsForOrders') INTO _check;
+        IF (_check) THEN
+          SELECT NEXTVAL('prj_prj_id_seq') INTO _prjId;
+          NEW.quhead_prj_id := _prjId;
+          INSERT INTO prj (prj_id, prj_number, prj_name, prj_descrip,
+                           prj_status, prj_so, prj_wo, prj_po,
+                           prj_owner_username, prj_start_date, prj_due_date,
+                           prj_assigned_date, prj_completed_date, prj_username,
+                           prj_recurring_prj_id, prj_crmacct_id,
+                           prj_cntct_id, prj_prjtype_id)
+          SELECT _prjId, NEW.quhead_number, NEW.quhead_number, 'Auto Generated Project from Quote.',
+                 'O', TRUE, TRUE, TRUE,
+                 getEffectiveXTUser(), NEW.quhead_quotedate, NEW.quhead_packdate,
+                 NEW.quhead_quotedate, NULL, getEffectiveXTUser(),
+                 NULL, crmacct_id,
+                 NEW.quhead_billto_cntct_id, NULL
+          FROM crmacct
+          WHERE (crmacct_cust_id=NEW.quhead_cust_id)
+             OR (crmacct_prospect_id=NEW.quhead_cust_id)
+          LIMIT 1;
+        END IF;
+      END IF;
+
+      -- Deal with Billing Address
+      IF (TG_OP = 'INSERT') THEN
+        IF (_p.cust_ffbillto) THEN
+          -- If they didn't supply data, we'll put in the bill to address
+          NEW.quhead_billtoname=COALESCE(NEW.quhead_billtoname,_p.cust_name,'');
+          NEW.quhead_billtoaddress1=COALESCE(NEW.quhead_billtoaddress1,_p.addr_line1,'');
+          NEW.quhead_billtoaddress2=COALESCE(NEW.quhead_billtoaddress2,_p.addr_line2,'');
+          NEW.quhead_billtoaddress3=COALESCE(NEW.quhead_billtoaddress3,_p.addr_line3,'');    
+          NEW.quhead_billtocity=COALESCE(NEW.quhead_billtocity,_p.addr_city,''); 
+          NEW.quhead_billtostate=COALESCE(NEW.quhead_billtostate,_p.addr_state,'');
+          NEW.quhead_billtozip=COALESCE(NEW.quhead_billtozip,_p.addr_postalcode,'');
+          NEW.quhead_billtocountry=COALESCE(NEW.quhead_billtocountry,_p.addr_country,'');   
+        ELSE
+          -- Free form not allowed, we're going to put in the address regardless
+          NEW.quhead_billtoname=COALESCE(_p.cust_name,'');
+          NEW.quhead_billtoaddress1=COALESCE(_p.addr_line1,'');
+          NEW.quhead_billtoaddress2=COALESCE(_p.addr_line2,'');
+          NEW.quhead_billtoaddress3=COALESCE(_p.addr_line3,'');    
+          NEW.quhead_billtocity=COALESCE(_p.addr_city,''); 
+          NEW.quhead_billtostate=COALESCE(_p.addr_state,'');
+          NEW.quhead_billtozip=COALESCE(_p.addr_postalcode,'');
+          NEW.quhead_billtocountry=COALESCE(_p.addr_country,'');
+        END IF;
+      END IF;
+
+      -- Now let's look at Shipto Address
+      -- If there's nothing in the address fields and there is a shipto id 
+      -- or there is a default address available, let's put in some shipto address data
+      IF ((TG_OP = 'INSERT') 
+       AND NOT ((NEW.quhead_shipto_id IS NULL) AND NOT _p.cust_ffshipto)
+       AND (NEW.quhead_shiptoname IS NULL)
+       AND (NEW.quhead_shiptoaddress1 IS NULL)
+       AND (NEW.quhead_shiptoaddress2 IS NULL)
+       AND (NEW.quhead_shiptoaddress3 IS NULL)
+       AND (NEW.quhead_shiptocity IS NULL)
+       AND (NEW.quhead_shiptostate IS NULL)
+       AND (NEW.quhead_shiptocountry IS NULL)) THEN
+        IF ((NEW.quhead_shipto_id IS NULL) AND (_p.shipto_id IS NOT NULL)) THEN
+          _shiptoId := _p.shipto_addr_id;
+        ELSE
+          _shiptoId := NEW.quhead_shipto_id;
+        END IF;
+
+        SELECT * INTO _a 
+        FROM shiptoinfo, addr 
+        WHERE ((shipto_id=_shiptoId)
+        AND (addr_id=shipto_addr_id));
+
+        NEW.quhead_shiptoname := COALESCE(_p.shipto_name,'');
+        NEW.quhead_shiptoaddress1 := COALESCE(_a.addr_line1,'');
+        NEW.quhead_shiptoaddress2 := COALESCE(_a.addr_line2,'');
+        NEW.quhead_shiptoaddress3 := COALESCE(_a.addr_line3,'');    
+        NEW.quhead_shiptocity := COALESCE(_a.addr_city,''); 
+        NEW.quhead_shiptostate := COALESCE(_a.addr_state,'');
+        NEW.quhead_shiptozipcode := COALESCE(_a.addr_postalcode,'');
+        NEW.quhead_shiptocountry := COALESCE(_a.addr_country,'');
+      ELSE
+        IF (_p.cust_ffshipto) THEN
+          -- Use Address Save function to see if the new address entered matches
+          -- data for the shipto number.  If not that will insert new address for CRM
+          SELECT SaveAddr(
+            NULL,
+            NULL,
+            NEW.quhead_shiptoaddress1,
+            NEW.quhead_shiptoaddress2,
+            NEW.quhead_shiptoaddress3,
+            NEW.quhead_shiptocity,
+            NEW.quhead_shiptostate,
+            NEW.quhead_shiptozipcode,
+            NEW.quhead_shiptocountry,
+            'CHANGEONE') INTO _addrId;
+          SELECT shipto_addr_id INTO _shiptoid FROM shiptoinfo WHERE (shipto_id=NEW.quhead_shipto_id);
+           -- If the address passed doesn't match shipto address, then it's something else
+           IF (_shiptoid <> _addrId) THEN
+             NEW.quhead_shipto_id := NULL;
+           END IF;
+        ELSE
+          SELECT quhead_shipto_id INTO _shiptoid FROM quhead WHERE (quhead_id=NEW.quhead_id);
+          -- Get the shipto address
+            IF (COALESCE(NEW.quhead_shipto_id,-1) <> COALESCE(_shiptoid,-1)) THEN
+            SELECT * INTO _a 
+            FROM shiptoinfo
+            LEFT OUTER JOIN cntct ON (shipto_cntct_id=cntct_id)
+            LEFT OUTER JOIN addr ON (shipto_addr_id=addr_id)
+            WHERE (shipto_id=NEW.quhead_shipto_id);
+            IF (FOUND) THEN
+              -- Free form not allowed so we're going to make sure address matches Shipto data
+              NEW.quhead_shiptoname := COALESCE(_a.shipto_name,'');
+              NEW.quhead_shiptophone := COALESCE(_a.cntct_phone,'');
+              NEW.quhead_shiptoaddress1 := COALESCE(_a.addr_line1,'');
+              NEW.quhead_shiptoaddress2 := COALESCE(_a.addr_line2,'');
+              NEW.quhead_shiptoaddress3 := COALESCE(_a.addr_line3,'');    
+              NEW.quhead_shiptocity := COALESCE(_a.addr_city,''); 
+              NEW.quhead_shiptostate := COALESCE(_a.addr_state,'');
+              NEW.quhead_shiptozipcode := COALESCE(_a.addr_postalcode,'');
+              NEW.quhead_shiptocountry := COALESCE(_a.addr_country,''); 
+            ELSE
+              -- If no shipto data and free form not allowed, this won't work
+              RAISE EXCEPTION 'Free form Shipto is not allowed on this Customer. You must supply a valid Shipto ID.';
+            END IF;
+          END IF;
+        END IF;
+      END IF;
+    END IF;
+  END IF;
+
+  IF ( SELECT (metric_value='t')
+       FROM metric
+       WHERE (metric_name='SalesOrderChangeLog') ) THEN
+
+--  Cache the cmnttype_id for ChangeLog
+    SELECT cmnttype_id INTO _cmnttypeid
+    FROM cmnttype
+    WHERE (cmnttype_name='ChangeLog');
+    IF (FOUND) THEN
+      IF (TG_OP = 'INSERT') THEN
+        PERFORM postComment(_cmnttypeid, 'Q', NEW.quhead_id, 'Created');
+
+      ELSIF (TG_OP = 'UPDATE') THEN
+
+        IF (OLD.quhead_terms_id <> NEW.quhead_terms_id) THEN
+          PERFORM postComment( _cmnttypeid, 'Q', NEW.quhead_id,
+                               ('Terms Changed from "' || oldterms.terms_code || '" to "' || newterms.terms_code || '"') )
+          FROM terms AS oldterms, terms AS newterms
+          WHERE ( (oldterms.terms_id=OLD.quhead_terms_id)
+           AND (newterms.terms_id=NEW.quhead_terms_id) );
+        END IF;
+
+      ELSIF (TG_OP = 'DELETE') THEN
+        DELETE FROM comment
+        WHERE ( (comment_source='Q')
+         AND (comment_source_id=OLD.quhead_id) );
+      END IF;
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  ELSE
+    RETURN NEW;
+  END IF;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER quheadtrigger ON quhead;
+CREATE TRIGGER quheadtrigger
+  BEFORE INSERT OR UPDATE OR DELETE
+  ON quhead
+  FOR EACH ROW
+  EXECUTE PROCEDURE _quheadtrigger();
diff --git a/foundation-database/public/trigger_functions/quitem.sql b/foundation-database/public/trigger_functions/quitem.sql
new file mode 100644 (file)
index 0000000..0f149bd
--- /dev/null
@@ -0,0 +1,145 @@
+CREATE OR REPLACE FUNCTION _quitemtrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _changelog BOOLEAN := FALSE;
+  _check BOOLEAN;
+
+BEGIN
+  --  Checks
+  SELECT checkPrivilege('MaintainQuotes') INTO _check;
+  IF NOT (_check) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Quotes.';
+  END IF;
+
+  IF ( SELECT fetchMetricBool('SalesOrderChangeLog') ) THEN
+    _changelog := TRUE;
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    IF (_changelog) THEN
+      PERFORM postComment('ChangeLog', 'QI', NEW.quitem_id, 'Created');
+    END IF;
+
+    RETURN NEW;
+  END IF;
+
+  IF (TG_OP = 'DELETE') THEN
+    DELETE FROM comment
+    WHERE ( (comment_source='QI')
+     AND (comment_source_id=OLD.quitem_id) );
+
+    DELETE FROM charass
+     WHERE ((charass_target_type='QI')
+       AND  (charass_target_id=OLD.quitem_id));
+    RETURN OLD;
+  END IF;
+
+  IF (TG_OP = 'UPDATE') THEN
+    IF (_changelog) THEN
+      IF (NEW.quitem_qtyord <> OLD.quitem_qtyord) THEN
+        PERFORM postComment( 'ChangeLog', 'QI', NEW.quitem_id,
+                             ( 'Changed Qty. Ordered from ' || formatQty(OLD.quitem_qtyord) ||
+                               ' to ' || formatQty(NEW.quitem_qtyord) ) );
+      END IF;
+
+      IF (NEW.quitem_price <> OLD.quitem_price) THEN
+        PERFORM postComment( 'ChangeLog', 'QI', NEW.quitem_id,
+                             ( 'Changed Unit Price from ' || formatPrice(OLD.quitem_price) ||
+                               ' to ' || formatPrice(NEW.quitem_price) ) );
+      END IF;
+
+      IF (NEW.quitem_scheddate <> OLD.quitem_scheddate) THEN
+        PERFORM postComment( 'ChangeLog', 'QI', NEW.quitem_id,
+                             ( 'Changed Sched. Date from ' || formatDate(OLD.quitem_scheddate) ||
+                               ' to ' || formatDate(NEW.quitem_scheddate)) );
+      END IF;
+    END IF;
+  END IF;
+
+--  NEW.quitem_lastupdated = CURRENT_TIMESTAMP;
+
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER quitemtrigger ON quitem;
+CREATE TRIGGER quitemtrigger
+  BEFORE INSERT OR UPDATE OR DELETE
+  ON quitem
+  FOR EACH ROW
+  EXECUTE PROCEDURE _quitemtrigger();
+
+CREATE OR REPLACE FUNCTION _quitemBeforeTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _check NUMERIC;
+  _itemNumber TEXT;
+BEGIN
+  -- Check
+  IF (NEW.quitem_scheddate IS NULL) THEN
+       RAISE EXCEPTION 'A schedule date is required.';
+  END IF;
+
+  -- If this is imported, go ahead and insert default characteristics
+   IF ((TG_OP = 'INSERT') AND NEW.quitem_imported) THEN
+     PERFORM updateCharAssignment('SI', NEW.quitem_id, char_id, charass_value) 
+     FROM (
+       SELECT DISTINCT char_id, char_name, charass_value
+       FROM charass, char, itemsite, item
+       WHERE ((itemsite_id=NEW.quitem_itemsite_id)
+       AND (itemsite_item_id=item_id)
+       AND (charass_target_type='I') 
+       AND (charass_target_id=item_id)
+       AND (charass_default)
+       AND (char_id=charass_char_id))
+       ORDER BY char_name) AS data;
+   END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER quitemBeforeTrigger ON quitem;
+CREATE TRIGGER quitemBeforeTrigger
+  BEFORE INSERT OR UPDATE
+  ON quitem
+  FOR EACH ROW
+  EXECUTE PROCEDURE _quitemBeforeTrigger();
+-- TODO: there are two BEFORE triggers. should these be merged?
+
+
+CREATE OR REPLACE FUNCTION _quitemAfterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _check NUMERIC;
+BEGIN
+
+  --If auto calculate freight, recalculate quhead_freight
+  IF (SELECT quhead_calcfreight FROM quhead WHERE (quhead_id=NEW.quitem_quhead_id)) THEN
+    UPDATE quhead SET quhead_freight =
+      (SELECT SUM(freightdata_total) FROM freightDetail('QU',
+                                                        quhead_id,
+                                                        quhead_cust_id,
+                                                        quhead_shipto_id,
+                                                        quhead_quotedate,
+                                                        quhead_shipvia,
+                                                        quhead_curr_id))
+    WHERE quhead_id=NEW.quitem_quhead_id;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER quitemAfterTrigger ON quitem;
+CREATE TRIGGER quitemAfterTrigger
+  AFTER INSERT OR UPDATE
+  ON quitem
+  FOR EACH ROW
+  EXECUTE PROCEDURE _quitemAfterTrigger();
+
diff --git a/foundation-database/public/trigger_functions/recur.sql b/foundation-database/public/trigger_functions/recur.sql
new file mode 100644 (file)
index 0000000..e6cde72
--- /dev/null
@@ -0,0 +1,22 @@
+CREATE OR REPLACE FUNCTION _recurAfterTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _parentid   INTEGER;
+  _parenttype TEXT;
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    IF (UPPER(OLD.recur_parent_type) = 'TODO') THEN
+      UPDATE todoitem SET todoitem_recurring_todoitem_id=NULL
+       WHERE (todoitem_recurring_todoitem_id=OLD.recur_parent_id);
+    END IF;
+
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'recurAfterTrigger');
+CREATE TRIGGER recurAfterTrigger AFTER DELETE ON recur FOR EACH ROW EXECUTE PROCEDURE _recurAfterTrigger();
diff --git a/foundation-database/public/trigger_functions/report.sql b/foundation-database/public/trigger_functions/report.sql
new file mode 100644 (file)
index 0000000..597996f
--- /dev/null
@@ -0,0 +1,13 @@
+CREATE OR REPLACE FUNCTION _reportTrigger () RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+  NEW.report_loaddate = CURRENT_TIMESTAMP;
+  RETURN NEW;
+
+END;
+' LANGUAGE 'plpgsql';
+
+DROP TRIGGER reportTrigger ON report;
+CREATE TRIGGER reportTrigger BEFORE INSERT OR UPDATE ON report FOR EACH ROW EXECUTE PROCEDURE _reportTrigger();
diff --git a/foundation-database/public/trigger_functions/salesrep.sql b/foundation-database/public/trigger_functions/salesrep.sql
new file mode 100644 (file)
index 0000000..e7aa64b
--- /dev/null
@@ -0,0 +1,149 @@
+CREATE OR REPLACE FUNCTION _salesrepBeforeTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+  IF NOT (checkPrivilege('MaintainSalesReps')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Sales Reps.';
+  END IF;
+
+  IF (TG_OP IN ('INSERT', 'UPDATE')) THEN
+    IF (NEW.salesrep_number IS NULL) THEN
+      RAISE EXCEPTION 'You must supply a valid Sales Rep Number.';
+    END IF;
+
+    IF (NEW.salesrep_commission IS NULL) THEN
+      RAISE EXCEPTION 'You must supply a Commission Rate for this Sales Rep.';
+    END IF;
+
+    IF (TG_OP = 'INSERT' AND fetchMetricText('CRMAccountNumberGeneration') IN ('A','O') AND isNumeric(NEW.salesrep_number)) THEN
+      --- clear the number from the issue cache
+      PERFORM clearNumberIssue('CRMAccountNumber', NEW.salesrep_number);
+    END IF;
+
+    NEW.salesrep_number = UPPER(NEW.salesrep_number);
+
+    -- deprecated column salesrep_emp_id
+    -- TODO: will this prevent breaking the crmacct-emp relationship?
+    IF (TG_OP = 'UPDATE') THEN
+      SELECT crmacct_emp_id INTO NEW.salesrep_emp_id
+        FROM crmacct
+       WHERE crmacct_salesrep_id = NEW.salesrep_id;
+    END IF;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    UPDATE crmacct SET crmacct_salesrep_id = NULL
+     WHERE crmacct_salesrep_id = OLD.salesrep_id;
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'salesrepBeforeTrigger');
+CREATE TRIGGER salesrepBeforeTrigger BEFORE INSERT OR UPDATE OR DELETE ON salesrep
+       FOR EACH ROW EXECUTE PROCEDURE _salesrepBeforeTrigger();
+
+CREATE OR REPLACE FUNCTION _salesrepAfterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+
+BEGIN
+
+  IF (TG_OP = 'INSERT') THEN
+    -- http://www.postgresql.org/docs/current/static/plpgsql-control-structures.html#PLPGSQL-UPSERT-EXAMPLE
+    LOOP
+      UPDATE crmacct SET crmacct_salesrep_id=NEW.salesrep_id,
+                         crmacct_name=NEW.salesrep_name
+      WHERE crmacct_number=NEW.salesrep_number;
+      IF (FOUND) THEN
+        EXIT;
+      END IF;
+      BEGIN
+        INSERT INTO crmacct(crmacct_number,      crmacct_name,      crmacct_active,
+                            crmacct_type,        crmacct_salesrep_id
+                  ) VALUES (NEW.salesrep_number, NEW.salesrep_name, NEW.salesrep_active,
+                            'I',                 NEW.salesrep_id);
+        EXIT;
+      EXCEPTION WHEN unique_violation THEN
+            -- do nothing, and loop to try the UPDATE again
+      END;
+    END LOOP;
+
+    -- TODO: default characteristic assignments?
+
+  ELSIF (TG_OP = 'UPDATE') THEN
+    UPDATE crmacct SET crmacct_number = NEW.salesrep_number
+    WHERE ((crmacct_salesrep_id=NEW.salesrep_id)
+      AND  (crmacct_number!=NEW.salesrep_number));
+
+    UPDATE crmacct SET crmacct_name = NEW.salesrep_name
+    WHERE ((crmacct_salesrep_id=NEW.salesrep_id)
+      AND  (crmacct_name!=NEW.salesrep_name));
+  END IF;
+
+  IF (fetchMetricBool('SalesRepChangeLog')) THEN
+      IF (TG_OP = 'INSERT') THEN
+        PERFORM postComment('ChangeLog', 'SR', NEW.salesrep_id, 'Created');
+
+      ELSIF (TG_OP = 'UPDATE') THEN
+        IF (OLD.salesrep_active <> NEW.salesrep_active) THEN
+          PERFORM postComment('ChangeLog', 'SR', NEW.salesrep_id,
+                              CASE WHEN NEW.salesrep_active THEN 'Activated'
+                                   ELSE 'Deactivated' END);
+        END IF;
+
+        IF (OLD.salesrep_number <> NEW.salesrep_number) THEN
+          PERFORM postComment('ChangeLog', 'SR', NEW.salesrep_id,
+                              'Number changed from "' || OLD.salesrep_number ||
+                              '" to "' || NEW.salesrep_number || '"');
+        END IF;
+
+        IF (OLD.salesrep_name <> NEW.salesrep_name) THEN
+          PERFORM postComment('ChangeLog', 'SR', NEW.salesrep_id,
+                              'Name changed from "' || OLD.salesrep_name ||
+                              '" to "' || NEW.salesrep_name || '"');
+        END IF;
+
+        IF (OLD.salesrep_commission <> NEW.salesrep_commission) THEN
+          PERFORM postComment('ChangeLog', 'SR', NEW.salesrep_id,
+                              'Commission changed from "' || OLD.salesrep_commission ||
+                              '" to "' || NEW.salesrep_commission || '"');
+        END IF;
+
+        IF (OLD.salesrep_method <> NEW.salesrep_method) THEN
+          PERFORM postComment('ChangeLog', 'SR', NEW.salesrep_id,
+                              'Method changed from "' || OLD.salesrep_method ||
+                              '" to "' || NEW.salesrep_method || '"');
+        END IF;
+
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'salesrepAfterTrigger');
+CREATE TRIGGER salesrepAfterTrigger AFTER INSERT OR UPDATE ON salesrep
+       FOR EACH ROW EXECUTE PROCEDURE _salesrepAfterTrigger();
+
+CREATE OR REPLACE FUNCTION _salesrepAfterDeleteTrigger() RETURNS TRIGGER AS $$
+BEGIN
+  IF (SELECT fetchMetricValue('DefaultSalesRep') = OLD.salesrep_id) THEN
+    RAISE EXCEPTION 'Cannot delete the default Sales Rep [xtuple: salesrep, -1, %]',
+                    OLD.salesrep_number;
+  END IF;
+
+  PERFORM postComment('ChangeLog', 'SR', OLD.salesrep_id,
+                      'Deleted "' || OLD.salesrep_number || '"');
+
+  RETURN OLD;
+END;
+$$ LANGUAGE PLPGSQL;
+
+DROP TRIGGER IF EXISTS salesrepAfterDeleteTrigger ON salesrep;
+CREATE TRIGGER salesrepAfterDeleteTrigger AFTER DELETE ON salesrep
+       FOR EACH ROW EXECUTE PROCEDURE _salesrepAfterDeleteTrigger();
diff --git a/foundation-database/public/trigger_functions/saletype.sql b/foundation-database/public/trigger_functions/saletype.sql
new file mode 100644 (file)
index 0000000..2870a04
--- /dev/null
@@ -0,0 +1,60 @@
+CREATE OR REPLACE FUNCTION _saletypeBeforeDeleteTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _check TEXT;
+
+BEGIN
+--  Check to see if any sales orders are assigned to the passed saletype
+  SELECT cohead_number INTO _check
+  FROM cohead
+  WHERE (cohead_saletype_id=OLD.saletype_id)
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Assigned to Sales Order % and possibly more. [xtuple: deletesaletype, -1]', _check;
+  END IF;
+
+--  Check to see if any quotes are assigned to the passed saletype
+  SELECT quhead_number INTO _check
+  FROM quhead
+  WHERE (quhead_saletype_id=OLD.saletype_id)
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Assigned to Quote % and possibly more. [xtuple: deletesaletype, -2]', _check;
+  END IF;
+
+--  Check to see if any invoice are assigned to the passed saletype
+  SELECT invchead_invcnumber INTO _check
+  FROM invchead
+  WHERE (invchead_saletype_id=OLD.saletype_id)
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Assigned to Invoice % and possibly more. [xtuple: deletesaletype, -3]', _check;
+  END IF;
+
+--  Check to see if any credit memos are assigned to the passed saletype
+  SELECT cmhead_number INTO _check
+  FROM cmhead
+  WHERE (cmhead_saletype_id=OLD.saletype_id)
+  LIMIT 1;
+  IF (FOUND) THEN
+    RAISE EXCEPTION 'Assigned to Credit Memo % and possibly more. [xtuple: deletesaletype, -4]', _check;
+  END IF;
+
+--  Check to see if any return ruthorizations are assigned to the passed saletype
+  IF (fetchMetricBool('EnableReturnAuth')) THEN
+    SELECT rahead_number INTO _check
+    FROM rahead
+    WHERE (rahead_saletype_id=OLD.saletype_id)
+    LIMIT 1;
+    IF (FOUND) THEN
+      RAISE EXCEPTION 'Assigned to Return Authorization % and possibly more returns. [xtuple: deleteSaleType, -5]', _check;
+    END IF;
+  END IF;
+
+  RETURN OLD;
+END;
+$$      LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'saletypeBeforeDeleteTrigger');
+CREATE TRIGGER saletypeBeforeDeleteTrigger BEFORE DELETE ON saletype FOR EACH ROW EXECUTE PROCEDURE _saletypeBeforeDeleteTrigger();
diff --git a/foundation-database/public/trigger_functions/shipdata.sql b/foundation-database/public/trigger_functions/shipdata.sql
new file mode 100644 (file)
index 0000000..5795420
--- /dev/null
@@ -0,0 +1,116 @@
+CREATE OR REPLACE FUNCTION _shipdatatrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _newShipdata_cohead_number   INTEGER;
+  _shipdatasum_shipper                 TEXT;
+  _rows                                INTEGER;
+  _cohead_id                   INTEGER;
+  _shiphead_number             TEXT;
+  _headcount                   INTEGER;
+
+BEGIN
+  --  This is where the shipper is identified and may need to be changed
+  NEW.shipdata_cohead_number := TRIM(NEW.shipdata_cohead_number);
+
+  IF (substring(NEW.shipdata_cosmisc_tracknum from 1 for 2) = '1Z') THEN
+    _shipdatasum_shipper := 'UPS';
+  ELSE
+    _shipdatasum_shipper := 'UNKNOWN';
+  END IF;
+
+  IF (LENGTH(TRIM(NEW.shipdata_shiphead_number)) = 0) THEN
+    NEW.shipdata_shiphead_number := NULL;
+  END IF;
+
+  IF (NEW.shipdata_cosmisc_tracknum = NEW.shipdata_cosmisc_packnum_tracknum) THEN
+    IF (NEW.shipdata_void_ind = 'Y') THEN
+      --  Delete the current shipdatasum
+      DELETE FROM shipdatasum
+      WHERE ((shipdatasum_cohead_number = NEW.shipdata_cohead_number)
+       AND  (shipdatasum_cosmisc_tracknum = NEW.shipdata_cosmisc_tracknum));
+
+    ELSIF (TG_OP = 'INSERT') THEN
+
+--      RAISE NOTICE 'Getting cohead_id (%)', NEW.shipdata_cohead_number;
+      IF (NEW.shipdata_shiphead_number IS NULL) THEN
+        SELECT cohead_id INTO _cohead_id FROM cohead WHERE cohead_number = NEW.shipdata_cohead_number;
+
+        IF (FOUND) THEN
+
+--          RAISE NOTICE 'Getting shiphead number (%)', _cohead_id;
+          SELECT count(shiphead_order_id), MAX(shiphead_number) INTO _headcount, _shiphead_number 
+          FROM shiphead 
+          WHERE ((shiphead_tracknum IS NULL OR shiphead_tracknum = '') 
+          AND ( shiphead_order_type = 'SO' and shiphead_order_id = _cohead_id) );
+          
+          IF (_headcount = 1) THEN
+--            RAISE NOTICE 'Updating Shiphead Number (%)', _shiphead_number;
+            NEW.shipdata_shiphead_number = _shiphead_number;
+            
+          ELSIF (_headcount > 1) THEN
+            -- Trap for potential workflow problem.  Can only infer shiphead from sales order number 
+            -- if shipping one at a time
+            RAISE EXCEPTION 'Multiple shipments exist for this order.  Please provide a specific a shipment number.';
+          END IF;
+        END IF;
+      END IF;
+
+      INSERT INTO shipdatasum
+             (shipdatasum_cohead_number, shipdatasum_cosmisc_tracknum,
+              shipdatasum_cosmisc_packnum_tracknum, shipdatasum_weight,
+              shipdatasum_base_freight, shipdatasum_total_freight,
+              shipdatasum_base_freight_curr_id, shipdatasum_total_freight_curr_id,
+              shipdatasum_shipper, shipdatasum_billing_option,
+              shipdatasum_package_type, shipdatasum_shiphead_number)
+       VALUES (NEW.shipdata_cohead_number, NEW.shipdata_cosmisc_tracknum,
+              NEW.shipdata_cosmisc_packnum_tracknum, NEW.shipdata_weight,
+              NEW.shipdata_base_freight, NEW.shipdata_total_freight,
+              NEW.shipdata_base_freight_curr_id, NEW.shipdata_total_freight_curr_id,
+              _shipdatasum_shipper, NEW.shipdata_billing_option,
+              NEW.shipdata_package_type, NEW.shipdata_shiphead_number);
+
+    ELSIF (TG_OP = 'UPDATE') THEN
+       UPDATE shipdatasum SET
+             shipdatasum_cohead_number=NEW.shipdata_cohead_number,
+             shipdatasum_cosmisc_tracknum=NEW.shipdata_cosmisc_tracknum,
+             shipdatasum_cosmisc_packnum_tracknum=NEW.shipdata_cosmisc_packnum_tracknum,
+             shipdatasum_weight=NEW.shipdata_weight,
+             shipdatasum_base_freight=NEW.shipdata_base_freight,
+             shipdatasum_total_freight=NEW.shipdata_total_freight,
+             shipdatasum_base_freight_curr_id=NEW.shipdata_base_freight_curr_id,
+             shipdatasum_total_freight_curr_id=NEW.shipdata_total_freight_curr_id,
+             shipdatasum_shipper=_shipdatasum_shipper,
+             shipdatasum_billing_option=NEW.shipdata_billing_option,
+             shipdatasum_package_type=NEW.shipdata_package_type,
+             shipdatasum_shiphead_number=NEW.shipdata_shiphead_number
+       WHERE ((TRIM(shipdatasum_cohead_number)=TRIM(OLD.shipdata_cohead_number))
+         AND (TRIM(shipdatasum_cosmisc_tracknum)=TRIM(OLD.shipdata_cosmisc_tracknum))
+         AND (TRIM(shipdatasum_cosmisc_packnum_tracknum)=TRIM(OLD.shipdata_cosmisc_packnum_tracknum)));
+
+       GET DIAGNOSTICS _rows = ROW_COUNT;
+       IF (_rows <= 0) THEN
+        INSERT INTO shipdatasum
+               (shipdatasum_cohead_number, shipdatasum_cosmisc_tracknum,
+                shipdatasum_cosmisc_packnum_tracknum, shipdatasum_weight,
+                shipdatasum_base_freight, shipdatasum_total_freight,
+                shipdatasum_base_freight_curr_id, shipdatasum_total_freight_curr_id,
+                shipdatasum_shipper, shipdatasum_billing_option,
+                shipdatasum_package_type, shipdatasum_shiphead_number)
+        VALUES (NEW.shipdata_cohead_number, NEW.shipdata_cosmisc_tracknum,
+                NEW.shipdata_cosmisc_packnum_tracknum, NEW.shipdata_weight,
+                NEW.shipdata_base_freight, NEW.shipdata_total_freight,
+                NEW.shipdata_base_freight_curr_id, NEW.shipdata_total_freight_curr_id,
+                _shipdatasum_shipper, NEW.shipdata_billing_option,
+                NEW.shipdata_package_type, NEW.shipdata_shiphead_number);
+       END IF;
+    END IF;
+  END IF;
+
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql' VOLATILE;
+
+SELECT dropIfExists('TRIGGER', 'shipdatatrigger');
+CREATE TRIGGER shipdatatrigger BEFORE INSERT OR UPDATE ON shipdata FOR EACH ROW EXECUTE PROCEDURE _shipdatatrigger();
diff --git a/foundation-database/public/trigger_functions/shipdatasum.sql b/foundation-database/public/trigger_functions/shipdatasum.sql
new file mode 100644 (file)
index 0000000..f90c94d
--- /dev/null
@@ -0,0 +1,16 @@
+CREATE OR REPLACE FUNCTION _shipdatasumtrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+  IF (LENGTH(TRIM(NEW.shipdatasum_shiphead_number)) = 0) THEN
+    NEW.shipdatasum_shiphead_number = NULL;
+  END IF;
+
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'shipdatasumtrigger');
+CREATE TRIGGER shipdatasumtrigger BEFORE INSERT OR UPDATE ON shipdatasum FOR EACH ROW EXECUTE PROCEDURE _shipdatasumtrigger();
diff --git a/foundation-database/public/trigger_functions/shipform.sql b/foundation-database/public/trigger_functions/shipform.sql
new file mode 100644 (file)
index 0000000..1eaf03e
--- /dev/null
@@ -0,0 +1,16 @@
+CREATE OR REPLACE FUNCTION _shipformAfterDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (fetchMetricValue('DefaultShipFormId') = OLD.shipform_id) THEN
+    RAISE EXCEPTION 'Cannot delete the default Shipping Form [xtuple: shipform, -1, %, %]',
+                    OLD.shipform_name, OLD.shipform_report_name;
+  END IF;
+
+  RETURN OLD;
+END;
+$$ LANGUAGE PLPGSQL;
+
+DROP TRIGGER IF EXISTS shipformAfterDeleteTrigger ON shipform;
+CREATE TRIGGER shipformAfterDeleteTrigger AFTER DELETE ON shipform
+  FOR EACH ROW EXECUTE PROCEDURE _shipformAfterDeleteTrigger();
diff --git a/foundation-database/public/trigger_functions/shiphead.sql b/foundation-database/public/trigger_functions/shiphead.sql
new file mode 100644 (file)
index 0000000..0f063d7
--- /dev/null
@@ -0,0 +1,28 @@
+CREATE OR REPLACE FUNCTION _shipheadBeforeTrigger () RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF ((TG_OP = ''INSERT'') OR (TG_OP = ''UPDATE'')) THEN
+
+    IF (NEW.shiphead_order_type = ''SO''
+       AND NEW.shiphead_order_id   IN (SELECT cohead_id FROM cohead)) THEN
+      RETURN NEW;
+
+    ELSEIF (NEW.shiphead_order_type = ''TO''
+       AND NEW.shiphead_order_id   IN (SELECT tohead_id FROM tohead)) THEN
+      RETURN NEW;
+
+    END IF;
+
+    RAISE EXCEPTION ''% with id % does not exist'',
+                   NEW.shiphead_order_type, NEW.shiphead_order_id;
+    RETURN OLD;
+
+  END IF;
+
+  RETURN NEW;
+END;
+' LANGUAGE 'plpgsql';
+
+SELECT dropifexists('trigger', 'shipheadbeforetrigger');
+CREATE TRIGGER shipheadBeforeTrigger BEFORE INSERT OR UPDATE ON shiphead FOR EACH ROW EXECUTE PROCEDURE _shipheadBeforeTrigger();
diff --git a/foundation-database/public/trigger_functions/shiptoinfo.sql b/foundation-database/public/trigger_functions/shiptoinfo.sql
new file mode 100644 (file)
index 0000000..82142c3
--- /dev/null
@@ -0,0 +1,79 @@
+CREATE OR REPLACE FUNCTION _shiptoinfoAfterTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid INTEGER;
+
+BEGIN
+  IF (NEW.shipto_default) THEN
+    UPDATE shiptoinfo
+    SET shipto_default = false
+    WHERE ((shipto_cust_id=NEW.shipto_cust_id)
+    AND (shipto_id <> NEW.shipto_id));
+  END IF;
+
+  IF (SELECT fetchMetricBool('CustomerChangeLog')) THEN
+--  Cache the cmnttype_id for ChangeLog
+    SELECT cmnttype_id INTO _cmnttypeid
+    FROM cmnttype
+    WHERE (cmnttype_name='ChangeLog');
+    IF (FOUND) THEN
+      IF (TG_OP = 'INSERT') THEN
+        PERFORM postComment(_cmnttypeid, 'C', NEW.shipto_cust_id, 'Created');
+
+      ELSIF (TG_OP = 'UPDATE') THEN
+        IF (OLD.shipto_name <> NEW.shipto_name) THEN
+          PERFORM postComment( _cmnttypeid, 'C', NEW.shipto_cust_id,
+                               ( NEW.shipto_name || ': Ship To Name Changed from "' || COALESCE(OLD.shipto_name, '') ||
+                                 '" to "' || COALESCE(NEW.shipto_name, '') || '"' ) );
+        END IF;
+        IF (OLD.shipto_shipvia <> NEW.shipto_shipvia) THEN
+          PERFORM postComment( _cmnttypeid, 'C', NEW.shipto_cust_id,
+                               ( NEW.shipto_name || ': Ship To ShipVia Changed from "' || COALESCE(OLD.shipto_shipvia, '') ||
+                                 '" to "' || COALESCE(NEW.shipto_shipvia, '') || '"' ) );
+        END IF;
+        IF (COALESCE(OLD.shipto_taxzone_id, -1) <> COALESCE(NEW.shipto_taxzone_id, -1)) THEN
+          PERFORM postComment( _cmnttypeid, 'C', NEW.shipto_cust_id,
+                               ( NEW.shipto_name || ': Ship To Tax Zone Changed from "' || COALESCE((SELECT taxzone_code
+                                                                                            FROM taxzone
+                                                                                            WHERE taxzone_id=OLD.shipto_taxzone_id), 'None') ||
+                                 '" to "' || COALESCE((SELECT taxzone_code
+                                              FROM taxzone
+                                              WHERE taxzone_id=NEW.shipto_taxzone_id), 'None') || '"' ) );
+        END IF;
+        IF (OLD.shipto_shipzone_id <> NEW.shipto_shipzone_id) THEN
+          PERFORM postComment( _cmnttypeid, 'C', NEW.shipto_cust_id,
+                               ( NEW.shipto_name || ': Ship To Shipping Zone Changed from "' || (SELECT shipzone_name
+                                                                                                 FROM shipzone
+                                                                                                 WHERE shipzone_id=OLD.shipto_shipzone_id) ||
+                                 '" to "' || (SELECT shipzone_name
+                                              FROM shipzone
+                                              WHERE shipzone_id=NEW.shipto_shipzone_id) || '"' ) );
+        END IF;
+        IF (OLD.shipto_salesrep_id <> NEW.shipto_salesrep_id) THEN
+          PERFORM postComment( _cmnttypeid, 'C', NEW.shipto_cust_id,
+                               ( NEW.shipto_name || ': Ship To Sales Rep Changed from "' || (SELECT salesrep_name
+                                                                                             FROM salesrep
+                                                                                             WHERE salesrep_id=OLD.shipto_salesrep_id) ||
+                                 '" to "' || (SELECT salesrep_name
+                                              FROM salesrep
+                                              WHERE salesrep_id=NEW.shipto_salesrep_id) || '"' ) );
+        END IF;
+        IF (OLD.shipto_active <> NEW.shipto_active) THEN
+          IF (NEW.shipto_active) THEN
+            PERFORM postComment(_cmnttypeid, 'C', NEW.shipto_cust_id, (NEW.shipto_name || ': Ship To Activated'));
+          ELSE
+            PERFORM postComment(_cmnttypeid, 'C', NEW.shipto_cust_id, (NEW.shipto_name || ': Ship To Deactivated'));
+          END IF;
+        END IF;
+      END IF;
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER shiptoinfoAfterTrigger ON shiptoinfo;
+CREATE TRIGGER shiptoinfoAfterTrigger AFTER INSERT OR UPDATE ON shiptoinfo FOR EACH ROW EXECUTE PROCEDURE _shiptoinfoAfterTrigger();
+
diff --git a/foundation-database/public/trigger_functions/shipvia.sql b/foundation-database/public/trigger_functions/shipvia.sql
new file mode 100644 (file)
index 0000000..27f86d8
--- /dev/null
@@ -0,0 +1,16 @@
+CREATE OR REPLACE FUNCTION _shipviaAfterDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (SELECT fetchMetricValue('DefaultShipViaId') = OLD.shipvia_id) THEN
+    RAISE EXCEPTION 'Cannot delete the default Ship-Via [xtuple: shipvia, -1, %]',
+                    OLD.shipvia_code;
+  END IF;
+
+  RETURN OLD;
+END;
+$$ LANGUAGE PLPGSQL;
+
+DROP TRIGGER IF EXISTS shipviaAfterDeleteTrigger ON shipvia;
+CREATE TRIGGER shipviaAfterDeleteTrigger AFTER DELETE ON shipvia
+  FOR EACH ROW EXECUTE PROCEDURE _shipviaAfterDeleteTrigger();
diff --git a/foundation-database/public/trigger_functions/sltrans.sql b/foundation-database/public/trigger_functions/sltrans.sql
new file mode 100644 (file)
index 0000000..8d88963
--- /dev/null
@@ -0,0 +1,76 @@
+CREATE OR REPLACE FUNCTION _sltransInsertTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _reqNotes BOOLEAN;
+  _externalCompany      BOOLEAN := false;
+BEGIN
+  -- Checks
+  SELECT company_external INTO _externalCompany
+  FROM company JOIN accnt ON (company_number=accnt_company)
+  WHERE (accnt_id=NEW.sltrans_accnt_id);
+  IF (_externalCompany) THEN
+    RAISE EXCEPTION 'Transactions are not allowed for G/L Accounts with External Company segments.';
+  END IF;
+  
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'sltransInsertTrigger');
+CREATE TRIGGER sltransInsertTrigger BEFORE INSERT ON sltrans FOR EACH ROW EXECUTE PROCEDURE _sltransInsertTrigger();
+
+CREATE OR REPLACE FUNCTION _sltransAlterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _externalCompany      BOOLEAN := false;
+  _updated BOOLEAN := false;
+BEGIN
+  IF(TG_OP='DELETE') THEN
+    RAISE EXCEPTION 'You may not delete Journal Transactions once they have been created.';
+  ELSIF (TG_OP = 'UPDATE') THEN        
+    IF(OLD.sltrans_id != NEW.sltrans_id) THEN
+      _updated := true;
+    ELSIF(OLD.sltrans_date != NEW.sltrans_date) THEN
+      _updated := true;
+    ELSIF(OLD.sltrans_accnt_id != NEW.sltrans_accnt_id) THEN
+      _updated := true;
+    ELSIF(OLD.sltrans_amount != NEW.sltrans_amount) THEN
+      _updated := true;
+    ELSIF(OLD.sltrans_username != NEW.sltrans_username) THEN
+      _updated := true;
+    ELSIF( (OLD.sltrans_sequence IS NULL     AND NEW.sltrans_sequence IS NOT NULL)
+        OR (OLD.sltrans_sequence IS NOT NULL AND NEW.sltrans_sequence IS NULL)
+        OR (COALESCE(OLD.sltrans_sequence,0) != COALESCE(NEW.sltrans_sequence,0)) ) THEN
+      _updated := true;
+    ELSIF( (OLD.sltrans_created IS NULL     AND NEW.sltrans_created IS NOT NULL)
+        OR (OLD.sltrans_created IS NOT NULL AND NEW.sltrans_created IS NULL)
+        OR (COALESCE(OLD.sltrans_created,now()) != COALESCE(NEW.sltrans_created,now())) ) THEN
+      _updated := true;
+    ELSIF( (OLD.sltrans_source IS NULL     AND NEW.sltrans_source IS NOT NULL)
+        OR (OLD.sltrans_source IS NOT NULL AND NEW.sltrans_source IS NULL)
+        OR (COALESCE(OLD.sltrans_source,'') != COALESCE(NEW.sltrans_source,'')) ) THEN
+      _updated := true;
+    ELSIF( (OLD.sltrans_docnumber IS NULL     AND NEW.sltrans_docnumber IS NOT NULL)
+        OR (OLD.sltrans_docnumber IS NOT NULL AND NEW.sltrans_docnumber IS NULL)
+        OR (COALESCE(OLD.sltrans_docnumber,'') != COALESCE(NEW.sltrans_docnumber,'')) ) THEN
+      _updated := true;
+    ELSIF( (OLD.sltrans_doctype IS NULL     AND NEW.sltrans_doctype IS NOT NULL)
+        OR (OLD.sltrans_doctype IS NOT NULL AND NEW.sltrans_doctype IS NULL)
+        OR (COALESCE(OLD.sltrans_doctype,'') != COALESCE(NEW.sltrans_doctype,'')) ) THEN
+      _updated := true;
+    END IF;
+
+    IF(_updated) THEN
+      RAISE EXCEPTION 'You may not alter some Journal Transaction fields once they have been created.';
+    END IF;
+  ELSE
+    RAISE EXCEPTION 'trigger for sltrans table called in unexpected state.';
+  END IF;
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'sltransAlterTrigger');
+CREATE TRIGGER sltransAlterTrigger BEFORE UPDATE OR DELETE ON sltrans FOR EACH ROW EXECUTE PROCEDURE _sltransAlterTrigger();
diff --git a/foundation-database/public/trigger_functions/taxauth.sql b/foundation-database/public/trigger_functions/taxauth.sql
new file mode 100644 (file)
index 0000000..a5ca93e
--- /dev/null
@@ -0,0 +1,183 @@
+CREATE OR REPLACE FUNCTION _taxauthBeforeTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (NOT checkPrivilege('MaintainTaxAuthorities')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Tax Authorities.';
+  END IF;
+
+  IF (NEW.taxauth_code IS NULL) THEN
+    RAISE EXCEPTION 'You must supply a Tax Authority Code.';
+  END IF;
+
+  IF (TG_OP = 'INSERT' AND
+      fetchMetricText('CRMAccountNumberGeneration') IN ('A','O')) THEN
+    PERFORM clearNumberIssue('CRMAccountNumber', NEW.taxauth_code);
+  END IF;
+
+  NEW.taxauth_code := UPPER(NEW.taxauth_code);
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('trigger', 'taxauthBeforeTrigger');
+CREATE TRIGGER taxauthBeforeTrigger BEFORE INSERT OR UPDATE ON taxauth
+       FOR EACH ROW EXECUTE PROCEDURE _taxauthBeforeTrigger();
+
+CREATE OR REPLACE FUNCTION _taxauthAfterTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid INTEGER;
+
+BEGIN
+  IF (TG_OP = 'INSERT') THEN
+    -- http://www.postgresql.org/docs/current/static/plpgsql-control-structures.html#PLPGSQL-UPSERT-EXAMPLE
+    LOOP
+      UPDATE crmacct SET crmacct_taxauth_id=NEW.taxauth_id,
+                         crmacct_name=NEW.taxauth_name
+       WHERE crmacct_number=NEW.taxauth_code;
+      IF (FOUND) THEN
+        EXIT;
+      END IF;
+      BEGIN
+        INSERT INTO crmacct(crmacct_number,   crmacct_name,     crmacct_active,
+                            crmacct_type,     crmacct_taxauth_id
+                  ) VALUES (NEW.taxauth_code, NEW.taxauth_name, TRUE, 
+                            'O',              NEW.taxauth_id);
+        EXIT;
+      EXCEPTION WHEN unique_violation THEN
+            -- do nothing, and loop to try the UPDATE again
+      END;
+    END LOOP;
+
+    /* TODO: default characteristic assignments based on what? */
+
+  ELSIF (TG_OP = 'UPDATE') THEN
+    UPDATE crmacct SET crmacct_number = NEW.taxauth_code
+    WHERE ((crmacct_taxauth_id=NEW.taxauth_id)
+      AND  (crmacct_number!=NEW.taxauth_code));
+
+    UPDATE crmacct SET crmacct_name = NEW.taxauth_name
+    WHERE ((crmacct_taxauth_id=NEW.taxauth_id)
+      AND  (crmacct_name!=NEW.taxauth_name));
+
+  END IF;
+
+  IF (fetchMetricBool('TaxAuthChangeLog')) THEN
+    SELECT cmnttype_id INTO _cmnttypeid
+      FROM cmnttype
+     WHERE (cmnttype_name='ChangeLog');
+
+    IF (_cmnttypeid IS NOT NULL) THEN
+      IF (TG_OP = 'INSERT') THEN
+        PERFORM postComment(_cmnttypeid, 'TAXAUTH', NEW.taxauth_id, 'Created');
+
+      ELSIF (TG_OP = 'UPDATE') THEN
+        IF (OLD.taxauth_code <> NEW.taxauth_code) THEN
+          PERFORM postComment(_cmnttypeid, 'TAXAUTH', NEW.taxauth_id,
+                              'Code changed from "' || OLD.taxauth_code ||
+                              '" to "' || NEW.taxauth_code || '"');
+        END IF;
+
+        IF (OLD.taxauth_name <> NEW.taxauth_name) THEN
+          PERFORM postComment(_cmnttypeid, 'TAXAUTH', NEW.taxauth_id,
+                              'Name changed from "' || OLD.taxauth_name ||
+                              '" to "' || NEW.taxauth_name || '"');
+        END IF;
+
+        IF (OLD.taxauth_extref <> NEW.taxauth_extref) THEN
+          PERFORM postComment(_cmnttypeid, 'TAXAUTH', NEW.taxauth_id,
+                              'External Ref. changed from "' || OLD.taxauth_extref ||
+                              '" to "' || NEW.taxauth_extref || '"');
+        END IF;
+
+        IF (OLD.taxauth_addr_id <> NEW.taxauth_addr_id) THEN
+          PERFORM postComment(_cmnttypeid, 'TAXAUTH', NEW.taxauth_id,
+                              'Address changed from ' || formatAddr(OLD.taxauth_addr_id)
+                              || ' to ' || formatAddr(NEW.taxauth_addr_id));
+        END IF;
+
+        IF (OLD.taxauth_curr_id <> NEW.taxauth_curr_id) THEN
+          PERFORM postComment(_cmnttypeid, 'TAXAUTH', NEW.taxauth_id,
+                              'Currency changed from "' ||
+                              currConcat(OLD.taxauth_curr_id) || '" to "' ||
+                              currConcat(NEW.taxauth_curr_id) || '"');
+        END IF;
+
+        IF (OLD.taxauth_county <> NEW.taxauth_county) THEN
+          PERFORM postComment(_cmnttypeid, 'TAXAUTH', NEW.taxauth_id,
+                              'County changed from "' || OLD.taxauth_county ||
+                              '" to "' || NEW.taxauth_county || '"');
+        END IF;
+
+        IF (OLD.taxauth_accnt_id <> NEW.taxauth_accnt_id) THEN
+          PERFORM postComment(_cmnttypeid, 'TAXAUTH', NEW.taxauth_id,
+                              'Account changed from "' ||
+                              formatGLAccount(OLD.taxauth_accnt_id) || '" to "' ||
+                              formatGLAccount(NEW.taxauth_accnt_id) || '"');
+        END IF;
+
+      END IF;
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('trigger', 'taxauthAfterTrigger');
+CREATE TRIGGER taxauthAfterTrigger AFTER INSERT OR UPDATE ON taxauth
+       FOR EACH ROW EXECUTE PROCEDURE _taxauthAfterTrigger();
+
+CREATE OR REPLACE FUNCTION _taxauthBeforeDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (NOT checkPrivilege('MaintainTaxAuthorities')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Tax Authorities.';
+  END IF;
+
+  UPDATE crmacct SET crmacct_taxauth_id = NULL
+   WHERE crmacct_taxauth_id = OLD.taxauth_id;
+
+  RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('trigger', 'taxauthBeforeDeleteTrigger');
+CREATE TRIGGER taxauthBeforeDeleteTrigger BEFORE DELETE ON taxauth
+       FOR EACH ROW EXECUTE PROCEDURE _taxauthBeforeDeleteTrigger();
+
+CREATE OR REPLACE FUNCTION _taxauthAfterDeleteTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (EXISTS(SELECT 1
+               FROM checkhead
+              WHERE checkhead_recip_id = OLD.taxauth_id
+                AND checkhead_recip_type='T')) THEN
+    RAISE EXCEPTION 'Cannot delete the tax authority % because checks have been written to it [xtuple: deleteTaxAuthority, -7, %]',
+                    OLD.taxauth_number, OLD.taxauth_number;
+  END IF;
+
+  IF (fetchMetricValue('DefaultTaxAuthority') = OLD.taxauth_id) THEN
+    RAISE EXCEPTION 'Cannot delete the default Tax Authority [xtuple: deleteTaxAuthority, -8, %]',
+                    OLD.taxauth_code;
+  END IF;
+
+  IF (fetchMetricBool('TaxAuthChangeLog')) THEN
+    PERFORM postComment(cmnttype_id, 'TAXAUTH', OLD.taxauth_id,
+                        'Deleted "' || OLD.taxauth_number || '"')
+      FROM cmnttype
+     WHERE (cmnttype_name='ChangeLog');
+  END IF;
+
+  RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('trigger', 'taxauthAfterDeleteTrigger');
+CREATE TRIGGER taxauthAfterDeleteTrigger AFTER DELETE ON taxauth
+       FOR EACH ROW EXECUTE PROCEDURE _taxauthAfterDeleteTrigger();
diff --git a/foundation-database/public/trigger_functions/terms.sql b/foundation-database/public/trigger_functions/terms.sql
new file mode 100644 (file)
index 0000000..c8a8334
--- /dev/null
@@ -0,0 +1,16 @@
+CREATE OR REPLACE FUNCTION _termsAfterDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (fetchMetricValue('DefaultTerms') = OLD.terms_id) THEN
+    RAISE EXCEPTION 'Cannot delete the default Terms [xtuple: terms, -1, %]',
+                    OLD.terms_code;
+  END IF;
+
+  RETURN OLD;
+END;
+$$ LANGUAGE PLPGSQL;
+
+DROP TRIGGER IF EXISTS termsAfterDeleteTrigger ON terms;
+CREATE TRIGGER termsAfterDeleteTrigger AFTER DELETE ON terms
+  FOR EACH ROW EXECUTE PROCEDURE _termsAfterDeleteTrigger();
diff --git a/foundation-database/public/trigger_functions/todoitem.sql b/foundation-database/public/trigger_functions/todoitem.sql
new file mode 100644 (file)
index 0000000..0943567
--- /dev/null
@@ -0,0 +1,57 @@
+CREATE OR REPLACE FUNCTION _todoitemTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _recurid     INTEGER;
+  _newparentid INTEGER;
+
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    SELECT recur_id INTO _recurid
+      FROM recur
+     WHERE ((recur_parent_id=OLD.todoitem_id)
+       AND  (recur_parent_type='TODO'));
+
+    IF (_recurid IS NOT NULL) THEN
+      RAISE DEBUG 'recur_id for deleted todoitem = %', _recurid;
+
+      SELECT todoitem_id INTO _newparentid
+        FROM todoitem
+       WHERE ((todoitem_recurring_todoitem_id=OLD.todoitem_id)
+          AND (todoitem_id!=OLD.todoitem_id))
+       ORDER BY todoitem_due_date
+       LIMIT 1;
+
+      RAISE DEBUG '_newparentid for deleted todoitem = %', COALESCE(_newparentid, NULL);
+
+      -- client is responsible for warning about deleting a recurring todoitem
+      IF (_newparentid IS NULL) THEN
+        DELETE FROM recur WHERE recur_id=_recurid;
+      ELSE
+        UPDATE recur SET recur_parent_id=_newparentid
+         WHERE recur_id=_recurid;
+
+        UPDATE todoitem SET todoitem_recurring_todoitem_id=_newparentid
+         WHERE todoitem_recurring_todoitem_id=OLD.todoitem_id
+           AND todoitem_id != OLD.todoitem_id;
+
+        RAISE DEBUG 'reparented recurrence';
+      END IF;
+    END IF;
+
+    DELETE FROM alarm
+     WHERE ((alarm_source='TODO')
+        AND (alarm_source_id=OLD.todoitem_id));
+
+    DELETE FROM docass WHERE docass_source_id = OLD.todoitem_id AND docass_source_type = 'TODO';
+    DELETE FROM docass WHERE docass_target_id = OLD.todoitem_id AND docass_target_type = 'TODO';
+
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'todoitemTrigger');
+CREATE TRIGGER todoitemTrigger BEFORE DELETE ON todoitem FOR EACH ROW EXECUTE PROCEDURE _todoitemTrigger();
diff --git a/foundation-database/public/trigger_functions/uomconv.sql b/foundation-database/public/trigger_functions/uomconv.sql
new file mode 100644 (file)
index 0000000..9d1fcd7
--- /dev/null
@@ -0,0 +1,19 @@
+CREATE OR REPLACE FUNCTION _uomconvupdate() RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  UPDATE itemuomconv
+  SET itemuomconv_to_value = NEW.uomconv_to_value,
+  itemuomconv_from_value = NEW.uomconv_from_value,
+  itemuomconv_fractional = NEW.uomconv_fractional
+  WHERE((itemuomconv_from_uom_id = NEW.uomconv_from_uom_id)
+  AND (itemuomconv_to_uom_id = NEW.uomconv_to_uom_id));
+
+RETURN NEW;
+
+END; 
+' LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'uomconvupdate');
+CREATE TRIGGER uomconvupdate BEFORE UPDATE ON uomconv FOR EACH ROW EXECUTE PROCEDURE _uomconvupdate();
diff --git a/foundation-database/public/trigger_functions/usrpref.sql b/foundation-database/public/trigger_functions/usrpref.sql
new file mode 100644 (file)
index 0000000..a42695b
--- /dev/null
@@ -0,0 +1,113 @@
+/* most of the processing here is to maintain crm accounts because
+   usr is a view on pg_user and usrpref, not an actual table.
+   the following records contribute to the usr view: usrpref_name IN
+   ('propername', 'locale', 'initials', 'agent', 'active', 'email', 'window')
+TODO: change usr view so it works with a cntct_id stored in usrpref instead of
+      'propername', 'initials', and 'email'?
+TODO: should usrpref_name='active' be calculated from pg_authid's
+      rolname, rolcanlogin, rolvaliduntil?
+ */
+
+CREATE OR REPLACE FUNCTION _usrprefBeforeTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF NOT (checkPrivilege('MaintainUsers') OR
+          checkPrivilege('MaintainPreferencesOthers') OR
+          (checkPrivilege('MaintainPreferencesSelf'))) THEN
+    -- 2 IFs because plpgsql doesn't always evaluate boolean exprs left-to-right
+    IF (TG_OP = 'DELETE') THEN
+      IF NOT (OLD.usrpref_name LIKE '%/checked' OR OLD.usrpref_name LIKE '%/columnsShown') THEN
+        RAISE EXCEPTION 'You do not have privileges to change this User Preference.';
+      END IF;
+    ELSIF (NEW.usrpref_username = getEffectiveXtUser()) THEN
+      IF NOT (NEW.usrpref_name LIKE '%/checked' OR NEW.usrpref_name LIKE '%/columnsShown') THEN
+        RAISE EXCEPTION 'You do not have privileges to change this User Preference.';
+      END IF;
+    END IF;
+  END IF;
+
+  IF (TG_OP IN ('INSERT', 'UPDATE')) THEN
+    IF (NEW.usrpref_name = 'locale') THEN
+      IF NOT EXISTS(SELECT locale_id
+                      FROM locale
+                     WHERE locale_id = NEW.usrpref_value::INTEGER) THEN
+        RAISE EXCEPTION 'You must supply a valid Locale.';
+      END IF;
+
+    ELSIF (NEW.usrpref_name IN ('agent', 'active')) THEN
+      IF (NEW.usrpref_value NOT IN ('t', 'f')) THEN
+        RAISE EXCEPTION '% must be either "t" or "f"', NEW.usrpref_name;
+      END IF;
+    END IF;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'usrprefBeforeTrigger');
+CREATE TRIGGER usrprefBeforeTrigger BEFORE INSERT OR UPDATE OR DELETE ON usrpref
+       FOR EACH ROW EXECUTE PROCEDURE _usrprefBeforeTrigger();
+
+CREATE OR REPLACE FUNCTION _usrprefAfterTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+  IF (TG_OP = 'INSERT' OR TG_OP = 'UPDATE') THEN
+    -- http://www.postgresql.org/docs/current/static/plpgsql-control-structures.html#PLPGSQL-UPSERT-EXAMPLE
+    IF (NEW.usrpref_name='active') THEN
+      LOOP
+        UPDATE crmacct SET crmacct_usr_username=NEW.usrpref_username
+         WHERE crmacct_number=UPPER(NEW.usrpref_username);
+        IF (FOUND) THEN
+          EXIT;
+        END IF;
+        BEGIN
+          INSERT INTO crmacct(crmacct_number,        crmacct_active,
+                              crmacct_type,          crmacct_usr_username
+                    ) VALUES (NEW.usrpref_username,  NEW.usrpref_value::BOOL,
+                              'I',                   NEW.usrpref_username);
+          EXIT;
+        EXCEPTION WHEN unique_violation THEN
+            -- do nothing, and loop to try the UPDATE again
+        END;
+      END LOOP;
+
+    ELSIF (NEW.usrpref_name='propername') THEN
+      LOOP
+        UPDATE crmacct SET crmacct_name=NEW.usrpref_value
+         WHERE crmacct_number=UPPER(NEW.usrpref_username);
+        IF (FOUND) THEN
+          EXIT;
+        END IF;
+        BEGIN
+          INSERT INTO crmacct(crmacct_number,        crmacct_active,
+                              crmacct_name,
+                              crmacct_type,          crmacct_usr_username
+                    ) VALUES (UPPER(NEW.usrpref_username), TRUE,
+                              NEW.usrpref_value,
+                              'I',                   NEW.usrpref_username);
+          EXIT;
+        EXCEPTION WHEN unique_violation THEN
+            -- do nothing, and loop to try the UPDATE again
+        END;
+      END LOOP;
+
+    END IF;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'usrprefAfterTrigger');
+CREATE TRIGGER usrprefAfterTrigger AFTER INSERT OR UPDATE OR DELETE ON usrpref
+       FOR EACH ROW EXECUTE PROCEDURE _usrprefAfterTrigger();
diff --git a/foundation-database/public/trigger_functions/usrpriv.sql b/foundation-database/public/trigger_functions/usrpriv.sql
new file mode 100644 (file)
index 0000000..7ab0098
--- /dev/null
@@ -0,0 +1,28 @@
+CREATE OR REPLACE FUNCTION _usrprivTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _check BOOLEAN;
+  _returnVal INTEGER;
+BEGIN
+  -- This looks like a candidate for a foreign key but isn't.
+  -- fkeys don't work if the foreign key value resides in a child of the 
+  -- table and not the table itself.
+  IF ((TG_OP = 'UPDATE' OR TG_OP = 'INSERT') AND
+      (NOT EXISTS(SELECT priv_id
+                  FROM priv
+                  WHERE (priv_id=NEW.usrpriv_priv_id)))) THEN
+    RAISE EXCEPTION 'Privilege id % does not exist or is part of a disabled package.',
+                NEW.usrpriv_priv_id;
+    RETURN OLD;
+
+  ELSIF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('trigger', 'usrprivTrigger');
+CREATE TRIGGER usrprivTrigger BEFORE INSERT OR UPDATE ON usrpriv FOR EACH ROW EXECUTE PROCEDURE _usrprivTrigger();
diff --git a/foundation-database/public/trigger_functions/vend.sql b/foundation-database/public/trigger_functions/vend.sql
new file mode 100644 (file)
index 0000000..d72676e
--- /dev/null
@@ -0,0 +1,182 @@
+CREATE OR REPLACE FUNCTION _vendTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple.
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+
+  IF NOT (checkPrivilege('MaintainVendors')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Vendors.';
+  END IF;
+
+  IF (LENGTH(COALESCE(NEW.vend_number, ''))=0) THEN
+    RAISE EXCEPTION 'You must supply a valid Vendor Number.';
+  END IF;
+
+  IF (LENGTH(COALESCE(NEW.vend_name, ''))=0) THEN
+    RAISE EXCEPTION 'You must supply a valid Vendor Name.';
+  END IF;
+
+  IF (NEW.vend_vendtype_id IS NULL) THEN
+    RAISE EXCEPTION 'You must supply a valid Vendor Type ID.';
+  END IF;
+
+  IF (NEW.vend_terms_id IS NULL) THEN
+    RAISE EXCEPTION 'You must supply a valid Terms Code ID.';
+  END IF;
+
+  IF (TG_OP = 'INSERT' AND fetchMetricText('CRMAccountNumberGeneration') IN ('A','O')) THEN
+    PERFORM clearNumberIssue('CRMAccountNumber', NEW.vend_number);
+  END IF;
+
+  NEW.vend_number := UPPER(NEW.vend_number);
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'vendTrigger');
+CREATE TRIGGER vendTrigger BEFORE INSERT OR UPDATE ON vendinfo
+       FOR EACH ROW EXECUTE PROCEDURE _vendTrigger();
+
+CREATE OR REPLACE FUNCTION _vendAfterTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple.
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid   INTEGER;
+
+BEGIN
+
+  IF (TG_OP = 'INSERT') THEN
+    -- http://www.postgresql.org/docs/current/static/plpgsql-control-structures.html#PLPGSQL-UPSERT-EXAMPLE
+    LOOP
+      UPDATE crmacct SET crmacct_vend_id=NEW.vend_id,
+                         crmacct_name=NEW.vend_name
+       WHERE crmacct_number=NEW.vend_number;
+      IF (FOUND) THEN
+        EXIT;
+      END IF;
+      BEGIN
+        INSERT INTO crmacct(crmacct_number,     crmacct_name,    crmacct_active,
+                            crmacct_type,       crmacct_vend_id,
+                            crmacct_cntct_id_1, crmacct_cntct_id_2
+                  ) VALUES (NEW.vend_number,    NEW.vend_name,   NEW.vend_active,
+                            'O',                NEW.vend_id,
+                            NEW.vend_cntct1_id, NEW.vend_cntct2_id);
+        EXIT;
+      EXCEPTION WHEN unique_violation THEN
+            -- do nothing, and loop to try the UPDATE again
+      END;
+    END LOOP;
+
+    /* TODO: default characteristic assignments based on vendgrp? */
+
+  ELSIF (TG_OP = 'UPDATE') THEN
+    UPDATE crmacct SET crmacct_number = NEW.vend_number
+    WHERE ((crmacct_vend_id=NEW.vend_id)
+      AND  (crmacct_number!=NEW.vend_number));
+
+    UPDATE crmacct SET crmacct_name = NEW.vend_name
+    WHERE ((crmacct_vend_id=NEW.vend_id)
+      AND  (crmacct_name!=NEW.vend_name));
+
+  END IF;
+
+  IF (fetchMetricBool('VendorChangeLog')) THEN
+    SELECT cmnttype_id INTO _cmnttypeid
+      FROM cmnttype
+     WHERE (cmnttype_name='ChangeLog');
+
+    IF (_cmnttypeid IS NOT NULL) THEN
+      IF (TG_OP = 'INSERT') THEN
+        PERFORM postComment(_cmnttypeid, 'V', NEW.vend_id, 'Created');
+
+      ELSIF (TG_OP = 'UPDATE') THEN
+
+        IF (OLD.vend_number <> NEW.vend_number) THEN
+          PERFORM postComment(_cmnttypeid, 'V', NEW.vend_id,
+                              ('Number Changed from "' || OLD.vend_number ||
+                               '" to "' || NEW.vend_number || '"') );
+        END IF;
+
+        IF (OLD.vend_name <> NEW.vend_name) THEN
+          PERFORM postComment( _cmnttypeid, 'V', NEW.vend_id,
+                              ('Name Changed from "' || OLD.vend_name ||
+                               '" to "' || NEW.vend_name || '"') );
+        END IF;
+
+        IF (OLD.vend_active <> NEW.vend_active) THEN
+          PERFORM postComment(_cmnttypeid, 'V', NEW.vend_id,
+                              CASE WHEN NEW.vend_active THEN 'Activated'
+                                   ELSE 'Deactivated' END);
+        END IF;
+
+      END IF;
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'vendAfterTrigger');
+CREATE TRIGGER vendAfterTrigger AFTER INSERT OR UPDATE ON vendinfo
+       FOR EACH ROW EXECUTE PROCEDURE _vendAfterTrigger();
+
+CREATE OR REPLACE FUNCTION _vendinfoBeforeDeleteTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple.
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF NOT (checkPrivilege('MaintainVendors')) THEN
+    RAISE EXCEPTION 'You do not have privileges to maintain Vendors.';
+  END IF;
+
+  DELETE FROM itemsrcp
+   WHERE itemsrcp_itemsrc_id IN (SELECT itemsrc_id
+                                   FROM itemsrc
+                                  WHERE itemsrc_vend_id=OLD.vend_id);
+
+  DELETE FROM itemsrc WHERE (itemsrc_vend_id=OLD.vend_id);
+
+  DELETE FROM vendaddrinfo WHERE (vendaddr_vend_id=OLD.vend_id);
+
+  DELETE FROM docass WHERE docass_source_id = OLD.vend_id AND docass_source_type = 'V';
+  DELETE FROM docass WHERE docass_target_id = OLD.vend_id AND docass_target_type = 'V';
+
+  UPDATE crmacct SET crmacct_vend_id = NULL
+   WHERE crmacct_vend_id = OLD.vend_id;
+  RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'vendinfoBeforeDeleteTrigger');
+CREATE TRIGGER vendinfoBeforeDeleteTrigger BEFORE DELETE ON vendinfo
+       FOR EACH ROW EXECUTE PROCEDURE _vendinfoBeforeDeleteTrigger();
+
+CREATE OR REPLACE FUNCTION _vendinfoAfterDeleteTrigger () RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple.
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF EXISTS(SELECT 1
+              FROM checkhead
+             WHERE ((checkhead_recip_id=OLD.vend_id)
+                AND (checkhead_recip_type='V'))) THEN
+    RAISE EXCEPTION '[xtuple: deleteVendor, -7]';
+  END IF;
+
+  DELETE FROM taxreg
+   WHERE ((taxreg_rel_type='V')
+      AND (taxreg_rel_id=OLD.vend_id));
+
+  IF (fetchMetricBool('VendorChangeLog')) THEN
+    PERFORM postComment(cmnttype_id, 'V', OLD.vend_id,
+                        ('Deleted "' || OLD.vend_number || '"'))
+      FROM cmnttype
+     WHERE (cmnttype_name='ChangeLog');
+  END IF;
+
+  RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'vendinfoAfterDeleteTrigger');
+CREATE TRIGGER vendinfoAfterDeleteTrigger AFTER DELETE ON vendinfo
+       FOR EACH ROW EXECUTE PROCEDURE _vendinfoAfterDeleteTrigger();
diff --git a/foundation-database/public/trigger_functions/vendaddr.sql b/foundation-database/public/trigger_functions/vendaddr.sql
new file mode 100644 (file)
index 0000000..ed79d76
--- /dev/null
@@ -0,0 +1,50 @@
+CREATE OR REPLACE FUNCTION _vendaddrTrigger () RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _check      BOOLEAN;
+  _vendname   TEXT;
+
+BEGIN
+
+--  Checks
+  SELECT checkPrivilege(''MaintainVendors'') INTO _check;
+  IF NOT (_check) THEN
+    RAISE EXCEPTION ''You do not have privileges to maintain Vendors.'';
+  END IF;
+
+  IF (TG_OP IN (''INSERT'',''UPDATE'')) THEN
+
+    IF (LENGTH(COALESCE(NEW.vendaddr_code, ''''))=0) THEN
+      RAISE EXCEPTION ''You must supply a valid Vendor Address Number.'';
+    END IF;
+
+    IF (LENGTH(COALESCE(NEW.vendaddr_name, ''''))=0) THEN
+      RAISE EXCEPTION ''You must supply a valid Vendor Address Name.'';
+    END IF;
+
+    IF (NEW.vendaddr_vend_id IS NULL) THEN
+      RAISE EXCEPTION ''You must supply a valid Vendor ID.'';
+    END IF;
+
+    SELECT vendaddr_code INTO _vendname
+    FROM vendaddrinfo
+    WHERE ( (vendaddr_vend_id=NEW.vendaddr_vend_id)
+      AND (UPPER(vendaddr_code)=UPPER(NEW.vendaddr_code))
+      AND (vendaddr_id<>NEW.vendaddr_id) );
+    IF (FOUND) THEN
+      RAISE EXCEPTION ''The Vendor Address Number entered cannot be used as it is in use.'';
+    END IF;
+
+  END IF;
+  
+  IF (TG_OP = ''DELETE'') THEN
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+' LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'vendaddrTrigger');
+CREATE TRIGGER vendaddrTrigger BEFORE INSERT OR UPDATE OR DELETE ON vendaddrinfo FOR EACH ROW EXECUTE PROCEDURE _vendaddrTrigger();
diff --git a/foundation-database/public/trigger_functions/vodist.sql b/foundation-database/public/trigger_functions/vodist.sql
new file mode 100644 (file)
index 0000000..68ce193
--- /dev/null
@@ -0,0 +1,94 @@
+CREATE OR REPLACE FUNCTION _vodistBeforeTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    IF (OLD.vodist_tax_id <> -1) THEN
+    -- Delete any existing voheadtax adjustment records
+      DELETE FROM voheadtax
+      WHERE ( (taxhist_parent_id=OLD.vodist_vohead_id)
+        AND   (taxhist_tax_id=OLD.vodist_tax_id)
+        AND   (taxhist_taxtype_id=getAdjustmentTaxTypeId()) );
+    END IF;
+
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'vodistBeforeTrigger');
+CREATE TRIGGER vodistBeforeTrigger
+  BEFORE INSERT OR UPDATE OR DELETE
+  ON vodist
+  FOR EACH ROW
+  EXECUTE PROCEDURE _vodistBeforeTrigger();
+
+CREATE OR REPLACE FUNCTION _vodistAfterTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _r RECORD;
+
+BEGIN
+  IF ( (TG_OP = 'UPDATE') OR (TG_OP = 'DELETE') ) THEN
+    IF (OLD.vodist_tax_id <> -1) THEN
+    -- Delete any existing voheadtax adjustment records
+      DELETE FROM voheadtax
+      WHERE ( (taxhist_parent_id=OLD.vodist_vohead_id)
+        AND   (taxhist_tax_id=OLD.vodist_tax_id)
+        AND   (taxhist_taxtype_id=getAdjustmentTaxTypeId()) );
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+-- Cache Voucher Head
+  SELECT * INTO _r
+  FROM vohead
+  WHERE (vohead_id=NEW.vodist_vohead_id);
+  IF (NOT FOUND) THEN
+    RAISE EXCEPTION 'Voucher head not found';
+  END IF;
+
+  IF (NEW.vodist_tax_id <> -1) THEN
+  -- Insert adjustment voheadtax
+    INSERT INTO voheadtax
+      ( taxhist_parent_id,
+        taxhist_taxtype_id,
+        taxhist_tax_id,
+        taxhist_basis,
+        taxhist_basis_tax_id,
+        taxhist_sequence,
+        taxhist_percent,
+        taxhist_amount,
+        taxhist_tax,
+        taxhist_docdate )
+    VALUES
+      ( NEW.vodist_vohead_id,
+        getAdjustmentTaxTypeId(),
+        NEW.vodist_tax_id,
+        0,
+        NULL,
+        1,
+        0,
+        0,
+        (NEW.vodist_amount * -1),
+        _r.vohead_docdate );
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'vodistAfterTrigger');
+CREATE TRIGGER vodistAfterTrigger
+  AFTER INSERT OR UPDATE OR DELETE
+  ON vodist
+  FOR EACH ROW
+  EXECUTE PROCEDURE _vodistAfterTrigger();
diff --git a/foundation-database/public/trigger_functions/vohead.sql b/foundation-database/public/trigger_functions/vohead.sql
new file mode 100644 (file)
index 0000000..9e87720
--- /dev/null
@@ -0,0 +1,117 @@
+SELECT dropIfExists('TRIGGER', 'voheadBeforeTrigger');
+SELECT dropIfExists('TRIGGER', 'voheadAfterTrigger');
+
+CREATE OR REPLACE FUNCTION _voheadBeforeTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _recurid     INTEGER;
+  _newparentid INTEGER;
+
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    IF (OLD.vohead_posted) THEN
+      -- Cannot delete a posted voucher
+      RAISE EXCEPTION 'Cannot delete a posted voucher';
+    END IF;
+
+    /* TODO: is setting recv_invoiced and poreject_invoiced to FALSE correct?
+             this behavior is inherited from the now-defunct deleteVoucher.
+     */
+    UPDATE recv SET recv_vohead_id = NULL,
+                    recv_voitem_id = NULL,
+                    recv_invoiced  = FALSE
+     WHERE recv_vohead_id = OLD.vohead_id;
+
+    UPDATE poreject SET poreject_vohead_id = NULL,
+                        poreject_voitem_id = NULL,
+                        poreject_invoiced  = FALSE
+     WHERE poreject_vohead_id = OLD.vohead_id;
+
+    DELETE FROM vodist    WHERE vodist_vohead_id  = OLD.vohead_id;
+    DELETE FROM voheadtax WHERE taxhist_parent_id = OLD.vohead_id;
+    DELETE FROM voitem    WHERE voitem_vohead_id  = OLD.vohead_id;
+
+    SELECT recur_id INTO _recurid
+      FROM recur
+     WHERE ((recur_parent_id=OLD.vohead_id)
+        AND (recur_parent_type='V'));
+    IF (_recurid IS NOT NULL) THEN
+      SELECT vohead_id INTO _newparentid
+        FROM vohead
+       WHERE ((vohead_recurring_vohead_id=OLD.vohead_id)
+          AND (vohead_id!=OLD.vohead_id))
+       ORDER BY vohead_docdate
+       LIMIT 1;
+
+      IF (_newparentid IS NULL) THEN
+        DELETE FROM recur WHERE recur_id=_recurid;
+      ELSE
+        UPDATE recur SET recur_parent_id=_newparentid
+         WHERE recur_id=_recurid;
+        UPDATE vohead SET vohead_recurring_vohead_id=_newparentid
+         WHERE vohead_recurring_vohead_id=OLD.vohead_id
+           AND vohead_id!=OLD.vohead_id;
+      END IF;
+    END IF;
+
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE TRIGGER voheadBeforeTrigger
+  BEFORE INSERT OR UPDATE OR DELETE
+  ON vohead
+  FOR EACH ROW
+  EXECUTE PROCEDURE _voheadBeforeTrigger();
+
+CREATE OR REPLACE FUNCTION _voheadAfterTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    PERFORM releaseVoNumber(CAST(OLD.vohead_number AS INTEGER));
+    RETURN OLD;
+  END IF;
+
+  IF (TG_OP = 'INSERT') THEN
+    PERFORM clearNumberIssue('VcNumber', NEW.vohead_number);
+    RETURN NEW;
+  END IF;
+
+  IF (TG_OP = 'UPDATE') THEN
+    IF ( (COALESCE(NEW.vohead_taxzone_id,-1) <> COALESCE(OLD.vohead_taxzone_id,-1)) OR
+         (NEW.vohead_docdate <> OLD.vohead_docdate) OR
+         (NEW.vohead_curr_id <> OLD.vohead_curr_id) ) THEN
+      PERFORM calculateTaxHist( 'voitemtax',
+                                voitem_id,
+                                NEW.vohead_taxzone_id,
+                                voitem_taxtype_id,
+                                NEW.vohead_docdate,
+                                NEW.vohead_curr_id,
+                                (vodist_amount * -1) )
+      FROM voitem JOIN vodist ON ( (vodist_vohead_id=voitem_vohead_id) AND
+                                   (vodist_poitem_id=voitem_poitem_id) )
+      WHERE (voitem_vohead_id = NEW.vohead_id);
+    END IF;
+
+    -- Touch any Misc Tax Distributions so voheadtax is recalculated
+    IF (NEW.vohead_docdate <> OLD.vohead_docdate) THEN
+      UPDATE vodist SET vodist_vohead_id=NEW.vohead_id
+      WHERE ( (vodist_vohead_id=OLD.vohead_id)
+        AND   (vodist_tax_id <> -1) );
+    END IF;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE TRIGGER voheadAfterTrigger
+  AFTER INSERT OR UPDATE OR DELETE
+  ON vohead
+  FOR EACH ROW
+  EXECUTE PROCEDURE _voheadAfterTrigger();
diff --git a/foundation-database/public/trigger_functions/voitem.sql b/foundation-database/public/trigger_functions/voitem.sql
new file mode 100644 (file)
index 0000000..27d786b
--- /dev/null
@@ -0,0 +1,65 @@
+CREATE OR REPLACE FUNCTION _voitemBeforeTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    DELETE FROM voitemtax
+    WHERE (taxhist_parent_id=OLD.voitem_id);
+
+    RETURN OLD;
+  END IF;
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'voitemBeforeTrigger');
+CREATE TRIGGER voitemBeforeTrigger
+  BEFORE INSERT OR UPDATE OR DELETE
+  ON voitem
+  FOR EACH ROW
+  EXECUTE PROCEDURE _voitemBeforeTrigger();
+
+CREATE OR REPLACE FUNCTION _voitemAfterTrigger() RETURNS "trigger" AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _r RECORD;
+
+BEGIN
+  IF (TG_OP = 'DELETE') THEN
+    RETURN OLD;
+  END IF;
+
+-- Cache Voucher Head
+  SELECT * INTO _r
+  FROM vohead
+  WHERE (vohead_id=NEW.voitem_vohead_id);
+  IF (NOT FOUND) THEN
+    RAISE EXCEPTION 'Voucher head not found';
+  END IF;
+
+-- Calculate Tax
+  PERFORM calculateTaxHist( 'voitemtax',
+                            NEW.voitem_id,
+                            COALESCE(_r.vohead_taxzone_id, -1),
+                            NEW.voitem_taxtype_id,
+                            COALESCE(_r.vohead_docdate, CURRENT_DATE),
+                            COALESCE(_r.vohead_curr_id, -1),
+                            COALESCE(SUM(vodist_amount * -1), 0) )
+  FROM vodist
+  WHERE ( (vodist_vohead_id=_r.vohead_id)
+    AND   (vodist_poitem_id=NEW.voitem_poitem_id) );
+
+  RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'voitemAfterTrigger');
+CREATE TRIGGER voitemAfterTrigger
+  AFTER INSERT OR UPDATE OR DELETE
+  ON voitem
+  FOR EACH ROW
+  EXECUTE PROCEDURE _voitemAfterTrigger();
diff --git a/foundation-database/public/trigger_functions/whsezone.sql b/foundation-database/public/trigger_functions/whsezone.sql
new file mode 100644 (file)
index 0000000..ef4c44b
--- /dev/null
@@ -0,0 +1,40 @@
+CREATE OR REPLACE FUNCTION _whseZoneTrigger () RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _check      BOOLEAN;
+  _checkId    INTEGER;
+
+BEGIN
+
+  -- Checks
+  -- Start with privileges
+  IF (TG_OP = ''INSERT'') THEN
+    SELECT checkPrivilege(''MaintainWarehouses'') INTO _check;
+    IF NOT (_check) THEN
+      RAISE EXCEPTION ''You do not have privileges to add new Site Zones.'';
+    END IF;
+  ELSE
+    SELECT checkPrivilege(''MaintainWarehouses'') INTO _check;
+    IF NOT (_check) THEN
+      RAISE EXCEPTION ''You do not have privileges to alter a Site Zone.'';
+    END IF;
+  END IF;
+
+  -- Name is required
+  IF (LENGTH(COALESCE(NEW.whsezone_name,''''))=0) THEN
+    RAISE EXCEPTION ''You must supply a valid Site Zone Name.'';
+  END IF;
+  
+  -- Site is required
+  IF (NEW.whsezone_warehous_id IS NULL) THEN
+    RAISE EXCEPTION ''You must supply a valid Site.'';
+  END IF;
+
+  RETURN NEW;
+
+END;
+' LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'whseZoneTrigger');
+CREATE TRIGGER whseZoneTrigger BEFORE INSERT OR UPDATE ON whsezone FOR EACH ROW EXECUTE PROCEDURE _whseZoneTrigger();
diff --git a/foundation-database/public/trigger_functions/whsinfo.sql b/foundation-database/public/trigger_functions/whsinfo.sql
new file mode 100644 (file)
index 0000000..cc668aa
--- /dev/null
@@ -0,0 +1,108 @@
+CREATE OR REPLACE FUNCTION _warehousTrigger () RETURNS TRIGGER AS '
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+  _cmnttypeid INTEGER;
+  _check      BOOLEAN;
+  _checkId    INTEGER;
+
+BEGIN
+
+  -- Checks
+  -- Start with privileges
+  IF (TG_OP = ''INSERT'') THEN
+    SELECT checkPrivilege(''MaintainWarehouses'') INTO _check;
+    IF NOT (_check) THEN
+      RAISE EXCEPTION ''You do not have privileges to add new Sites.'';
+    END IF;
+  ELSE
+    SELECT checkPrivilege(''MaintainWarehouses'') OR checkPrivilege(''IssueCountTags'') INTO _check;
+    IF NOT (_check) THEN
+      RAISE EXCEPTION ''You do not have privileges to alter a Site.'';
+    END IF;
+  END IF;
+
+  -- Code is required
+  IF (LENGTH(COALESCE(NEW.warehous_code,''''))=0) THEN
+    RAISE EXCEPTION ''You must supply a valid Site Code.'';
+  END IF;
+  
+  -- Sitetype is required
+  IF (NEW.warehous_sitetype_id IS NULL) THEN
+    RAISE EXCEPTION ''You must supply a valid Site Type.'';
+  END IF;
+
+  -- Cost Category is required for Transit types
+  IF ((NEW.warehous_transit) AND (NEW.warehous_costcat_id IS NULL)) THEN
+    RAISE EXCEPTION ''You must supply a valid Cost Category for Transit Sites.'';
+  END IF;
+
+  -- Code must be unique
+  SELECT warehous_id INTO _checkId
+  FROM whsinfo
+  WHERE ( (UPPER(warehous_code)=UPPER(NEW.warehous_code))
+    AND   (warehous_id<>NEW.warehous_id) );
+  IF (FOUND) THEN
+    RAISE EXCEPTION ''You must supply a unique Site Code.'';
+  END IF;
+  
+  -- Count Tag Prefix must be unique
+  IF (TG_OP = ''INSERT'') THEN
+    SELECT warehous_id INTO _checkId
+    FROM whsinfo
+    WHERE (warehous_counttag_prefix=NEW.warehous_counttag_prefix);
+  ELSE
+    SELECT warehous_id INTO _checkId
+    FROM whsinfo
+    WHERE ( (warehous_counttag_prefix=NEW.warehous_counttag_prefix)
+      AND   (warehous_id<>NEW.warehous_id) );
+  END IF;
+  IF (FOUND) THEN
+    RAISE EXCEPTION ''You must supply a unique Count Tag Prefix.'';
+  END IF;
+  
+  -- Check Complete
+  -- Change Log
+  IF ( SELECT (metric_value=''t'')
+       FROM metric
+       WHERE (metric_name=''WarehouseChangeLog'') ) THEN
+
+--  Cache the cmnttype_id for ChangeLog
+    SELECT cmnttype_id INTO _cmnttypeid
+    FROM cmnttype
+    WHERE (cmnttype_name=''ChangeLog'');
+    IF (FOUND) THEN
+      IF (TG_OP = ''INSERT'') THEN
+        PERFORM postComment(_cmnttypeid, ''WH'', NEW.warehous_id, ''Created'');
+
+      ELSIF (TG_OP = ''UPDATE'') THEN
+        IF (OLD.warehous_code <> NEW.warehous_code) THEN
+          PERFORM postComment( _cmnttypeid, ''WH'', NEW.warehous_id,
+                               (''Code Changed from "'' || OLD.warehous_code || ''" to "'' || NEW.warehous_code || ''"'') );
+        END IF;
+
+        IF (OLD.warehous_descrip <> NEW.warehous_descrip) THEN
+          PERFORM postComment( _cmnttypeid, ''WH'', NEW.warehous_id,
+                               ( ''Description Changed from "'' || OLD.warehous_descrip ||
+                                 ''" to "'' || NEW.warehous_descrip || ''"'' ) );
+        END IF;
+
+        IF (OLD.warehous_active <> NEW.warehous_active) THEN
+          IF (NEW.warehous_active) THEN
+            PERFORM postComment(_cmnttypeid, ''WH'', NEW.warehous_id, ''Activated'');
+          ELSE
+            PERFORM postComment(_cmnttypeid, ''WH'', NEW.warehous_id, ''Deactivated'');
+          END IF;
+        END IF;
+
+      END IF;
+    END IF;
+  END IF;
+  
+  RETURN NEW;
+
+END;
+' LANGUAGE 'plpgsql';
+
+DROP TRIGGER warehousTrigger ON whsinfo;
+CREATE TRIGGER warehousTrigger BEFORE INSERT OR UPDATE ON whsinfo FOR EACH ROW EXECUTE PROCEDURE _warehousTrigger();
diff --git a/foundation-database/public/trigger_functions/wo.sql b/foundation-database/public/trigger_functions/wo.sql
new file mode 100644 (file)
index 0000000..5674716
--- /dev/null
@@ -0,0 +1,105 @@
+CREATE OR REPLACE FUNCTION _woTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+
+BEGIN
+
+  IF (TG_OP = 'INSERT') THEN
+    PERFORM postEvent('WoCreated', 'W', NEW.wo_id,
+                      itemsite_warehous_id,
+                      (NEW.wo_number || '-' || NEW.wo_subnumber), 
+                      NULL, NULL, NULL, NULL)
+    FROM itemsite
+    WHERE (itemsite_id=NEW.wo_itemsite_id)
+      AND (NEW.wo_duedate <= (CURRENT_DATE + itemsite_eventfence));
+
+    PERFORM postComment('ChangeLog', 'W', NEW.wo_id, 'Created');
+
+    IF (fetchMetricText('WONumberGeneration') IN ('A','O')) THEN
+      --- clear the number from the issue cache
+      PERFORM clearNumberIssue('WoNumber', NEW.wo_number);
+    END IF;
+
+    RETURN NEW;
+
+  ELSE
+      IF (TG_OP = 'DELETE') THEN
+      PERFORM postEvent('WoCancelled', 'W', OLD.wo_id,
+                        itemsite_warehous_id,
+                        (OLD.wo_number || '-' || OLD.wo_subnumber), 
+                        NULL, NULL, NULL, NULL)
+      FROM itemsite
+      WHERE (itemsite_id=OLD.wo_itemsite_id)
+        AND (OLD.wo_duedate <= (CURRENT_DATE + itemsite_eventfence));
+
+      DELETE FROM docass WHERE docass_source_id = OLD.wo_id AND docass_source_type = 'W';
+      DELETE FROM docass WHERE docass_target_id = OLD.wo_id AND docass_target_type = 'W';
+
+      DELETE FROM comment
+      WHERE ( (comment_source='W')
+       AND (comment_source_id=OLD.wo_id) );
+
+      DELETE FROM charass
+       WHERE ((charass_target_type='W')
+         AND  (charass_target_id=OLD.wo_id));
+
+       RETURN OLD;
+
+    ELSE
+      IF (TG_OP = 'UPDATE') THEN
+
+        IF (NEW.wo_qtyord <> OLD.wo_qtyord) THEN
+          PERFORM postEvent('WoQtyChanged', 'W', NEW.wo_id,
+                            itemsite_warehous_id,
+                            (NEW.wo_number || '-' || NEW.wo_subnumber), 
+                            NEW.wo_qtyord, OLD.wo_qtyord, NULL, NULL)
+          FROM itemsite
+          WHERE (itemsite_id=NEW.wo_itemsite_id)
+            AND ( (NEW.wo_duedate <= (CURRENT_DATE + itemsite_eventfence))
+             OR   (OLD.wo_duedate <= (CURRENT_DATE + itemsite_eventfence)) );
+
+          PERFORM postComment( 'ChangeLog', 'W', NEW.wo_id,
+                               ( 'Qty. Ordered Changed from ' || formatQty(OLD.wo_qtyord) ||
+                                 ' to ' || formatQty(NEW.wo_qtyord ) ) );
+        END IF;
+
+        IF (NEW.wo_duedate <> OLD.wo_duedate) THEN
+          PERFORM postEvent('WoDueDateChanged', 'W', NEW.wo_id,
+                            itemsite_warehous_id,
+                            (NEW.wo_number || '-' || NEW.wo_subnumber), 
+                            NULL, NULL, NEW.wo_duedate, OLD.wo_duedate)
+          FROM itemsite
+          WHERE (itemsite_id=NEW.wo_itemsite_id)
+            AND ( (NEW.wo_duedate <= (CURRENT_DATE + itemsite_eventfence))
+             OR   (OLD.wo_duedate <= (CURRENT_DATE + itemsite_eventfence)) );
+
+          PERFORM postComment( 'ChangeLog', 'W', NEW.wo_id,
+                               ( 'Due Date Changed from ' || formatDate(OLD.wo_duedate) ||
+                                 ' to ' || formatDate(NEW.wo_duedate ) ) );
+        END IF;
+
+        IF (NEW.wo_status <> OLD.wo_status) THEN
+          PERFORM postComment( 'ChangeLog', 'W', NEW.wo_id,
+                               ('Status Changed from ' || OLD.wo_status || ' to ' || NEW.wo_status) );
+        END IF;
+
+      END IF; 
+    END IF;
+  END IF;
+
+  IF (TG_OP = 'UPDATE') THEN
+    IF (NEW.wo_prj_id <> OLD.wo_prj_id) THEN
+      UPDATE wo SET wo_prj_id=NEW.wo_prj_id
+      WHERE (wo_ordtype='W')
+        AND (wo_ordid=NEW.wo_id);
+    END IF;
+  END IF;
+
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+DROP TRIGGER woTrigger ON wo;
+CREATE TRIGGER woTrigger BEFORE INSERT OR UPDATE OR DELETE ON wo FOR EACH ROW EXECUTE PROCEDURE _woTrigger();
diff --git a/foundation-database/public/trigger_functions/womatl.sql b/foundation-database/public/trigger_functions/womatl.sql
new file mode 100644 (file)
index 0000000..eec94d8
--- /dev/null
@@ -0,0 +1,24 @@
+CREATE OR REPLACE FUNCTION _womatlAfterTrigger() RETURNS TRIGGER AS $$
+-- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
+-- See www.xtuple.com/CPAL for the full text of the software license.
+DECLARE
+
+BEGIN
+
+  IF (TG_OP = 'INSERT') THEN
+
+  --  Create any required P/R's
+    PERFORM createPr('W', NEW.womatl_id)
+       FROM itemsite 
+      WHERE ((itemsite_id=NEW.womatl_itemsite_id)
+        AND  (itemsite_createpr));
+
+  END IF;
+
+  RETURN NEW;
+
+END;
+$$ LANGUAGE 'plpgsql';
+
+SELECT dropIfExists('TRIGGER', 'womatlAfterTrigger');
+CREATE TRIGGER womatlAfterTrigger AFTER INSERT OR UPDATE OR DELETE ON womatl FOR EACH ROW EXECUTE PROCEDURE _womatlAfterTrigger();