src-db/database/model/functions/M_UPDATE_PARETO_PRODUCT.xml
author Juan Pablo Aroztegi <juanpablo.aroztegi@openbravo.com>
Wed, 03 Sep 2008 17:55:37 +0000
changeset 1605 8a0fe0193bef
parent 1273 3f48377a0023
child 1684 916be19be567
permissions -rw-r--r--
Merge r2.5x intro trunk
juanpablo@721
     1
<?xml version="1.0"?>
juanpablo@721
     2
  <database name="FUNCTION M_UPDATE_PARETO_PRODUCT">
juanpablo@721
     3
    <function name="M_UPDATE_PARETO_PRODUCT" type="NULL">
juanpablo@1605
     4
      <parameter name="p_pinstance_id" type="VARCHAR" mode="in">
antonio@735
     5
        <default/>
antonio@735
     6
      </parameter>
juanpablo@1605
     7
      <parameter name="p_warehouse_id" type="VARCHAR" mode="in">
antonio@735
     8
        <default/>
antonio@735
     9
      </parameter>
juanpablo@1605
    10
      <parameter name="p_org_id" type="VARCHAR" mode="in">
antonio@735
    11
        <default/>
antonio@735
    12
      </parameter>
carlos@616
    13
      <body><![CDATA[/*************************************************************************
carlos@616
    14
* The contents of this file are subject to the Openbravo  Public  License
carlos@616
    15
* Version  1.0  (the  "License"),  being   the  Mozilla   Public  License
carlos@616
    16
* Version 1.1  with a permitted attribution clause; you may not  use this
carlos@616
    17
* file except in compliance with the License. You  may  obtain  a copy of
carlos@616
    18
* the License at http://www.openbravo.com/legal/license.html
carlos@616
    19
* Software distributed under the License  is  distributed  on  an "AS IS"
carlos@616
    20
* basis, WITHOUT WARRANTY OF ANY KIND, either express or implied. See the
carlos@616
    21
* License for the specific  language  governing  rights  and  limitations
carlos@616
    22
* under the License.
carlos@616
    23
* The Original Code is Openbravo ERP.
carlos@616
    24
* The Initial Developer of the Original Code is Openbravo SL
carlos@616
    25
* All portions are Copyright (C) 2001-2008 Openbravo SL
carlos@616
    26
* All Rights Reserved.
carlos@616
    27
* Contributor(s):  ______________________________________.
carlos@616
    28
************************************************************************/
carlos@616
    29
carlos@646
    30
  v_ResultStr VARCHAR2(2000):='';
antonio@737
    31
  v_Result NUMBER:= 1;
carlos@616
    32
  v_Message VARCHAR2(2000):='';
antonio@735
    33
  v_exist NUMBER:=0;
juanpablo@1605
    34
  v_M_Product_Org_ID VARCHAR2(32);
juanpablo@1605
    35
  v_warehouse_ID VARCHAR2(32);
juanpablo@1605
    36
  v_org_ID VARCHAR2(32);
antonio@735
    37
  v_count_update NUMBER:= 0;
antonio@737
    38
  v_count_insert NUMBER:= 0;
carlos@616
    39
  TYPE RECORD IS REF CURSOR;
carlos@616
    40
  Cur_Cursor RECORD;
antonio@737
    41
  Cur_Parameter RECORD;
juanpablo@1605
    42
  v_AD_Client_ID VARCHAR2(32);
carlos@616
    43
BEGIN
carlos@616
    44
carlos@616
    45
  IF(p_PInstance_ID IS NOT NULL) THEN
carlos@616
    46
      --  Update AD_PInstance
carlos@616
    47
      DBMS_OUTPUT.PUT_LINE('Updating PInstance - Processing ' || p_PInstance_ID) ;
carlos@616
    48
      v_ResultStr:='PInstanceNotFound';
carlos@616
    49
      AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'Y', NULL, NULL) ;
carlos@616
    50
      -- Get Parameters
carlos@616
    51
      v_ResultStr:='ReadingParameters';
carlos@616
    52
      FOR Cur_Parameter IN (SELECT i.Record_ID, i.AD_User_ID, p.ParameterName, p.P_String, p.P_Number, p.P_Date, i.UpdatedBy
carlos@616
    53
                            FROM AD_PINSTANCE i LEFT JOIN AD_PINSTANCE_PARA p ON i.AD_PInstance_ID=p.AD_PInstance_ID
carlos@616
    54
                            WHERE i.AD_PInstance_ID=p_PInstance_ID
carlos@616
    55
                            ORDER BY p.SeqNo) LOOP
carlos@616
    56
        IF (Cur_Parameter.ParameterName = 'm_warehouse_id') THEN
carlos@616
    57
          v_warehouse_ID := Cur_Parameter.P_String;
carlos@616
    58
          DBMS_OUTPUT.PUT_LINE('  m_warehouse_id=' || v_warehouse_ID) ;
carlos@616
    59
        ELSIF (Cur_Parameter.ParameterName = 'ad_org_id') THEN
carlos@616
    60
          v_org_ID := Cur_Parameter.P_String;
carlos@616
    61
          DBMS_OUTPUT.PUT_LINE('  ad_org_id=' || v_org_ID) ;
carlos@616
    62
        END IF;
carlos@616
    63
      END LOOP; --Get Parameter
carlos@616
    64
carlos@616
    65
    ELSE
carlos@616
    66
      DBMS_OUTPUT.PUT_LINE('--<<M_UPDATE_PARETO_PRODUCT>>') ;
carlos@616
    67
      v_warehouse_ID:=p_warehouse_ID;
antonio@737
    68
      v_org_ID:=p_org_ID;
carlos@616
    69
    END IF;
carlos@616
    70
    BEGIN --BODY
antonio@737
    71
carlos@616
    72
  for Cur_Cursor in (
carlos@629
    73
     SELECT ORGID, SEARCHKEY, NAME, COST, PORCENTAJE,
carlos@629
    74
     GET_PARETO_ABC(v_warehouse_ID, v_org_ID, PORCENTAJE) AS ISABC,
carlos@629
    75
     AD_ORG_ID, AD_CLIENT_ID, M_PRODUCT_ID
carlos@616
    76
     FROM
carlos@616
    77
     (
antonio@737
    78
     SELECT
carlos@616
    79
      AD_ORG.NAME AS ORGID,
carlos@616
    80
      PR.VALUE AS SEARCHKEY,
carlos@616
    81
      PR.NAME,
antonio@735
    82
      GET_PRODUCT_COST(PR.M_PRODUCT_ID,TO_DATE(now()),'AV') AS COST,
antonio@737
    83
      100*(GET_PRODUCT_COST(PR.M_PRODUCT_ID,TO_DATE(now()),'AV')/ (SELECT SUM(GET_PRODUCT_COST(PR1.M_PRODUCT_ID,TO_DATE(now()),'AV'))
antonio@737
    84
                                                           from M_WAREHOUSE MW1
carlos@616
    85
                                                           LEFT JOIN M_LOCATOR ML1 ON ML1.M_WAREHOUSE_ID=MW1.M_WAREHOUSE_ID
carlos@616
    86
                                                           LEFT JOIN M_STORAGE_DETAIL MSD1 ON ML1.M_LOCATOR_ID=MSD1.M_LOCATOR_ID
antonio@737
    87
                                                           LEFT JOIN M_PRODUCT PR1 ON MSD1.M_PRODUCT_ID=PR1.M_PRODUCT_ID
carlos@616
    88
                                                           WHERE MSD1.QTYONHAND>0
carlos@616
    89
                                                           AND (v_warehouse_ID IS NULL OR MW1.M_WAREHOUSE_ID = TO_NUMBER(v_warehouse_ID))
antonio@737
    90
                                                           AND (v_org_ID IS NULL OR MW1.AD_ORG_ID = TO_NUMBER(v_org_ID))
carlos@616
    91
                                                           ) ) as PORCENTAJE,
carlos@629
    92
      MW.AD_ORG_ID,
carlos@629
    93
      MW.AD_CLIENT_ID,
carlos@616
    94
      PR.M_PRODUCT_ID
carlos@616
    95
     FROM
antonio@737
    96
     M_WAREHOUSE MW
carlos@616
    97
       LEFT JOIN M_LOCATOR ML ON ML.M_WAREHOUSE_ID=MW.M_WAREHOUSE_ID
carlos@616
    98
       LEFT JOIN M_STORAGE_DETAIL MSD ON ML.M_LOCATOR_ID=MSD.M_LOCATOR_ID
antonio@737
    99
       LEFT JOIN M_PRODUCT PR ON MSD.M_PRODUCT_ID=PR.M_PRODUCT_ID, AD_ORG
carlos@616
   100
     WHERE (v_warehouse_ID IS NULL OR MW.M_WAREHOUSE_ID = TO_NUMBER(v_warehouse_ID))
carlos@629
   101
       AND (v_org_ID IS NULL OR MW.AD_ORG_ID = TO_NUMBER(v_org_ID))
carlos@616
   102
       AND MSD.QTYONHAND>0
antonio@735
   103
       AND GET_PRODUCT_COST(PR.M_PRODUCT_ID,TO_DATE(now()),'AV') IS NOT NULL
antonio@735
   104
       AND GET_PRODUCT_COST(PR.M_PRODUCT_ID,TO_DATE(now()),'AV') <> 0
carlos@616
   105
       AND MSD.AD_ORG_ID = AD_ORG.AD_ORG_ID
antonio@737
   106
     GROUP BY AD_ORG.NAME ,PR.VALUE, PR.NAME, MW.AD_ORG_ID, MW.AD_CLIENT_ID, PR.M_PRODUCT_ID
carlos@616
   107
     ORDER BY PORCENTAJE DESC) BBB) loop
antonio@737
   108
antonio@737
   109
     SELECT COUNT(*)
antonio@737
   110
     INTO v_exist
carlos@616
   111
     FROM M_PRODUCT_ORG
carlos@616
   112
     WHERE M_PRODUCT_ID = Cur_Cursor.M_PRODUCT_ID
antonio@737
   113
     AND AD_ORG_ID = Cur_Cursor.AD_ORG_ID;
antonio@737
   114
carlos@616
   115
     IF (v_exist > 0) THEN
carlos@616
   116
       UPDATE M_PRODUCT_ORG SET
carlos@616
   117
       ABC = Cur_Cursor.ISABC
carlos@616
   118
       WHERE M_PRODUCT_ID = Cur_Cursor.M_PRODUCT_ID
antonio@737
   119
       AND AD_ORG_ID = Cur_Cursor.AD_ORG_ID;
carlos@616
   120
       v_count_update := v_count_update + 1;
carlos@616
   121
     ELSE
carlos@616
   122
       AD_Sequence_Next('M_Product_Org', Cur_Cursor.AD_CLIENT_ID, v_M_Product_Org_ID) ;
carlos@616
   123
       INSERT INTO M_PRODUCT_ORG (M_PRODUCT_ORG_ID, AD_CLIENT_ID, AD_ORG_ID, ISACTIVE, CREATED, CREATEDBY, UPDATED, UPDATEDBY, M_PRODUCT_ID, ABC) VALUES
juanpablo@1605
   124
       (v_M_Product_Org_ID, Cur_Cursor.AD_CLIENT_ID, Cur_Cursor.AD_ORG_ID, 'Y', now(), '100', now(), '100', Cur_Cursor.M_PRODUCT_ID, Cur_Cursor.ISABC);
carlos@616
   125
       v_count_insert := v_count_insert + 1;
carlos@616
   126
     END IF;
carlos@616
   127
carlos@616
   128
  end loop;
carlos@616
   129
  v_Message:='@Created@=' || v_count_insert || ', @Updated@=' || v_count_update;
carlos@616
   130
--<<FINISH_PROCESS>>
carlos@616
   131
    IF(p_PInstance_ID IS NOT NULL) THEN
carlos@616
   132
      --  Update AD_PInstance
carlos@616
   133
      DBMS_OUTPUT.PUT_LINE('Updating PInstance - Finished ' || v_Message) ;
carlos@616
   134
      AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', v_Result, v_Message) ;
carlos@616
   135
    ELSE
carlos@616
   136
      DBMS_OUTPUT.PUT_LINE('--<<M_UPDATE_PARETO_PRODUCT finished>>') ;
carlos@616
   137
    END IF;
carlos@616
   138
    RETURN;
carlos@616
   139
  END; --BODY
carlos@616
   140
EXCEPTION
carlos@616
   141
WHEN OTHERS THEN
carlos@616
   142
  v_ResultStr:= '@ERROR=' || SQLERRM;
carlos@616
   143
  DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
carlos@616
   144
  IF(p_PInstance_ID IS NOT NULL) THEN
carlos@616
   145
    ROLLBACK;
carlos@616
   146
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', 0, v_ResultStr) ;
carlos@616
   147
  ELSE
carlos@616
   148
    RAISE;
carlos@616
   149
  END IF;
carlos@616
   150
  RETURN;
antonio@735
   151
END M_UPDATE_PARETO_PRODUCT
antonio@735
   152
]]></body>
juanpablo@721
   153
    </function>
juanpablo@721
   154
  </database>