From 90accc91fbb7c8c68133dbdf736c1ccbf72ab14a Mon Sep 17 00:00:00 2001 From: teo_sarca Date: Thu, 30 Apr 2009 06:27:01 +0000 Subject: [PATCH] FR [ 2783860 ] DBA_Cleanup should clean all temporary tables https://sourceforge.net/tracker/?func=detail&atid=879335&aid=2783860&group_id=176962 * delete AD_Find records ONLY after a week * delete processed AD_Notes ONLY after a week --- db/ddlutils/oracle/procedures/DBA_Cleanup.sql | 16 +++- migration/353a-trunk/oracle/457_FR2783860.sql | 86 +++++++++++++++++++ .../353a-trunk/postgresql/457_FR2783860.sql | 1 + 3 files changed, 99 insertions(+), 4 deletions(-) create mode 100644 migration/353a-trunk/oracle/457_FR2783860.sql create mode 100644 migration/353a-trunk/postgresql/457_FR2783860.sql diff --git a/db/ddlutils/oracle/procedures/DBA_Cleanup.sql b/db/ddlutils/oracle/procedures/DBA_Cleanup.sql index 18956e8f54..d560d89eac 100644 --- a/db/ddlutils/oracle/procedures/DBA_Cleanup.sql +++ b/db/ddlutils/oracle/procedures/DBA_Cleanup.sql @@ -10,6 +10,9 @@ CREATE OR REPLACE PROCEDURE DBA_Cleanup *** * Title: Cleanup old temporary data * Description: + * + * Author: Teo Sarca, www.arhipac.ro + * * Autodetect temporary tables and delete rows that are older then 7 days ************************************************************************/ AS BEGIN @@ -28,17 +31,22 @@ BEGIN -- Temporary Tables FOR t IN (SELECT t.TableName FROM AD_Table t WHERE t.TableName like 'T!_%' ESCAPE '!' + AND t.IsView='N' AND EXISTS (SELECT 1 FROM user_tables ut WHERE UPPER(ut.table_name)=UPPER(t.TableName)) + AND EXISTS (SELECT 1 FROM user_tab_cols uc WHERE UPPER(uc.table_name)=UPPER(t.TableName) AND uc.column_name='AD_PINSTANCE_ID') ORDER BY t.TableName) LOOP - EXECUTE IMMEDIATE 'DELETE FROM '||t.TableName; + EXECUTE IMMEDIATE + 'DELETE FROM '||t.TableName||' t' + ||' WHERE EXISTS (SELECT 1 FROM AD_PInstance pi WHERE pi.AD_PInstance_ID=t.AD_PInstance_ID AND Created < SysDate-7)' + ; IF (SQL%ROWCOUNT <> 0) THEN DBMS_OUTPUT.PUT_LINE(' '||t.TableName||'=' || SQL%ROWCOUNT); END IF; END LOOP; -- Search Info - DELETE FROM AD_Find; + DELETE FROM AD_Find WHERE Created < SysDate-7; IF (SQL%ROWCOUNT <> 0) THEN DBMS_OUTPUT.PUT_LINE(' AD_Find=' || SQL%ROWCOUNT); END IF; @@ -66,8 +74,8 @@ BEGIN DBMS_OUTPUT.PUT_LINE(' Old AD_Error=' || SQL%ROWCOUNT); END IF; - -- Acknowledged Notes older than a day - DELETE FROM AD_Note WHERE Processed='Y' AND Updated < SysDate-1; + -- Acknowledged Notes older than one week + DELETE FROM AD_Note WHERE Processed='Y' AND Updated < SysDate-7; IF (SQL%ROWCOUNT <> 0) THEN DBMS_OUTPUT.PUT_LINE(' Processed AD_Note=' || SQL%ROWCOUNT); END IF; diff --git a/migration/353a-trunk/oracle/457_FR2783860.sql b/migration/353a-trunk/oracle/457_FR2783860.sql new file mode 100644 index 0000000000..d560d89eac --- /dev/null +++ b/migration/353a-trunk/oracle/457_FR2783860.sql @@ -0,0 +1,86 @@ +CREATE OR REPLACE PROCEDURE DBA_Cleanup +/************************************************************************* + * The contents of this file are subject to the Adempiere License. You may + * obtain a copy of the License at http://www.adempiere.org/license.html + * Software is on an "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either + * express or implied. See the License for details. Code: Adempiere ERP+CRM + * Copyright (C) 1999-2001 Jorg Janke, ComPiere, Inc. All Rights Reserved. + ************************************************************************* + * $Id: DBA_Cleanup.sql,v 1.1 2006/04/21 17:51:58 jjanke Exp $ + *** + * Title: Cleanup old temporary data + * Description: + * + * Author: Teo Sarca, www.arhipac.ro + * * Autodetect temporary tables and delete rows that are older then 7 days + ************************************************************************/ +AS +BEGIN + DBMS_OUTPUT.PUT_LINE('DBA_Cleanup'); + -- Clean up data + /** +-- C_Invoice_CheckPaid(); + UPDATE C_Payment_v + SET IsAllocated=CASE WHEN paymentAllocated(C_Payment_ID, C_Currency_ID)=PayAmt THEN 'Y' ELSE 'N' END + WHERE IsAllocated='N'; + UPDATE C_Invoice_v1 + SET IsPaid = CASE WHEN invoicePaid(C_Invoice_ID,C_Currency_ID,MultiplierAP)=GrandTotal THEN 'Y' ELSE 'N' END + WHERE IsPaid='N'; + **/ + + -- Temporary Tables + FOR t IN (SELECT t.TableName FROM AD_Table t + WHERE t.TableName like 'T!_%' ESCAPE '!' + AND t.IsView='N' + AND EXISTS (SELECT 1 FROM user_tables ut WHERE UPPER(ut.table_name)=UPPER(t.TableName)) + AND EXISTS (SELECT 1 FROM user_tab_cols uc WHERE UPPER(uc.table_name)=UPPER(t.TableName) AND uc.column_name='AD_PINSTANCE_ID') + ORDER BY t.TableName) + LOOP + EXECUTE IMMEDIATE + 'DELETE FROM '||t.TableName||' t' + ||' WHERE EXISTS (SELECT 1 FROM AD_PInstance pi WHERE pi.AD_PInstance_ID=t.AD_PInstance_ID AND Created < SysDate-7)' + ; + IF (SQL%ROWCOUNT <> 0) THEN + DBMS_OUTPUT.PUT_LINE(' '||t.TableName||'=' || SQL%ROWCOUNT); + END IF; + END LOOP; + + -- Search Info + DELETE FROM AD_Find WHERE Created < SysDate-7; + IF (SQL%ROWCOUNT <> 0) THEN + DBMS_OUTPUT.PUT_LINE(' AD_Find=' || SQL%ROWCOUNT); + END IF; + + -- Processes older than a week + DELETE FROM AD_PInstance WHERE Created < SysDate-7; + IF (SQL%ROWCOUNT <> 0) THEN + DBMS_OUTPUT.PUT_LINE(' Old AD_PInstance=' || SQL%ROWCOUNT); + END IF; + + /** Old Session (1 Week) + DELETE FROM AD_ChangeLog WHERE Created < SysDate-7; + IF (SQL%ROWCOUNT <> 0) THEN + DBMS_OUTPUT.PUT_LINE(' Old AD_ChangeLock=' || SQL%ROWCOUNT); + END IF; + DELETE FROM AD_Session WHERE Created < SysDate-7; + IF (SQL%ROWCOUNT <> 0) THEN + DBMS_OUTPUT.PUT_LINE(' Old AD_Session=' || SQL%ROWCOUNT); + END IF; + /** */ + + -- Errors older than 1 week + DELETE FROM AD_Error WHERE Created < SysDate-7; + IF (SQL%ROWCOUNT <> 0) THEN + DBMS_OUTPUT.PUT_LINE(' Old AD_Error=' || SQL%ROWCOUNT); + END IF; + + -- Acknowledged Notes older than one week + DELETE FROM AD_Note WHERE Processed='Y' AND Updated < SysDate-7; + IF (SQL%ROWCOUNT <> 0) THEN + DBMS_OUTPUT.PUT_LINE(' Processed AD_Note=' || SQL%ROWCOUNT); + END IF; + + -- + COMMIT; +END DBA_Cleanup; +/ diff --git a/migration/353a-trunk/postgresql/457_FR2783860.sql b/migration/353a-trunk/postgresql/457_FR2783860.sql new file mode 100644 index 0000000000..16843ce809 --- /dev/null +++ b/migration/353a-trunk/postgresql/457_FR2783860.sql @@ -0,0 +1 @@ +-- oracle specific \ No newline at end of file