src-db/database/model/triggers/M_PRODUCT_TRG.xml
author Atul Gaware <atul.gaware@openbravo.com>
Fri, 21 Mar 2014 12:52:37 +0530
changeset 22744 f25d4926a29a
parent 22741 18e0d8ef18ce
child 22745 ca8c20bc2f67
permissions -rw-r--r--
Backout Issue 25301 Wrong fix pushed to pi
adrian@94
     1
<?xml version="1.0"?>
adrian@94
     2
  <database name="TRIGGER M_PRODUCT_TRG">
adrianromero@6800
     3
    <trigger name="M_PRODUCT_TRG" table="M_PRODUCT" fires="after" insert="true" update="true" delete="false" foreach="row">
gorkaion@239
     4
      <body><![CDATA[
asier@799
     5
/*************************************************************************
asier@799
     6
  * The contents of this file are subject to the Compiere Public
asier@799
     7
  * License 1.1 ("License"); You may not use this file except in
asier@799
     8
  * compliance with the License. You may obtain a copy of the License in
asier@799
     9
  * the legal folder of your Openbravo installation.
asier@799
    10
  * Software distributed under the License is distributed on an
asier@799
    11
  * "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either express or
asier@799
    12
  * implied. See the License for the specific language governing rights
asier@799
    13
  * and limitations under the License.
asier@799
    14
  * The Original Code is  Compiere  ERP &  Business Solution
asier@799
    15
  * The Initial Developer of the Original Code is Jorg Janke and ComPiere, Inc.
asier@799
    16
  * Portions created by Jorg Janke are Copyright (C) 1999-2001 Jorg Janke,
asier@799
    17
  * parts created by ComPiere are Copyright (C) ComPiere, Inc.;
asier@799
    18
  * All Rights Reserved.
ggi@6702
    19
  * Contributor(s): Openbravo SLU
atul@22744
    20
  * Contributions are Copyright (C) 2001-2013 Openbravo, S.L.U.
asier@799
    21
  *
asier@799
    22
  * Specifically, this derivative work is based upon the following Compiere
asier@799
    23
  * file and version.
asier@799
    24
  *************************************************************************/
adrian@94
    25
adrian@94
    26
   TYPE RECORD IS REF CURSOR;
adrian@94
    27
   Cur_Defaults RECORD;
adrian@94
    28
vinoth@4313
    29
    v_xTree_ID    			           varchar2(32);
vinoth@4313
    30
    v_xParent_ID  			           varchar2(32);
vinoth@4313
    31
    v_NextNo      			           VARCHAR2(32);
vinoth@4313
    32
    v_ControlNo 	 	               NUMBER;
vinoth@4313
    33
    v_P_Revenue_Acct    		       VARCHAR2(32);
naiara@18266
    34
    v_P_Def_Revenue_Acct    		   VARCHAR2(32);
vinoth@4313
    35
    v_P_Expense_Acct    		       VARCHAR2(32);
naiara@18267
    36
    v_P_Def_Expense_Acct    		   VARCHAR2(32);
vinoth@4325
    37
    v_P_Asset_Acct    			       VARCHAR2(32);
vinoth@4325
    38
    v_P_COGS_Acct    			         VARCHAR2(32);
vinoth@4325
    39
    v_P_PurchasePriceVariance_Acct VARCHAR2(32);
vinoth@4325
    40
    v_P_InvoicePriceVariance_Acct  VARCHAR2(32);
vinoth@4325
    41
    v_P_TradeDiscountRec_Acct    	 VARCHAR2(32);
vinoth@4325
    42
    v_P_TradeDiscountGrant_Acct    VARCHAR2(32);
naiara@17921
    43
    v_P_COGS_Return_Acct    VARCHAR2(32);
naiara@17921
    44
    v_P_Revenue_Return_Acct    VARCHAR2(32);
vinoth@4313
    45
    v_seq_name				             VARCHAR2(32);
vinoth@4313
    46
    v_Sequence_No			             VARCHAR2(32);
vinoth@4313
    47
    v_C_AcctSchema_ID			         VARCHAR2(32);
rafael@6108
    48
    v_Count 	 	               NUMBER;
atul@22744
    49
    v_qtyin_hand 	 	       NUMBER;
vinoth@4313
    50
  			
adrian@94
    51
BEGIN
asier@2084
    52
    IF AD_isTriggerEnabled()='N' THEN RETURN;
asier@2078
    53
    END IF;
asier@2078
    54
eduardo@1067
    55
 IF (UPDATING) THEN
eduardo@1067
    56
  UPDATE M_PRODUCT_ACCT SET AD_ORG_ID = :new.AD_ORG_ID
eduardo@1067
    57
  WHERE M_PRODUCT_ID = :new.M_PRODUCT_ID;
vinoth@4313
    58
  
adrian@94
    59
 -- Do not allow to de-activate products with OnHand Qty
javier@14739
    60
 -- or Change the attribute set
gorkaion@20882
    61
  IF ((:new.IsActive='N' AND :old.IsActive='Y')
gorkaion@20882
    62
      OR (COALESCE(:new.m_attributeset_id,'null') <> COALESCE(:old.m_attributeset_id,'null'))
gorkaion@20951
    63
      OR (COALESCE(:new.c_uom_id,'null') <> COALESCE(:old.c_uom_id,'null'))
gorkaion@20951
    64
      OR (:old.isStocked='Y' AND :new.isStocked='N')) THEN
atul@22744
    65
   SELECT  COALESCE(SUM(QtyOnHand)+SUM(QtyReserved)*.111+SUM(QtyOrdered)*999, 0) INTO v_ControlNo
adrian@94
    66
   FROM (SELECT QtyOnHand, 0 AS QtyReserved, 0 AS QtyOrdered
adrian@94
    67
   FROM M_Storage_Detail s
adrian@94
    68
   WHERE s.M_Product_ID=:new.M_Product_ID
adrian@94
    69
   UNION
adrian@94
    70
   SELECT 0 AS QtyOnHand, QtyReserved, QtyOrdered
adrian@94
    71
   FROM M_Storage_Pending s
adrian@94
    72
   WHERE s.M_Product_ID=:new.M_Product_ID) A;
atul@22744
    73
   select COALESCE(sum(QtyOnHand),0) Into v_qtyin_hand from (
atul@22744
    74
   SELECT QtyOnHand
atul@22744
    75
   FROM M_Storage_Detail s
atul@22744
    76
   WHERE s.M_Product_ID=:new.M_Product_ID
atul@22744
    77
   UNION
atul@22744
    78
   SELECT 0 AS QtyOnHand
atul@22744
    79
   FROM M_Storage_Pending s
atul@22744
    80
   WHERE s.M_Product_ID=:new.M_Product_ID )A;
gorkaion@239
    81
   IF (v_ControlNo <> 0) THEN
atul@22744
    82
    IF (COALESCE(:new.m_attributeset_id,'null') <> COALESCE(:old.m_attributeset_id,'null')) THEN
atul@22744
    83
      RAISE_APPLICATION_ERROR(-20000, '@20633@');
atul@22744
    84
    ELSIF (COALESCE(:new.c_uom_id,'null') <> COALESCE(:old.c_uom_id,'null')) THEN
atul@22744
    85
      RAISE_APPLICATION_ERROR(-20000, '@20634@');
atul@22744
    86
    ELSIF (:old.isStocked = 'Y' AND :new.isStocked = 'N') THEN
atul@22744
    87
      RAISE_APPLICATION_ERROR(-20000, '@StockedProductWithMovements@');
atul@22744
    88
    ELSIF (v_qtyin_hand=0) THEN
atul@22744
    89
      RAISE_APPLICATION_ERROR(-20000, '@ActivePoSo@');
atul@22744
    90
    ELSE
atul@22744
    91
      RAISE_APPLICATION_ERROR(-20000, '@20400@');
atul@22744
    92
    END IF;
adrian@94
    93
   END IF;
adrian@94
    94
  END IF;
gorkaion@20882
    95
vinoth@4313
    96
  IF( COALESCE(:old.Name,'.') <> COALESCE(:new.Name,'.')  OR COALESCE(:old.documentnote,'.') <> COALESCE(:new.documentnote,'.') ) THEN   
gorka@367
    97
    UPDATE M_PRODUCT_Trl
gorka@367
    98
      SET IsTranslated='N'
gorka@367
    99
    WHERE M_PRODUCT_ID=:new.M_PRODUCT_ID;
gorka@367
   100
  END IF;
gorka@367
   101
gorkaion@20947
   102
  -- Do not allow to set as generic a product used in documents.
gorkaion@20947
   103
  IF (:OLD.isgeneric = 'N' AND :NEW.isgeneric = 'Y') THEN
gorkaion@20947
   104
    SELECT count(*) INTO v_count
gorkaion@20947
   105
    FROM dual
gorkaion@20947
   106
    WHERE EXISTS (SELECT 1 FROM c_orderline WHERE m_product_id = :NEW.m_product_id)
gorkaion@20947
   107
       OR EXISTS (SELECT 1 FROM c_invoiceline WHERE m_product_id = :NEW.m_product_id)
gorkaion@20947
   108
       OR EXISTS (SELECT 1 FROM m_storage_detail WHERE m_product_id = :NEW.m_product_id)
gorkaion@20947
   109
       OR EXISTS (SELECT 1 FROM m_transaction WHERE m_product_id = :NEW.m_product_id);
gorkaion@20947
   110
    IF (v_count > 0) THEN
gorkaion@20947
   111
      RAISE_APPLICATION_ERROR(-20000, '@CannotSetAsGenericProduct@');
gorkaion@20947
   112
    END IF;
gorkaion@20947
   113
  END IF;
gorkaion@20947
   114
adrian@94
   115
 ELSIF (INSERTING) THEN
vinoth@4313
   116
  v_C_AcctSchema_ID:=null;
vinoth@4313
   117
  --   For all AcctSchema create ...
eduardo@3181
   118
  FOR Cur_Defaults IN (
vinoth@4313
   119
	SELECT  distinct AD_IsOrgIncluded(:new.AD_ORG_ID, a.AD_Org_ID, :new.AD_Client_ID), 
vinoth@4313
   120
  a.ad_sequence_pr_id,a.isprnewaccount,a.acct_length,a.subacct_length, d.ad_client_id, 
naiara@18267
   121
  d.p_revenue_acct, d.p_def_revenue_acct, d.p_expense_acct, d.p_def_expense_acct, d.p_asset_acct, d.p_cogs_acct, d.P_PurchasePriceVariance_Acct, d.P_InvoicePriceVariance_Acct,
naiara@17921
   122
  d.P_TradeDiscountRec_Acct, d.P_TradeDiscountGrant_Acct, d.P_COGS_Return_Acct, d.P_Revenue_Return_Acct, a.createdby, a.updatedby, a.C_AcctSchema_ID, d.ISACTIVE
vinoth@4313
   123
  FROM  M_Product_Category_Acct d, ad_Org_AcctSchema a
eduardo@3181
   124
	WHERE  d.M_Product_Category_ID=:new.M_Product_Category_ID
eduardo@3181
   125
	AND d.C_AcctSchema_ID = a.C_AcctSchema_ID
naiara@16064
   126
	AND a.ISACTIVE = 'Y'
naiara@16064
   127
    	AND (AD_IsOrgIncluded(a.AD_Org_ID, :new.AD_ORG_ID, :new.AD_Client_ID)<>-1
eduardo@3181
   128
	OR AD_IsOrgIncluded(:new.AD_ORG_ID, a.AD_Org_ID, :new.AD_Client_ID)<>-1)
vinoth@4313
   129
	ORDER BY 1 DESC
eduardo@3181
   130
  ) LOOP
vinoth@4313
   131
	
vinoth@4313
   132
   	-- Create new account for Product
vinoth@4313
   133
  IF (v_C_AcctSchema_ID is null or v_C_AcctSchema_ID <> Cur_Defaults.C_AcctSchema_ID) THEN
vinoth@4313
   134
  
vinoth@4313
   135
      IF(Cur_Defaults.IsPrNewAccount='Y') THEN
vinoth@4313
   136
   		
vinoth@4313
   137
            -- Retrieving the sequence number for sub account.		
vinoth@4313
   138
            SELECT NAME INTO v_seq_name FROM AD_SEQUENCE WHERE AD_SEQUENCE.AD_SEQUENCE_ID=Cur_Defaults.ad_sequence_pr_id;
vinoth@4313
   139
		
vinoth@4313
   140
            
vinoth@4313
   141
           
vinoth@4313
   142
            -- Retrieving the expense account number.
vinoth@4313
   143
            AD_Sequence_Doc(v_seq_name, Cur_Defaults.AD_Client_ID, 'Y', v_Sequence_No);
juanpablo@4388
   144
            c_validcombination_clone(Cur_Defaults.P_Expense_Acct, v_Sequence_No, :new.Name, Cur_Defaults.acct_length, Cur_Defaults.subacct_length, v_P_Expense_Acct);
naiara@18267
   145
            c_validcombination_clone(Cur_Defaults.P_Def_Expense_Acct, v_Sequence_No, :new.Name, Cur_Defaults.acct_length, Cur_Defaults.subacct_length, v_P_Def_Expense_Acct);
vinoth@4313
   146
            
vinoth@4313
   147
             -- Retrieving the revenue account number.
juanpablo@4388
   148
            c_validcombination_clone(Cur_Defaults.P_Revenue_Acct, v_Sequence_No, :new.Name, Cur_Defaults.acct_length, Cur_Defaults.subacct_length, v_P_Revenue_Acct);
vinoth@4325
   149
            
naiara@18266
   150
             -- Retrieving the revenue account number.
naiara@18266
   151
            c_validcombination_clone(Cur_Defaults.P_Def_Revenue_Acct, v_Sequence_No, :new.Name, Cur_Defaults.acct_length, Cur_Defaults.subacct_length, v_P_Def_Revenue_Acct);
naiara@18266
   152
            
vinoth@4325
   153
            -- Retrieving the asset account number.
juanpablo@4388
   154
            c_validcombination_clone(Cur_Defaults.P_Asset_Acct, v_Sequence_No, :new.Name, Cur_Defaults.acct_length, Cur_Defaults.subacct_length, v_P_Asset_Acct);
vinoth@4325
   155
			
vinoth@4325
   156
            -- Retrieving the cogs account number.
juanpablo@4388
   157
            c_validcombination_clone(Cur_Defaults.P_COGS_Acct, v_Sequence_No, :new.Name, Cur_Defaults.acct_length, Cur_Defaults.subacct_length, v_P_COGS_Acct);
vinoth@4325
   158
			
vinoth@4325
   159
            -- Retrieving the purchase price variance account number.
juanpablo@4388
   160
            c_validcombination_clone(Cur_Defaults.P_PurchasePriceVariance_Acct, v_Sequence_No, :new.Name, Cur_Defaults.acct_length, Cur_Defaults.subacct_length, v_P_PurchasePriceVariance_Acct);
vinoth@4325
   161
			
vinoth@4325
   162
            -- Retrieving the invoice price variance account number.
juanpablo@4388
   163
	    c_validcombination_clone(Cur_Defaults.P_InvoicePriceVariance_Acct, v_Sequence_No, :new.Name, Cur_Defaults.acct_length, Cur_Defaults.subacct_length, v_P_InvoicePriceVariance_Acct);		
vinoth@4325
   164
 
vinoth@4325
   165
            -- Retrieving the trade discount rec account number.
juanpablo@4388
   166
      	    c_validcombination_clone(Cur_Defaults.P_TradeDiscountRec_Acct, v_Sequence_No, :new.Name, Cur_Defaults.acct_length, Cur_Defaults.subacct_length, v_P_TradeDiscountRec_Acct);
vinoth@4325
   167
vinoth@4325
   168
            -- Retrieving the trade discount grant account number.
juanpablo@4388
   169
      	    c_validcombination_clone(Cur_Defaults.P_TradeDiscountGrant_Acct, v_Sequence_No, :new.Name, Cur_Defaults.acct_length, Cur_Defaults.subacct_length, v_P_TradeDiscountGrant_Acct);
vinoth@4313
   170
               
naiara@17921
   171
            -- Retrieving the cogs return grant account number.
naiara@17921
   172
      	    c_validcombination_clone(Cur_Defaults.P_COGS_Return_Acct, v_Sequence_No, :new.Name, Cur_Defaults.acct_length, Cur_Defaults.subacct_length, v_P_COGS_Return_Acct);
naiara@17921
   173
naiara@17921
   174
            -- Retrieving the revenue return grant account number.
naiara@17921
   175
      	    c_validcombination_clone(Cur_Defaults.P_Revenue_Return_Acct, v_Sequence_No, :new.Name, Cur_Defaults.acct_length, Cur_Defaults.subacct_length, v_P_Revenue_Return_Acct);
vinoth@4313
   176
            
vinoth@4313
   177
            -- Inserting the new sub account for Product 
vinoth@4313
   178
            INSERT INTO M_Product_Acct
vinoth@4313
   179
            (M_Product_Acct_ID, M_Product_ID, C_AcctSchema_ID,
vinoth@4313
   180
            AD_Client_ID, AD_Org_ID, IsActive, Created, CreatedBy, Updated, UpdatedBy,
naiara@18267
   181
            P_Revenue_Acct, P_Def_Revenue_Acct, P_Expense_Acct, P_Def_Expense_Acct, P_Asset_Acct, P_COGS_Acct,
vinoth@4313
   182
            P_PurchasePriceVariance_Acct, P_InvoicePriceVariance_Acct,
naiara@17921
   183
            P_TradeDiscountRec_Acct, P_TradeDiscountGrant_Acct,
naiara@17921
   184
            P_COGS_Return_Acct, P_Revenue_Return_Acct)
vinoth@4313
   185
            VALUES
vinoth@4313
   186
            (get_uuid(), :new.M_Product_ID, Cur_Defaults.C_AcctSchema_ID,
naiara@16064
   187
            :new.AD_Client_ID, :new.AD_ORG_ID, Cur_Defaults.ISACTIVE, now(), :new.CreatedBy, now(), :new.UpdatedBy,
naiara@18267
   188
            v_P_Revenue_Acct, v_P_Def_Revenue_Acct, v_P_Expense_Acct, v_P_Def_Expense_Acct, v_P_Asset_Acct, v_P_COGS_Acct,
vinoth@4325
   189
            v_P_PurchasePriceVariance_Acct, v_P_InvoicePriceVariance_Acct,
naiara@17921
   190
            v_P_TradeDiscountRec_Acct, v_P_TradeDiscountGrant_Acct,
naiara@17921
   191
            v_P_COGS_Return_Acct, v_P_Revenue_Return_Acct); 
vinoth@4325
   192
		  
vinoth@4313
   193
		  ELSE
vinoth@4313
   194
            --  Default Account
vinoth@4313
   195
            INSERT INTO M_Product_Acct
vinoth@4313
   196
            (M_Product_Acct_ID, M_Product_ID, C_AcctSchema_ID,
vinoth@4313
   197
            AD_Client_ID, AD_Org_ID, IsActive, Created, CreatedBy, Updated, UpdatedBy,
naiara@18267
   198
            P_Revenue_Acct, P_Def_Revenue_Acct, P_Expense_Acct, P_Def_Expense_Acct, P_Asset_Acct, P_COGS_Acct,
vinoth@4313
   199
            P_PurchasePriceVariance_Acct, P_InvoicePriceVariance_Acct,
naiara@17921
   200
            P_TradeDiscountRec_Acct, P_TradeDiscountGrant_Acct,
naiara@18266
   201
	    			P_COGS_Return_Acct, P_Revenue_Return_Acct)
vinoth@4313
   202
            VALUES
vinoth@4313
   203
			      (get_uuid(), :new.M_Product_ID, Cur_Defaults.C_AcctSchema_ID,
naiara@16064
   204
			      :new.AD_Client_ID, :new.AD_ORG_ID, Cur_Defaults.ISACTIVE, now(), :new.CreatedBy, now(), :new.UpdatedBy,
naiara@18267
   205
			      Cur_Defaults.P_Revenue_Acct, Cur_Defaults.P_Def_Revenue_Acct, Cur_Defaults.P_Expense_Acct, Cur_Defaults.P_Def_Expense_Acct, Cur_Defaults.P_Asset_Acct, Cur_Defaults.P_COGS_Acct,
vinoth@4313
   206
            Cur_Defaults.P_PurchasePriceVariance_Acct, Cur_Defaults.P_InvoicePriceVariance_Acct,
naiara@17921
   207
            Cur_Defaults.P_TradeDiscountRec_Acct, Cur_Defaults.P_TradeDiscountGrant_Acct, 
naiara@17921
   208
            Cur_Defaults.P_COGS_Return_Acct, Cur_Defaults.P_Revenue_Return_Acct);
vinoth@4313
   209
      END IF;
vinoth@4313
   210
            --Set the value for the variable with the used C_Acctschema_ID
vinoth@4313
   211
            v_C_AcctSchema_ID:=Cur_Defaults.C_AcctSchema_ID;
vinoth@4313
   212
  END IF;
vinoth@4313
   213
  END LOOP;
adrian@94
   214
     --  Create Translation Row
adrian@94
   215
     INSERT INTO M_Product_Trl
juanpablo@1605
   216
         (M_Product_Trl_ID, M_Product_ID, AD_Language, AD_Client_ID, AD_Org_ID,
adrian@94
   217
         IsActive, Created, CreatedBy, Updated, UpdatedBy,
adrian@94
   218
         Name, DocumentNote, IsTranslated)
juanpablo@1605
   219
     SELECT get_uuid(), :new.M_Product_ID, AD_Language, :new.AD_Client_ID, :new.AD_Org_ID,
adrian@94
   220
         :new.IsActive, :new.Created, :new.CreatedBy, :new.Updated, :new.UpdatedBy,
vinoth@4313
   221
         :new.Name, :new.DocumentNote, 'N' FROM  AD_Language
adrian@94
   222
     WHERE IsActive = 'Y' AND IsSystemLanguage = 'Y'
adrian@94
   223
    AND EXISTS (SELECT * FROM AD_Client
adrian@94
   224
     WHERE AD_Client_ID=:new.AD_Client_ID AND IsMultiLingualDocument='Y');
victor@11798
   225
     
adrian@94
   226
 END IF;
rafael@6108
   227
 IF (INSERTING OR UPDATING) THEN
rafael@6108
   228
    -- Checks on the attribute set value
rafael@6108
   229
    IF (COALESCE(:new.M_AttributeSetInstance_ID, '0') != '0') THEN
rafael@6108
   230
       IF (:new.M_AttributeSet_ID IS NULL) THEN
rafael@6108
   231
          RAISE_APPLICATION_ERROR(-20000, '@SelectAttrSetDeleteAttrSetValue@');
rafael@6108
   232
       ELSE
rafael@6108
   233
          SELECT COUNT(*)
rafael@6108
   234
	  INTO v_Count
rafael@6108
   235
	  FROM M_ATTRIBUTESETINSTANCE
rafael@6108
   236
	  WHERE M_ATTRIBUTESETINSTANCE_ID = :new.M_AttributeSetInstance_ID
rafael@6108
   237
	  AND M_ATTRIBUTESET_ID = :new.M_AttributeSet_ID;
rafael@6108
   238
          IF (v_Count = 0) THEN
rafael@6108
   239
             RAISE_APPLICATION_ERROR(-20000, '@MismatchAttrSetAttrSetValue@');
rafael@6108
   240
          END IF;
rafael@6108
   241
       END IF;
rafael@6108
   242
    ELSE
rafael@6108
   243
       IF (:new.AttrSetValueType IS NOT NULL) THEN
rafael@6108
   244
          RAISE_APPLICATION_ERROR(-20000, '@DeleteAttrSetValueType@');
rafael@6108
   245
       END IF;
rafael@6108
   246
    END IF;
rafael@6108
   247
 END IF;
adrian@94
   248
EXCEPTION
adrian@94
   249
 WHEN NO_DATA_FOUND THEN
naiara@16428
   250
  RAISE_APPLICATION_ERROR(-20000, '@20009@');
adrian@94
   251
antonio@735
   252
END M_PRODUCT_TRG
gorkaion@239
   253
]]></body>
adrian@94
   254
    </trigger>
adrian@94
   255
  </database>