src-db/database/model/functions/AD_TABLE_IMPORT.xml
author Asier Lostalé <asier.lostale@openbravo.com>
Mon, 26 May 2008 11:24:39 +0000
changeset 1027 2e9052d7de0e
parent 799 fef2c5e2feb7
child 1605 8a0fe0193bef
permissions -rw-r--r--
fixed bug 0000399: Remove insertions in AD_PInstance_Log table
carlos@0
     1
<?xml version="1.0"?>
adrian@94
     2
  <database name="FUNCTION AD_TABLE_IMPORT">
adrian@94
     3
    <function name="AD_TABLE_IMPORT" type="NULL">
antonio@735
     4
      <parameter name="p_pinstance_id" type="NUMERIC" mode="in">
antonio@735
     5
        <default/>
antonio@735
     6
      </parameter>
antonio@735
     7
      <parameter name="p_ad_table_id" type="NUMERIC" mode="in">
antonio@735
     8
        <default/>
antonio@735
     9
      </parameter>
gorkaion@239
    10
      <body><![CDATA[/*************************************************************************
juanpablo@771
    11
  * The contents of this file are subject to the Compiere Public
juanpablo@771
    12
  * License 1.1 ("License"); You may not use this file except in
juanpablo@771
    13
  * compliance with the License. You may obtain a copy of the License in
juanpablo@771
    14
  * the legal folder of your Openbravo installation.
carlos@0
    15
  * Software distributed under the License is distributed on an
carlos@0
    16
  * "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either express or
carlos@0
    17
  * implied. See the License for the specific language governing rights
carlos@0
    18
  * and limitations under the License.
juanpablo@778
    19
  * The Original Code is  Compiere  ERP &  Business Solution
juanpablo@771
    20
  * The Initial Developer of the Original Code is Jorg Janke and ComPiere, Inc.
carlos@0
    21
  * Portions created by Jorg Janke are Copyright (C) 1999-2001 Jorg Janke,
carlos@0
    22
  * parts created by ComPiere are Copyright (C) ComPiere, Inc.;
carlos@0
    23
  * All Rights Reserved.
carlos@0
    24
  * Contributor(s): Openbravo SL
juanpablo@785
    25
  * Contributions are Copyright (C) 2001-2008 Openbravo, S.L.
juanpablo@771
    26
  *
juanpablo@771
    27
  * Specifically, this derivative work is based upon the following Compiere
juanpablo@771
    28
  * file and version.
carlos@0
    29
  *************************************************************************
carlos@0
    30
  * $Id: AD_Table_Import.sql,v 1.8 2003/01/18 05:34:25 jjanke Exp $
carlos@0
    31
  ***
carlos@0
    32
  * Title: Import Table Column Definition
carlos@0
    33
  * Description:
carlos@0
    34
  *   Create Columns of Table not existing as a Dictionary Column
carlos@0
    35
  ************************************************************************/
carlos@0
    36
  -- Logistice
carlos@0
    37
  v_ResultStr VARCHAR2(2000):='';
carlos@0
    38
  v_Message VARCHAR2(2000):='';
carlos@0
    39
  v_Result NUMBER:=1; -- 0=failure
carlos@0
    40
  v_Record_ID NUMBER;
carlos@0
    41
  v_AD_User_ID NUMBER:=0;
carlos@0
    42
  -- Parameter
carlos@0
    43
  TYPE RECORD IS REF CURSOR;
carlos@0
    44
    Cur_Parameter RECORD;
carlos@0
    45
    -- Parameter Variables
carlos@0
    46
    --
carlos@0
    47
    Cur_Column RECORD;
carlos@0
    48
    --
carlos@0
    49
    v_NextNo NUMBER(10) ;
carlos@0
    50
    v_count NUMBER(10):=0;
carlos@0
    51
    -- Added by Ismael Ciordia
carlos@0
    52
    v_AD_Reference_ID NUMBER;
carlos@0
    53
    v_AD_Reference_Value_ID NUMBER;
carlos@0
    54
    v_AD_Val_Rule_ID NUMBER;
carlos@0
    55
    v_IsParent CHAR(1):='N';
carlos@0
    56
    v_IsKey CHAR(1):='N';
carlos@0
    57
    v_IsIdentifier CHAR(1):='N';
carlos@0
    58
    v_IsSessionAttr CHAR(1):='N';
carlos@0
    59
    v_IsUpdateable CHAR(1):='Y';
carlos@0
    60
    v_DefaultValue NVARCHAR2(2000):='';
carlos@0
    61
    v_SeqNo NUMBER(10) ;
carlos@0
    62
    v_columnName VARCHAR2(40) ;
carlos@0
    63
    v_LastColumnName VARCHAR2(40) ;
carlos@0
    64
    v_varchar2 VARCHAR2(32767) ;
carlos@0
    65
    v_FieldLength NUMBER(10) ;
asier@799
    66
    v_PInstance_Log_ID NUMBER;
asier@799
    67
    v_Client_ID NUMBER;
carlos@0
    68
  BEGIN
carlos@0
    69
    IF(p_PInstance_ID IS NOT NULL) THEN
carlos@0
    70
      --  Update AD_PInstance
carlos@0
    71
      DBMS_OUTPUT.PUT_LINE('Updating PInstance - Processing ' || p_PInstance_ID) ;
carlos@0
    72
      v_ResultStr:='PInstanceNotFound';
carlos@0
    73
      AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'Y', NULL, NULL) ;
carlos@0
    74
      -- Get Parameters
carlos@0
    75
      v_ResultStr:='ReadingParameters';
carlos@0
    76
      FOR Cur_Parameter IN
asier@799
    77
        (SELECT i.Record_ID, i.AD_User_ID, p.ParameterName, p.P_String, p.P_Number, p.P_Date, p.AD_CLIENT_ID
carlos@0
    78
        FROM AD_PInstance i
carlos@0
    79
        LEFT JOIN AD_PInstance_Para p
carlos@0
    80
          ON i.AD_PInstance_ID=p.AD_PInstance_ID
carlos@0
    81
        WHERE i.AD_PInstance_ID=p_PInstance_ID
carlos@0
    82
        ORDER BY p.SeqNo
carlos@0
    83
        )
carlos@0
    84
      LOOP
carlos@0
    85
        v_Record_ID:=Cur_Parameter.Record_ID;
carlos@0
    86
        v_AD_User_ID:=Cur_Parameter.AD_User_ID;
asier@799
    87
        v_Client_ID:=Cur_Parameter.AD_CLIENT_ID;
carlos@0
    88
      END LOOP; -- Get Parameter
carlos@0
    89
    ELSE
carlos@0
    90
      v_Record_ID:=p_AD_Table_ID;
carlos@0
    91
    END IF;
carlos@0
    92
    DBMS_OUTPUT.PUT_LINE('  Record_ID=' || v_Record_ID) ;
carlos@0
    93
  BEGIN --BODY
carlos@0
    94
    IF(v_Record_ID IS NOT NULL) THEN
carlos@0
    95
      SELECT COALESCE(MAX(SeqNo), 0) + 10
carlos@0
    96
      INTO v_SeqNo
carlos@0
    97
      FROM AD_Column
carlos@0
    98
      WHERE AD_Table_ID=v_Record_ID;
carlos@0
    99
    ELSE
carlos@0
   100
      v_SeqNo:=0;
carlos@0
   101
    END IF;
carlos@0
   102
    FOR Cur_Column IN
carlos@0
   103
      (SELECT Column_Name, Data_Type, Data_Length, Nullable, AD_Table_ID, -- added by Ismael Ciordia
asier@799
   104
        uc.DATA_PRECISION, uc.DATA_SCALE, DATA_DEFAULT, Table_Name
carlos@0
   105
      FROM User_Tab_Columns uc, AD_Table t
carlos@0
   106
      WHERE uc.Table_Name=UPPER(t.TableName) AND NOT EXISTS
carlos@0
   107
        (SELECT *
carlos@0
   108
        FROM AD_Table t, AD_Column c
carlos@0
   109
        WHERE t.AD_Table_ID=c.AD_Table_ID  AND uc.Table_Name=UPPER(t.TableName) AND uc.Column_Name=UPPER(c.ColumnName)
carlos@0
   110
        )
carlos@0
   111
        AND(v_Record_ID=t.AD_Table_ID OR v_Record_ID IS NULL) -- added by Ismael Ciordia
carlos@0
   112
      ORDER BY uc.COLUMN_ID
carlos@0
   113
      )
carlos@0
   114
    LOOP
carlos@0
   115
      AD_Sequence_Next('AD_Column', 0, v_NextNo) ; -- get ID
carlos@0
   116
      -- Added by Ismael Ciordia
carlos@0
   117
      v_AD_Reference_ID:=NULL;
carlos@0
   118
      v_AD_Reference_Value_ID:=NULL;
carlos@0
   119
      v_AD_Val_Rule_ID:=NULL;
carlos@0
   120
      v_IsParent:='N';
carlos@0
   121
      v_IsKey:='N';
carlos@0
   122
      v_IsIdentifier:='N';
carlos@0
   123
      v_IsSessionAttr:='N';
carlos@0
   124
      v_IsUpdateable:='Y';
carlos@0
   125
      v_varchar2:=Cur_Column.DATA_DEFAULT;
carlos@0
   126
      v_varchar2:=SUBSTR(v_varchar2, 1, 2000) ;
gorkaion@239
   127
      IF(INSTR(v_varchar2, '''')<>0) THEN
carlos@0
   128
        v_varchar2:=SUBSTR(SUBSTR(v_varchar2, 2, 1999), 1, INSTR(SUBSTR(v_varchar2, 2, 1999), '''') -1) ;
carlos@0
   129
      ELSE
carlos@285
   130
        v_varchar2:=TRIM(REPLACE(REPLACE(v_varchar2, REPLACE('now ()',' ',''), '@#Date@'), CHR(10), '')) ;
carlos@0
   131
      END IF;
carlos@0
   132
      v_DefaultValue:=v_varchar2;
carlos@0
   133
      IF(UPPER(Cur_Column.Column_Name)=UPPER(Cur_Column.Table_Name) ||'_ID') THEN --ID column
carlos@0
   134
        v_AD_Reference_ID:=13;
carlos@0
   135
        v_IsKey:='Y';
carlos@0
   136
        v_IsUpdateable:='N';
carlos@0
   137
      ELSIF(UPPER(Cur_Column.Column_Name) IN('AD_CLIENT_ID', 'AD_ORG_ID')) THEN
carlos@0
   138
        v_AD_Reference_ID:=19;
carlos@0
   139
        v_DefaultValue:='@'||Cur_Column.Column_Name||'@';
carlos@0
   140
        v_IsUpdateable:='N';
carlos@0
   141
        v_IsSessionAttr:='Y';
carlos@0
   142
        IF(UPPER(Cur_Column.Column_Name)='AD_CLIENT_ID') THEN
carlos@0
   143
          v_AD_Val_Rule_ID:=103;
carlos@0
   144
        ELSE
carlos@0
   145
          v_AD_Val_Rule_ID:=104;
carlos@0
   146
        END IF;
carlos@0
   147
      ELSIF(UPPER(Cur_Column.Column_Name) IN('UPDATED', 'CREATED')) THEN
carlos@0
   148
        v_AD_Reference_ID:=16;
carlos@0
   149
        v_IsUpdateable:='N';
carlos@0
   150
      ELSIF(UPPER(Cur_Column.Column_Name) IN('UPDATEDBY', 'CREATEDBY')) THEN
carlos@0
   151
        v_AD_Reference_ID:=18;
carlos@0
   152
        v_AD_Reference_Value_ID:=110;
carlos@0
   153
        v_IsUpdateable:='N';
carlos@0
   154
      ELSIF(UPPER(Cur_Column.Column_Name) IN('NAME')) THEN
carlos@0
   155
        v_IsIdentifier:='Y';
carlos@0
   156
      ELSIF(UPPER(Cur_Column.Column_Name) IN('M_PRODUCT_ID', 'C_BPARTNER_ID')) THEN
carlos@0
   157
        v_AD_Reference_ID:=30;
carlos@0
   158
      ELSIF(UPPER(Cur_Column.Column_Name) IN('M_ATTRIBUTESETINSTANCE_ID')) THEN
carlos@0
   159
        v_AD_Reference_ID:=35;
carlos@0
   160
      ELSIF(UPPER(Cur_Column.Column_Name) LIKE '%_LOCATION_ID') THEN
carlos@0
   161
        v_AD_Reference_ID:=21;
carlos@0
   162
      ELSIF(UPPER(Cur_Column.Column_Name) LIKE '%_LOCATOR%_ID') THEN
carlos@0
   163
        v_AD_Reference_ID:=31;
carlos@0
   164
      ELSIF(UPPER(Cur_Column.Column_Name) LIKE '%_ACCT') THEN
carlos@0
   165
        v_AD_Reference_ID:=25;
carlos@0
   166
      ELSIF(UPPER(Cur_Column.Column_Name) LIKE '%_ID') THEN
carlos@0
   167
        v_AD_Reference_ID:=19;
carlos@0
   168
      ELSIF(UPPER(Cur_Column.Column_Name) IN('LINE', 'SEQNO')) THEN
carlos@0
   169
        v_DefaultValue:='@SQL=SELECT COALESCE(MAX('||Cur_Column.Column_Name||'),0)+10 AS DefaultValue FROM '||Cur_Column.Table_Name||' WHERE xxParentColumn=@xxParentColumn@';
carlos@0
   170
      END IF;
carlos@0
   171
      IF(UPPER(v_LastColumnName)='UPDATEDBY' AND UPPER(Cur_Column.Column_Name) LIKE '%_ID') THEN
carlos@0
   172
        v_IsParent:='Y';
carlos@0
   173
        v_IsUpdateable:='N';
carlos@0
   174
      END IF;
carlos@0
   175
      --added by Pablo Sarobe
carlos@0
   176
      IF(Cur_Column.Data_Type IN('VARCHAR2', 'CHAR')) THEN
carlos@0
   177
        v_FieldLength:=Cur_Column.Data_Length;
carlos@0
   178
      ELSIF(Cur_Column.Data_Type IN('NVARCHAR2', 'NCHAR')) THEN
carlos@0
   179
        v_FieldLength:=Cur_Column.Data_Length/2;
carlos@0
   180
      ELSIF(Cur_Column.Data_Type IN('DATE')) THEN
carlos@0
   181
        v_FieldLength:=19;
carlos@0
   182
      ELSIF(Cur_Column.Data_Type IN('NUMBER')) THEN
carlos@0
   183
        v_FieldLength:=COALESCE(Cur_Column.Data_Precision, 10) +2;
carlos@0
   184
      ELSE
carlos@0
   185
        v_FieldLength:=Cur_Column.Data_Length;
carlos@0
   186
      END IF;
carlos@0
   187
      IF(v_AD_Reference_ID IS NULL) THEN
carlos@285
   188
        IF(Cur_Column.Data_Type IN('CHAR','BPCHAR') AND Cur_Column.Data_Length=1) THEN
carlos@0
   189
          v_AD_Reference_ID:=20;
carlos@0
   190
        ELSIF(Cur_Column.Data_Type IN('VARCHAR2', 'NVARCHAR2', 'CHAR', 'NCHAR') AND Cur_Column.Data_Length=4000) THEN
carlos@0
   191
          v_AD_Reference_ID:=14;
carlos@0
   192
        ELSIF(Cur_Column.Data_Type IN('VARCHAR2', 'NVARCHAR2', 'CHAR', 'NCHAR')) THEN
carlos@0
   193
          v_AD_Reference_ID:=10;
carlos@0
   194
        ELSIF(Cur_Column.Data_Type IN('VARCHAR2', 'NVARCHAR2', 'CHAR', 'NCHAR')) THEN
carlos@0
   195
          v_AD_Reference_ID:=10;
carlos@0
   196
        ELSIF(Cur_Column.Data_Type='NUMBER' AND Cur_Column.DATA_SCALE=0) THEN
carlos@0
   197
          v_AD_Reference_ID:=11;
carlos@0
   198
        ELSIF(Cur_Column.Data_Type='NUMBER' AND UPPER(Cur_Column.Column_Name) LIKE '%AMT%') THEN
carlos@0
   199
          v_AD_Reference_ID:=12;
carlos@0
   200
        ELSIF(Cur_Column.Data_Type='NUMBER' AND UPPER(Cur_Column.Column_Name) LIKE '%QTY%') THEN
carlos@0
   201
          v_AD_Reference_ID:=29;
carlos@0
   202
        ELSIF(Cur_Column.Data_Type='NUMBER') THEN
carlos@0
   203
          v_AD_Reference_ID:=22;
carlos@0
   204
        ELSIF(Cur_Column.Data_Type='DATE') THEN
carlos@0
   205
          v_AD_Reference_ID:=15;
carlos@0
   206
        ELSE
carlos@0
   207
          v_AD_Reference_ID:=10; -- if not found, use String
carlos@0
   208
        END IF;
carlos@0
   209
      END IF;
carlos@0
   210
      v_columnName:=InitCap(Cur_Column.Column_Name) ;
gorkaion@239
   211
      IF(INSTR(v_columnName, '_')<>0 AND INSTR(v_columnName, '_')<5) THEN
carlos@0
   212
        v_columnName:=UPPER(SUBSTR(v_columnName, 1, INSTR(v_columnName, '_'))) ||SUBSTR(v_columnName, INSTR(v_columnName, '_') +1, 40) ;
carlos@0
   213
      END IF;
carlos@0
   214
      IF(v_columnName LIKE '%_Id') THEN
carlos@0
   215
        v_columnName:=SUBSTR(v_columnName, 1, LENGTH(v_columnName) -3) ||'_ID';
carlos@0
   216
      END IF;
carlos@0
   217
      INSERT
carlos@0
   218
      INTO AD_COLUMN
carlos@0
   219
        (
carlos@0
   220
          AD_COLUMN_ID, AD_CLIENT_ID, AD_ORG_ID, ISACTIVE,
carlos@0
   221
          CREATED, CREATEDBY, UPDATED, UPDATEDBY,
asier@799
   222
          NAME, COLUMNNAME, AD_TABLE_ID,
carlos@0
   223
          AD_REFERENCE_ID, FIELDLENGTH, ISKEY, ISPARENT,
carlos@0
   224
          ISMANDATORY, ISIDENTIFIER, SEQNO, ISTRANSLATED,
asier@799
   225
          ISENCRYPTED, ISUPDATEABLE, AD_REFERENCE_VALUE_ID,
carlos@0
   226
          AD_VAL_RULE_ID, DEFAULTVALUE, ISSESSIONATTR
carlos@0
   227
        )
carlos@0
   228
        VALUES
carlos@0
   229
        (v_NextNo, 0, 0, 'Y',
carlos@0
   230
        now(), 0, now(), 0,
asier@799
   231
        v_columnName, v_columnName, Cur_Column.AD_Table_ID,
carlos@0
   232
        v_AD_Reference_ID, v_FieldLength, v_IsKey, v_IsParent,
carlos@0
   233
       (CASE Cur_Column.Nullable WHEN 'Y' THEN 'N' ELSE 'Y' END),
asier@799
   234
        v_IsIdentifier, v_SeqNo, 'N', 'N', v_IsUpdateable, v_AD_Reference_Value_ID, v_AD_Val_Rule_ID, v_DefaultValue, v_IsSessionAttr) ;
carlos@0
   235
      --
carlos@0
   236
      v_count:=v_count + 1;
carlos@0
   237
      -- Added by Ismael Ciordia
carlos@0
   238
      v_SeqNo:=v_SeqNo + 10;
carlos@0
   239
      v_LastColumnName:=Cur_Column.Column_Name;
carlos@0
   240
      -- Falta: insert de AD_Element
asier@1027
   241
       DBMS_OUTPUT.PUT_LINE('adding Table ' || InitCap(Cur_Column.Table_Name) || ' Column ' || InitCap(Cur_Column.Column_Name)) ;
asier@1027
   242
      
carlos@0
   243
    END LOOP; --  All new columns
carlos@0
   244
    -- Summary info
carlos@0
   245
    v_Message:='@Created@ = ' || v_count;
gorkaion@239
   246
    --<<FINISH_PROCESS>>
carlos@0
   247
    IF(p_PInstance_ID IS NOT NULL) THEN
carlos@0
   248
      --  Update AD_PInstance
carlos@0
   249
      DBMS_OUTPUT.PUT_LINE('Updating PInstance - Finished ' || v_Message) ;
carlos@0
   250
      AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', v_Result, v_Message) ;
carlos@0
   251
    ELSE
carlos@0
   252
      DBMS_OUTPUT.PUT_LINE('Finished ' || v_Message) ;
carlos@0
   253
    END IF;
carlos@0
   254
    -- Commented by cromero 19102006 COMMIT;
carlos@0
   255
    RETURN;
carlos@0
   256
  END; --BODY
carlos@0
   257
EXCEPTION
carlos@0
   258
WHEN OTHERS THEN
carlos@0
   259
  v_ResultStr:= '@ERROR=' || SQLERRM;
carlos@0
   260
  DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
carlos@0
   261
  ROLLBACK;
carlos@0
   262
  IF(p_PInstance_ID IS NOT NULL) THEN
carlos@0
   263
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', 0, v_ResultStr) ;
carlos@0
   264
  END IF;
carlos@0
   265
--  RETURN;
antonio@735
   266
END AD_TABLE_IMPORT
gorkaion@239
   267
]]></body>
adrian@94
   268
    </function>
adrian@94
   269
  </database>