src-db/database/model/functions/FACT_ACCT_RESET.xml
author Juan Pablo Aroztegi <juanpablo.aroztegi@openbravo.com>
Wed, 03 Sep 2008 17:55:37 +0000
changeset 1605 8a0fe0193bef
parent 785 8dba91261590
child 1929 ad0353d93b0f
permissions -rw-r--r--
Merge r2.5x intro trunk
carlos@0
     1
<?xml version="1.0"?>
adrian@94
     2
  <database name="FUNCTION FACT_ACCT_RESET">
adrian@94
     3
    <function name="FACT_ACCT_RESET" type="NULL">
juanpablo@1605
     4
      <parameter name="p_pinstance_id" type="VARCHAR" mode="in">
antonio@735
     5
        <default/>
antonio@735
     6
      </parameter>
gorkaion@239
     7
      <body><![CDATA[/*************************************************************************
juanpablo@771
     8
  * The contents of this file are subject to the Compiere Public
juanpablo@771
     9
  * License 1.1 ("License"); You may not use this file except in
juanpablo@771
    10
  * compliance with the License. You may obtain a copy of the License in
juanpablo@771
    11
  * the legal folder of your Openbravo installation.
adrian@94
    12
  * Software distributed under the License is distributed on an
adrian@94
    13
  * "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either express or
adrian@94
    14
  * implied. See the License for the specific language governing rights
adrian@94
    15
  * and limitations under the License.
juanpablo@778
    16
  * The Original Code is  Compiere  ERP &  Business Solution
juanpablo@771
    17
  * The Initial Developer of the Original Code is Jorg Janke and ComPiere, Inc.
adrian@94
    18
  * Portions created by Jorg Janke are Copyright (C) 1999-2001 Jorg Janke,
adrian@94
    19
  * parts created by ComPiere are Copyright (C) ComPiere, Inc.;
adrian@94
    20
  * All Rights Reserved.
adrian@94
    21
  * Contributor(s): Openbravo SL
juanpablo@785
    22
  * Contributions are Copyright (C) 2001-2008 Openbravo, S.L.
juanpablo@771
    23
  *
juanpablo@771
    24
  * Specifically, this derivative work is based upon the following Compiere
juanpablo@771
    25
  * file and version.
adrian@94
    26
  *************************************************************************
adrian@94
    27
  * $Id: Fact_Acct_Reset.sql,v 1.4 2003/01/27 06:22:11 jjanke Exp $
adrian@94
    28
  ***
adrian@94
    29
  * Title: Reset Posting Records
adrian@94
    30
  * Description:
adrian@94
    31
  *   Delete Records in Fact_Acct or
adrian@94
    32
  *   Reset Posted
adrian@94
    33
  *   for AD_Client_ID and AD_Table_ID
adrian@94
    34
  ************************************************************************/
adrian@94
    35
  -- Logistice
adrian@94
    36
  v_ResultStr VARCHAR2(2000):='';
adrian@94
    37
  v_Message VARCHAR2(2000):='';
adrian@94
    38
  v_Result NUMBER:=1; -- 0=failure
juanpablo@1605
    39
  v_Record_ID VARCHAR2(32);
juanpablo@1605
    40
  v_AD_User_ID VARCHAR2(32);
adrian@94
    41
  v_DateColumn VARCHAR2(2000):='';
adrian@94
    42
  -- Parameter
adrian@94
    43
  TYPE RECORD IS REF CURSOR;
adrian@94
    44
    Cur_Parameter RECORD;
adrian@94
    45
    -- Parameter Variables
juanpablo@1605
    46
    v_AD_Client_ID VARCHAR2(32) ;
juanpablo@1605
    47
    v_AD_Table_ID VARCHAR2(32) ;
adrian@94
    48
    v_DeletePosting VARCHAR(1):='N';
adrian@94
    49
    --
adrian@94
    50
    v_Updated NUMBER(10):=0;
adrian@94
    51
    v_Deleted NUMBER(10):=0;
adrian@94
    52
    v_Cmd VARCHAR2(2000):='';
adrian@94
    53
    v_rowcount NUMBER;
adrian@94
    54
  BEGIN
adrian@94
    55
    --  Update AD_PInstance
adrian@94
    56
    DBMS_OUTPUT.PUT_LINE('Updating PInstance - Processing ' || p_PInstance_ID) ;
adrian@94
    57
    v_ResultStr:='PInstanceNotFound';
antonio@735
    58
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'Y', NULL, NULL) ;
adrian@94
    59
  BEGIN --BODY
adrian@94
    60
    -- Get Parameters
adrian@94
    61
    v_ResultStr:='ReadingParameters';
adrian@94
    62
    FOR Cur_Parameter IN
adrian@94
    63
      (SELECT i.Record_ID,
adrian@94
    64
        i.AD_User_ID,
adrian@94
    65
        p.ParameterName,
adrian@94
    66
        p.P_String,
adrian@94
    67
        p.P_Number,
adrian@94
    68
        p.P_Date
adrian@94
    69
      FROM AD_PINSTANCE i
adrian@94
    70
      LEFT JOIN AD_PINSTANCE_PARA p
adrian@94
    71
        ON i.AD_PInstance_ID=p.AD_PInstance_ID
adrian@94
    72
      WHERE i.AD_PInstance_ID=p_PInstance_ID
adrian@94
    73
      ORDER BY p.SeqNo
adrian@94
    74
      )
adrian@94
    75
    LOOP
adrian@94
    76
      v_Record_ID:=Cur_Parameter.Record_ID;
adrian@94
    77
      v_AD_User_ID:=Cur_Parameter.AD_User_ID;
adrian@94
    78
      IF(Cur_Parameter.ParameterName='AD_Client_ID') THEN
juanpablo@1605
    79
        v_AD_Client_ID:=Cur_Parameter.P_String;
adrian@94
    80
        DBMS_OUTPUT.PUT_LINE('  AD_Client_ID=' || v_AD_Client_ID) ;
adrian@94
    81
      ELSIF(Cur_Parameter.ParameterName='AD_Table_ID') THEN
juanpablo@1605
    82
        v_AD_Table_ID:=Cur_Parameter.P_String;
adrian@94
    83
        DBMS_OUTPUT.PUT_LINE('  AD_Table_ID=' || v_AD_Table_ID) ;
adrian@94
    84
      ELSIF(Cur_Parameter.ParameterName='DeletePosting') THEN
adrian@94
    85
        v_DeletePosting:=Cur_Parameter.P_String;
adrian@94
    86
        DBMS_OUTPUT.PUT_LINE('  DeletePosting=' || v_DeletePosting) ;
adrian@94
    87
      ELSE
adrian@94
    88
        DBMS_OUTPUT.PUT_LINE('*** Unknown Parameter=' || Cur_Parameter.ParameterName) ;
adrian@94
    89
      END IF;
adrian@94
    90
    END LOOP; -- Get Parameter
adrian@94
    91
    DBMS_OUTPUT.PUT_LINE('  Record_ID=' || v_Record_ID) ;
adrian@94
    92
    DECLARE
adrian@94
    93
    TYPE RECORD IS REF CURSOR;
adrian@94
    94
      Cur_Clients RECORD;
adrian@94
    95
      Cur_Tables RECORD;
adrian@94
    96
      Cur_Fact_Acct RECORD;
adrian@94
    97
    BEGIN
adrian@94
    98
      FOR Cur_Clients IN
adrian@94
    99
        (SELECT AD_Client_ID
adrian@94
   100
        FROM AD_CLIENT
adrian@94
   101
        WHERE(v_AD_Client_ID IS NULL
adrian@94
   102
          OR AD_Client_ID=v_AD_Client_ID)
juanpablo@1605
   103
          AND AD_Client_ID<>'0'
adrian@94
   104
        )
adrian@94
   105
      LOOP
adrian@94
   106
        FOR Cur_Tables IN
adrian@94
   107
          (SELECT DISTINCT t.AD_Table_ID,
adrian@94
   108
            t.TableName,
adrian@94
   109
            C_DOCTYPE.DOCBASETYPE
adrian@94
   110
          FROM AD_TABLE t,
adrian@94
   111
            C_DOCTYPE
adrian@94
   112
          WHERE t.AD_TABLE_ID=C_DOCTYPE.AD_TABLE_ID
adrian@94
   113
            AND(v_AD_Table_ID IS NULL
adrian@94
   114
            OR t.AD_Table_ID=v_AD_Table_ID)
adrian@94
   115
            AND EXISTS
adrian@94
   116
            (SELECT *
adrian@94
   117
            FROM AD_COLUMN c
adrian@94
   118
            WHERE t.AD_Table_ID=c.AD_Table_ID
adrian@94
   119
              AND c.ColumnName='Posted'
adrian@94
   120
            )
adrian@94
   121
            AND EXISTS
adrian@94
   122
            (SELECT *
adrian@94
   123
            FROM AD_COLUMN c
adrian@94
   124
            WHERE t.AD_Table_ID=c.AD_Table_ID
adrian@94
   125
              AND c.ColumnName='Processing'
adrian@94
   126
            )
adrian@94
   127
            AND t.IsView='N'
adrian@94
   128
          )
adrian@94
   129
        LOOP
adrian@94
   130
          DBMS_OUTPUT.PUT_LINE('AD_Client_ID=' || Cur_Clients.AD_Client_ID || ', AD_Table_ID=' || Cur_Tables.AD_Table_ID || ' ' || Cur_Tables.TableName) ;
adrian@94
   131
          -- Update Table
adrian@94
   132
          v_ResultStr:='ResetTable:' || Cur_Tables.TableName;
adrian@94
   133
          IF(v_DeletePosting='Y') THEN
adrian@94
   134
            FOR Cur_Fact_Acct IN (
adrian@94
   135
              SELECT Record_ID
adrian@94
   136
              FROM FACT_ACCT
adrian@94
   137
              WHERE AD_TABLE_ID=Cur_Tables.AD_Table_ID
adrian@94
   138
                AND NOT EXISTS
adrian@94
   139
                    (SELECT 1
adrian@94
   140
                    FROM C_YEAR, C_PERIOD, C_PERIODCONTROL, AD_CLIENTINFO, FACT_ACCT fa_aux
adrian@94
   141
                    WHERE C_YEAR.c_year_id=C_PERIOD.c_year_id
adrian@94
   142
                      AND C_PERIOD.c_period_id=C_PERIODCONTROL.c_period_id
adrian@94
   143
                      AND C_YEAR.c_calendar_id=AD_CLIENTINFO.c_calendar_id
adrian@94
   144
                      AND AD_CLIENTINFO.ad_client_id=fa_aux.AD_CLIENT_ID
adrian@94
   145
                      AND C_PERIODCONTROL.docbasetype=fa_aux.DOCBASETYPE
gorkaion@239
   146
                      AND C_PERIODCONTROL.periodstatus<>'O'
gorkaion@239
   147
                      AND fa_aux.DATEACCT>=C_PERIOD.StartDate
gorkaion@239
   148
                      AND fa_aux.DATEACCT<C_PERIOD.EndDate + 1
adrian@94
   149
                      AND fa_aux.AD_TABLE_ID = FACT_ACCT.AD_TABLE_ID
adrian@94
   150
                      AND fa_aux.RECORD_ID = FACT_ACCT.RECORD_ID
adrian@94
   151
                    )
adrian@94
   152
                AND Record_ID=(
juanpablo@1605
   153
                      CASE COALESCE(v_Record_ID, '0') WHEN '0' THEN Record_ID ELSE v_Record_ID
adrian@94
   154
                      END)
adrian@94
   155
                AND AD_Client_ID = Cur_Clients.AD_Client_ID
adrian@94
   156
              ) LOOP
juanpablo@1605
   157
              IF(Cur_Tables.AD_Table_ID IN('472', '473')) THEN
adrian@94
   158
                v_DateColumn:='DATETRX';
juanpablo@1605
   159
              ELSIF(Cur_Tables.AD_Table_ID IN('392')) THEN
adrian@94
   160
                v_DateColumn:='STATEMENTDATE';
juanpablo@1605
   161
              ELSIF(Cur_Tables.AD_Table_ID IN('321', '323', '325')) THEN
adrian@94
   162
                v_DateColumn:='MOVEMENTDATE';
adrian@94
   163
              ELSE
adrian@94
   164
                v_DateColumn:='DATEACCT';
adrian@94
   165
              END IF;
juanpablo@1605
   166
              v_Cmd:='UPDATE ' || Cur_Tables.TableName  || ' SET Posted=''N'', Processing=''N'' WHERE AD_Client_ID='''  || Cur_Clients.AD_Client_ID
juanpablo@1605
   167
        || ''' AND (Posted<>''N'' OR Posted IS NULL OR Processing<>''N'' OR Processing IS NULL) AND '   ||
juanpablo@1605
   168
        Cur_Tables.TableName||'_ID = '''||Cur_Fact_Acct.Record_ID||'''';
adrian@94
   169
              -- DBMS_OUTPUT.PUT_LINE('  executing: ' || v_Cmd);
adrian@94
   170
              EXECUTE IMMEDIATE v_Cmd;
adrian@94
   171
              v_rowcount:=SQL%ROWCOUNT;
adrian@94
   172
              v_Updated:=v_Updated + v_rowcount;
adrian@94
   173
              DBMS_OUTPUT.PUT_LINE('  updated=' || v_rowcount) ;
adrian@94
   174
              -- Delete Fact
adrian@94
   175
              v_ResultStr:='DeleteFact';
adrian@94
   176
        DELETE --Deleting complete entries related to the document
ben@486
   177
           FROM FACT_ACCT_CFS
ben@486
   178
           WHERE FACT_ACCT_CFS_ID IN (
ben@486
   179
		        SELECT FACT_ACCT_CFS_ID
ben@486
   180
		        FROM FACT_ACCT_CFS CFS1
ben@486
   181
		        INNER JOIN FACT_ACCT ON
ben@486
   182
			             FACT_ACCT.FACT_ACCT_ID = CFS1.FACT_ACCT_REF_ID
ben@486
   183
			             AND AD_TABLE_ID=Cur_Tables.AD_Table_ID
adrian@94
   184
                         AND Record_ID=Cur_Fact_Acct.Record_ID
ben@486
   185
                         AND FACT_ACCT.AD_Client_ID = Cur_Clients.AD_Client_ID
ben@486
   186
	        );
ben@486
   187
        DELETE
adrian@94
   188
              FROM FACT_ACCT
adrian@94
   189
              WHERE AD_TABLE_ID=Cur_Tables.AD_Table_ID
adrian@94
   190
                AND Record_ID=Cur_Fact_Acct.Record_ID
adrian@94
   191
                AND AD_Client_ID = Cur_Clients.AD_Client_ID;
adrian@94
   192
adrian@94
   193
              v_rowcount:=SQL%ROWCOUNT;
adrian@94
   194
              v_Deleted:=v_Deleted + v_rowcount;
adrian@94
   195
              DBMS_OUTPUT.PUT_LINE('  deleted=' || v_rowcount) ;
adrian@94
   196
            END LOOP;
juanpablo@1605
   197
        v_Cmd:='UPDATE ' || Cur_Tables.TableName  || ' SET Posted=''N'', Processing=''N'' WHERE AD_Client_ID='''  || Cur_Clients.AD_Client_ID
juanpablo@1605
   198
        || ''' AND (Posted=''Y'' OR Processing<>''N'' OR Processing IS NULL) AND NOT EXISTS (SELECT 1 FROM FACT_ACCT WHERE AD_TABLE_ID =''' || Cur_Tables.AD_Table_ID ||
juanpablo@1605
   199
        ''' AND RECORD_ID = ' || Cur_Tables.TableName || '_ID AND AD_CLIENT_ID =''' || Cur_Clients.AD_Client_ID || ''' )';
adrian@94
   200
            -- DBMS_OUTPUT.PUT_LINE('  executing: ' || v_Cmd);
adrian@94
   201
            EXECUTE IMMEDIATE v_Cmd;
adrian@94
   202
            v_rowcount:=SQL%ROWCOUNT;
adrian@94
   203
            v_Updated:=v_Updated + v_rowcount;
adrian@94
   204
            DBMS_OUTPUT.PUT_LINE('  updated=' || v_rowcount) ;
adrian@94
   205
          ELSE
juanpablo@1605
   206
            v_Cmd:='UPDATE ' || Cur_Tables.TableName  || ' SET Processing=''N'' WHERE AD_Client_ID='''  || Cur_Clients.AD_Client_ID  || ''' AND Processing<>''N'' OR Processing IS NULL';
adrian@94
   207
            EXECUTE IMMEDIATE v_Cmd;
adrian@94
   208
            v_rowcount:=SQL%ROWCOUNT;
adrian@94
   209
            v_Updated:=v_Updated + v_rowcount;
adrian@94
   210
            DBMS_OUTPUT.PUT_LINE('  unlocked=' || v_rowcount) ;
juanpablo@1605
   211
            v_Cmd:='UPDATE ' || Cur_Tables.TableName  || ' SET Posted=''N'' WHERE AD_Client_ID='''  || Cur_Clients.AD_Client_ID  || ''' AND Posted NOT IN (''Y'',''N'') AND Processed=''Y''';
adrian@94
   212
            EXECUTE IMMEDIATE v_Cmd;
adrian@94
   213
            v_rowcount:=SQL%ROWCOUNT;
adrian@94
   214
            v_Updated:=v_Updated + v_rowcount;
adrian@94
   215
            DBMS_OUTPUT.PUT_LINE('  updated=' || v_rowcount) ;
adrian@94
   216
          END IF;
adrian@94
   217
        END LOOP;
adrian@94
   218
      END LOOP;
adrian@94
   219
    END;
adrian@94
   220
    -- Summary info
adrian@94
   221
    v_Message:='@Updated@ = ' || v_Updated || ', @Deleted@ = ' || v_Deleted;
gorkaion@239
   222
    --<<FINISH_PROCESS>>
adrian@94
   223
    --  Update AD_PInstance
adrian@94
   224
    DBMS_OUTPUT.PUT_LINE('Updating PInstance - Finished ' || v_Message) ;
antonio@735
   225
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', v_Result, v_Message) ;
adrian@94
   226
    RETURN;
adrian@94
   227
  END; --BODY
adrian@94
   228
EXCEPTION
adrian@94
   229
WHEN OTHERS THEN
adrian@94
   230
  v_ResultStr:= '@ERROR=' || SQLERRM;
adrian@94
   231
  DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
adrian@94
   232
  ROLLBACK;
antonio@735
   233
  AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', 0, v_ResultStr) ;
adrian@94
   234
  RETURN;
antonio@735
   235
END FACT_ACCT_RESET
gorkaion@239
   236
]]></body>
adrian@94
   237
    </function>
adrian@94
   238
  </database>