├── .gitignore
├── source
├── packages
│ ├── tePLSQL.pkb
│ ├── tePLSQL.pks
│ ├── TAPI_GEN2.pkb
│ └── TAPI_GEN2.pks
├── install
│ ├── tapigen2_uninstall.sql
│ └── tapigen2_install.sql
└── tables
│ └── TE_TEMPLATES.sql
├── .gitattributes
├── LICENSE
└── README.md
/.gitignore:
--------------------------------------------------------------------------------
1 | .Rhistory
2 | npm-debug.log
3 |
--------------------------------------------------------------------------------
/source/packages/tePLSQL.pkb:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/osalvador/tapiGen2/HEAD/source/packages/tePLSQL.pkb
--------------------------------------------------------------------------------
/.gitattributes:
--------------------------------------------------------------------------------
1 | # Auto detect text files and perform LF normalization
2 | * text=auto
3 |
4 | # Custom for Visual Studio
5 | *.cs diff=csharp
6 |
7 | # Standard to msysgit
8 | *.doc diff=astextplain
9 | *.DOC diff=astextplain
10 | *.docx diff=astextplain
11 | *.DOCX diff=astextplain
12 | *.dot diff=astextplain
13 | *.DOT diff=astextplain
14 | *.pdf diff=astextplain
15 | *.PDF diff=astextplain
16 | *.rtf diff=astextplain
17 | *.RTF diff=astextplain
18 |
--------------------------------------------------------------------------------
/source/install/tapigen2_uninstall.sql:
--------------------------------------------------------------------------------
1 | Rem NAME
2 | Rem tapigen2_install.sql
3 | Rem
4 | Rem DESCRIPTION
5 | Rem TAPI Gen2 uninstallation script.
6 | Rem
7 | Rem REQUIREMENTS
8 | Rem - Oracle Database 10 or later
9 | Rem
10 | Rem Example:
11 | Rem sqlplus "user/userpasss" @tapigen2_uninstall
12 | Rem
13 | Rem MODIFIED (MM/DD/YYYY)
14 | Rem osalvador 16/09/2015 - Created
15 |
16 | DROP PACKAGE TAPI_GEN2;
17 | DROP PACKAGE tePLSQL;
18 | DROP TABLE TE_TEMPLATES;
19 |
20 | quit;
21 | /
22 |
--------------------------------------------------------------------------------
/source/tables/TE_TEMPLATES.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE TE_TEMPLATES
2 | (
3 | NAME VARCHAR2(300 BYTE),
4 | TEMPLATE CLOB,
5 | DESCRIPTION VARCHAR2(300 BYTE),
6 | CREATED_BY VARCHAR2(100 BYTE) DEFAULT user NOT NULL,
7 | CREATED_DATE DATE DEFAULT SYSDATE NOT NULL,
8 | MODIFIED_BY VARCHAR2(100 BYTE) DEFAULT user NOT NULL,
9 | MODIFIED_DATE DATE DEFAULT SYSDATE NOT NULL
10 | );
11 |
12 |
13 | CREATE UNIQUE INDEX TE_TEMPLATES_PK ON TE_TEMPLATES
14 | (NAME);
15 |
16 |
17 | ALTER TABLE TE_TEMPLATES ADD (
18 | CONSTRAINT TE_TEMPLATES_PK
19 | PRIMARY KEY
20 | (NAME));
21 |
22 |
--------------------------------------------------------------------------------
/source/install/tapigen2_install.sql:
--------------------------------------------------------------------------------
1 | Rem NAME
2 | Rem tapigen2_install.sql
3 | Rem
4 | Rem DESCRIPTION
5 | Rem TAPI Gen2 installation script.
6 | Rem
7 | Rem REQUIREMENTS
8 | Rem - Oracle Database 10 or later
9 | Rem
10 | Rem Example:
11 | Rem sqlplus "user/userpasss" @tapigen2_install
12 | Rem
13 | Rem MODIFIED (MM/DD/YYYY)
14 | Rem osalvador 16/09/2015 - Created
15 |
16 | whenever sqlerror exit
17 | -- User Grants
18 | DECLARE
19 | l_count PLS_INTEGER := 0;
20 | BEGIN
21 | SELECT COUNT ( * )
22 | INTO l_count
23 | FROM user_tab_privs
24 | WHERE table_name = 'DBMS_CRYPTO' AND privilege = 'EXECUTE';
25 |
26 | IF l_count = 0
27 | THEN
28 | raise_application_error (-20000, 'Execute on DBMS_CRYPTO grant is necessary.');
29 | END IF;
30 | END;
31 | /
32 |
33 | whenever sqlerror continue
34 |
35 | @@../packages/tePLSQL.pks
36 | @@../packages/TAPI_GEN2.pks
37 | @@../tables/TE_TEMPLATES.sql
38 | @@../packages/tePLSQL.pkb
39 | @@../packages/TAPI_GEN2.pkb
40 |
41 | quit;
42 | /
43 |
--------------------------------------------------------------------------------
/LICENSE:
--------------------------------------------------------------------------------
1 | The MIT License (MIT)
2 |
3 | Original work Copyright (c) 2008 Daniel McGhan
4 |
5 | Modified work Copyright (c) 2014-2015 Oscar Salvador Magallanes
6 |
7 | Permission is hereby granted, free of charge, to any person obtaining a copy of
8 | this software and associated documentation files (the "Software"), to deal in
9 | the Software without restriction, including without limitation the rights to
10 | use, copy, modify, merge, publish, distribute, sublicense, and/or sell copies of
11 | the Software, and to permit persons to whom the Software is furnished to do so,
12 | subject to the following conditions:
13 |
14 | The above copyright notice and this permission notice shall be included in all
15 | copies or substantial portions of the Software.
16 |
17 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
18 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, FITNESS
19 | FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR
20 | COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER
21 | IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN
22 | CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE.
23 |
--------------------------------------------------------------------------------
/source/packages/tePLSQL.pks:
--------------------------------------------------------------------------------
1 | CREATE OR REPLACE PACKAGE teplsql
2 | AS
3 | --Define Associative Array
4 | TYPE t_assoc_array
5 | IS
6 | TABLE OF VARCHAR2 (32767)
7 | INDEX BY VARCHAR2 (255);
8 |
9 | null_assoc_array t_assoc_array;
10 |
11 | /**
12 | * Output CLOB data to the DBMS_OUTPUT.PUT_LINE
13 | *
14 | * @param p_clob the CLOB to print to the DBMS_OUTPUT
15 | */
16 | PROCEDURE output_clob(p_clob in CLOB);
17 |
18 | /**
19 | * Prints received data into the buffer
20 | *
21 | * @param p_data the data to print into buffer
22 | */
23 | PROCEDURE PRINT (p_data IN CLOB);
24 |
25 | PROCEDURE p (p_data IN CLOB);
26 |
27 | PROCEDURE PRINT (p_data IN VARCHAR2);
28 |
29 | PROCEDURE p (p_data IN VARCHAR2);
30 |
31 | PROCEDURE PRINT (p_data IN NUMBER);
32 |
33 | PROCEDURE p (p_data IN NUMBER);
34 |
35 | /**
36 | * Renders the template received as parameter.
37 | *
38 | * @param p_vars the template's arguments.
39 | * @param p_template the template's body.
40 | * @return the processed template.
41 | */
42 | FUNCTION render (p_vars IN t_assoc_array DEFAULT null_assoc_array, p_template IN CLOB)
43 | RETURN CLOB;
44 |
45 | /**
46 | * Receives the name of the object, usually a package,
47 | * which contains an embedded template.
48 | * The template is extracted and is rendered with `render` function
49 | *
50 | * @param p_vars the template's arguments.
51 | * @param p_template_name the name of the template
52 | * @param p_object_name the name of the object (usually the name of the package)
53 | * @param p_object_type the type of the object (PACKAGE, PROCEDURE, FUNCTION...)
54 | * @param p_schema the object's schema name.
55 | * @return the processed template.
56 | */
57 | FUNCTION process (p_vars IN t_assoc_array DEFAULT null_assoc_array
58 | , p_template_name IN VARCHAR2 DEFAULT NULL
59 | , p_object_name IN VARCHAR2 DEFAULT 'TE_TEMPLATES'
60 | , p_object_type IN VARCHAR2 DEFAULT 'PACKAGE'
61 | , p_schema IN VARCHAR2 DEFAULT NULL )
62 | RETURN CLOB;
63 | END teplsql;
64 | /
--------------------------------------------------------------------------------
/source/packages/TAPI_GEN2.pkb:
--------------------------------------------------------------------------------
1 | /* Formatted on 16/09/2015 9:35:19 (QP5 v5.115.810.9015) */
2 | CREATE OR REPLACE PACKAGE BODY tapi_gen2
3 | AS
4 | --Global private variables
5 | g_unque_key dbo_name_t;
6 |
7 | PROCEDURE create_tapi_package (p_table_name IN VARCHAR2
8 | , p_compile_table_api IN BOOLEAN DEFAULT TRUE
9 | , p_unique_key IN VARCHAR2 DEFAULT NULL
10 | , p_created_by_col_name IN VARCHAR2 DEFAULT NULL
11 | , p_created_date_col_name IN VARCHAR2 DEFAULT NULL
12 | , p_modified_by_col_name IN VARCHAR2 DEFAULT NULL
13 | , p_modified_date_col_name IN VARCHAR2 DEFAULT NULL
14 | , p_raise_exceptions IN BOOLEAN DEFAULT FALSE )
15 | AS
16 | l_count PLS_INTEGER := 0;
17 | l_table_name dbo_name_t := LOWER (p_table_name);
18 | l_vars teplsql.t_assoc_array;
19 | l_spec_tapi CLOB;
20 | l_body_tapi CLOB;
21 | BEGIN
22 | /*Validations*/
23 |
24 | --check_table_exists
25 | SELECT COUNT ( * )
26 | INTO l_count
27 | FROM user_tables
28 | WHERE UPPER (table_name) = UPPER (l_table_name);
29 |
30 | IF l_count = 0
31 | THEN
32 | raise_application_error (-20000, 'Table ' || l_table_name || ' does not exist!');
33 | END IF;
34 |
35 | --Check table hash PK or p_unique_key is not null
36 | IF p_unique_key IS NULL
37 | THEN
38 | SELECT COUNT ( * )
39 | INTO l_count
40 | FROM user_constraints
41 | WHERE UPPER (table_name) = UPPER (l_table_name) AND constraint_type = 'P';
42 |
43 | IF l_count = 0
44 | THEN
45 | raise_application_error (-20000
46 | , 'Table '
47 | || l_table_name
48 | || ' does not have a Primary Key'
49 | || ' and P_UNIQUE_KEY parameter is null');
50 | END IF;
51 | END IF;
52 |
53 | --Init variables for render template
54 | l_vars ('date') := TO_CHAR (SYSDATE, 'DD-MON-YYYY HH24:MI');
55 | l_vars ('table_name') := l_table_name;
56 | l_vars ('user') := USER;
57 | l_vars ('created_by_col_name') := p_created_by_col_name;
58 | l_vars ('created_date_col_name') := p_created_date_col_name;
59 | l_vars ('modified_by_col_name') := p_modified_by_col_name;
60 | l_vars ('modified_date_col_name') := p_modified_date_col_name;
61 | l_vars ('result_cache') := 'RESULT_CACHE';
62 |
63 | IF p_raise_exceptions
64 | THEN
65 | l_vars ('raise_exceptions') := 'TRUE';
66 | ELSE
67 | l_vars ('raise_exceptions') := '';
68 | END IF;
69 |
70 | --If the table hash LOBS columns, disable result_cache.
71 | FOR c1 IN (SELECT *
72 | FROM user_tab_cols
73 | WHERE table_name = UPPER (l_table_name) AND data_type IN ('BLOB', 'CLOB'))
74 | LOOP
75 | l_vars ('result_cache') := '';
76 | END LOOP;
77 |
78 | --Define unique key if table don't hace primary key
79 | g_unque_key := p_unique_key;
80 |
81 | -- Spec --
82 | --Process template
83 | l_spec_tapi := teplsql.process (l_vars, 'spec', 'TAPI_GEN2');
84 |
85 | -- Body --
86 | --Process template
87 | l_body_tapi := teplsql.process (l_vars, 'body', 'TAPI_GEN2');
88 |
89 | IF p_compile_table_api
90 | THEN
91 | BEGIN
92 | EXECUTE IMMEDIATE l_spec_tapi;
93 | EXCEPTION
94 | WHEN OTHERS
95 | THEN
96 | DBMS_OUTPUT.put_line (l_spec_tapi);
97 | raise_application_error (-20000, 'Spec compiled with error(s)! ' || SQLERRM);
98 | END;
99 |
100 | BEGIN
101 | EXECUTE IMMEDIATE l_body_tapi;
102 | EXCEPTION
103 | WHEN OTHERS
104 | THEN
105 | raise_application_error (-20000, ' Body compiled with error(s)! ' || SQLERRM);
106 | END;
107 |
108 | DBMS_OUTPUT.put_line('Creation of Table API package for ' || l_table_name || ' table completed successfully!');
109 | ELSE
110 | DBMS_OUTPUT.put_line (l_spec_tapi);
111 | DBMS_OUTPUT.put_line (l_body_tapi);
112 | END IF;
113 | END create_tapi_package;
114 |
115 |
116 | FUNCTION get_all_columns (p_tab_name VARCHAR2)
117 | RETURN column_tt
118 | IS
119 | l_tt column_tt;
120 | BEGIN
121 | SELECT c.table_name
122 | , LOWER (c.column_name)
123 | , c.nullable
124 | , '' constraint_type
125 | BULK COLLECT
126 | INTO l_tt
127 | FROM user_tab_columns c
128 | WHERE c.table_name = UPPER (p_tab_name)
129 | ORDER BY c.column_id;
130 |
131 | RETURN l_tt;
132 | END;
133 |
134 | FUNCTION get_pk_columns (p_tab_name VARCHAR2)
135 | RETURN column_tt
136 | IS
137 | l_tt column_tt;
138 | BEGIN
139 | IF g_unque_key IS NOT NULL
140 | THEN
141 | IF NOT l_tt.EXISTS (1)
142 | THEN
143 | l_tt := column_tt (NULL);
144 | END IF;
145 |
146 | l_tt (1).table_name := p_tab_name;
147 | l_tt (1).column_name := LOWER (g_unque_key);
148 | l_tt (1).nullable := 'N';
149 | l_tt (1).constraint_type := 'P';
150 | ELSE
151 | SELECT c.table_name
152 | , LOWER (c.column_name)
153 | , c.nullable
154 | , cs.constraint_type
155 | BULK COLLECT
156 | INTO l_tt
157 | FROM user_tab_columns c
158 | LEFT JOIN
159 | user_cons_columns cc
160 | ON c.table_name = cc.table_name AND c.column_name = cc.column_name
161 | LEFT JOIN
162 | user_constraints cs
163 | ON cc.constraint_name = cs.constraint_name
164 | WHERE c.table_name = UPPER (p_tab_name) AND cs.constraint_type = 'P'
165 | ORDER BY c.column_id;
166 | END IF;
167 |
168 | RETURN l_tt;
169 | END;
170 |
171 |
172 | FUNCTION get_noblob_columns (p_tab_name VARCHAR2)
173 | RETURN column_tt
174 | IS
175 | l_tt column_tt;
176 | BEGIN
177 | SELECT c.table_name
178 | , LOWER (c.column_name)
179 | , c.nullable
180 | , '' constraint_type
181 | BULK COLLECT
182 | INTO l_tt
183 | FROM user_tab_columns c
184 | WHERE table_name = UPPER (p_tab_name)
185 | AND column_name NOT IN (SELECT column_name
186 | FROM user_tab_cols
187 | WHERE table_name = UPPER (p_tab_name) AND data_type = 'BLOB')
188 | ORDER BY column_id;
189 |
190 | RETURN l_tt;
191 | END;
192 | END tapi_gen2;
193 | /
194 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # tapiGen2
2 | PL/SQL Table API Generator for Oracle
3 |
4 | tapiGen2 aims to automate the creation of PLSQL TABLE APIs. [You can use the online version](https://apex.oracle.com/pls/apex/f?p=48301:3:1326289165255::NO:3::)
5 |
6 | A table API is a data access layer that provides the basic CRUD operations for a single table. The key principle is to avoid repetition of SQL statements and consequently make it easier to optimize, maintain, and enhance those statements. For this reason, a data access layer is critical. Some of us build apps that perform DML on individual tables, and so we find TAPIs useful.
7 |
8 | - [Let's start](#letsStart)
9 | - [What's New](#watsNew)
10 | - [Getting started](#getStart)
11 | + [Install](#install)
12 | + [Usage](#usage)
13 | - [Functions and procedures included](#functions)
14 | - [Procedure description](#procedureDesc)
15 | - [Special Thanks](#thanks)
16 | - [Contributing](#contributing)
17 | - [License](#license)
18 |
19 |
20 | ## Let's start
21 |
22 | Let's start by taking a look at a single row fetch, using its id - a very common operation.
23 |
24 | This would be typically done in 4 lines of code:
25 | ```sql
26 | SELECT *
27 | INTO l_table_rec
28 | FROM table_name
29 | WHERE id = l_var_with_id;
30 | ```
31 |
32 | Although it's easy enough to write, there are few problems with this approach.
33 |
34 | 1. This implicit cursor introduces a possible NO_DATA_FOUND exception that should be handled - that means more code. Explicit cursors would also require more code.
35 | 2. Each statement written like this, must be maintained, hence, if the table name is changed then all the statements must be updated.
36 | 3. If any of the statements written for this purpose are not written exactly in the same way, Oracle may take a little longer to execute them.
37 |
38 | The RT function in tapiGen was created for this very purpose and is used as follows:
39 |
40 | l_table_rec := table_name_te.rt(l_var_with_id);
41 |
42 |
43 | That's it, one line! Granted there are many more lines behind the scenes, but
44 | you did not have to write them nor must you maintain them. Errors are handled,
45 | maintenance is easier, and if everyone uses this function, performance is
46 | better. If you're using Oracle 11g, the function cache will be used for subsequent calls.
47 |
48 |
49 | ## What's New in tapiGen2
50 |
51 | tapiGen2 uses the template engine [tePLSQL](https://github.com/osalvador/tePLSQL) that simplifies the creation of code and allows it to be easily customizable.
52 |
53 | It also adds new features to the generated API, and some of them are modified. Now, as an option, the framework [ logger ]( https://github.com/oraopensource/logger ) is used for exception handling
54 |
55 | Also, it includes:
56 |
57 | - Single column primary key restriction has been deleted. Now the primary key can contain from 0 to N columns. If the table has no primary key, parameter `unique_key` must be not null.
58 | - The `tt` PIPELINED function has been implemented. This returns an array of records and standardizes access to the tables, without losing the ability to make queries directly.
59 | - DML operations, based on the rowid, have been created to facilitate their use by API clients. `upd_rowid`, `web_upd_rowid`, `del_rowid` and `web_del_rowid`
60 | - Audit columns will be injected as parameters and won't be mandatory.
61 | - Tables won't require a sequence restriction. In case that the used table has one, the code will have to be modified to add the `nextval()` statement. Under construction.
62 | - SHA1 is used instead of MD5 hash, in Oracle 12c we will use SHA256.
63 | - The `put_apex_form_code` procedure has been removed.
64 |
65 |
66 | ## Getting started
67 |
68 |
69 | ### Install
70 | Clone the repo and install:
71 |
72 | git clone https://github.com/osalvador/tapiGen2.git
73 | cd tapiGen2/source/install
74 | sqlplus "user/userpass"@SID @tapigen2_install
75 |
76 | Execute on `DBMS_CRYPTO` grant is necessary.
77 |
78 | ### Uninstall
79 | Clone the repo and uninstall:
80 |
81 | git clone https://github.com/osalvador/tapiGen2.git
82 | cd tapiGen2/source/install
83 | sqlplus "user/userpass"@SID @tapigen2_uninstall
84 |
85 | #### Logger
86 | If you use logger for exception handling you may also:
87 |
88 | - Download logger https://github.com/oraopensource/logger
89 | - And follow the installation instruction https://github.com/OraOpenSource/Logger/blob/master/docs/Installation.md
90 |
91 | Logger needs the following grants
92 |
93 | grant connect,create view, create job, create table, create sequence,
94 | create trigger, create procedure, create any context to existing_user;
95 |
96 |
97 |
98 | ### Usage
99 |
100 | #### Basic Example
101 | Create Table API for DEPT table, without audit columns
102 |
103 | ```plsql
104 | exec tapi_gen2.create_tapi_package (p_table_name => 'DEPT', p_compile_table_api => TRUE);
105 | ```
106 |
107 | Result:
108 |
109 | Creation of Table API package for DEPT table completed successfully!
110 |
111 | #### With audit columns
112 | Create Table API for EMP table assign custom audit columns.
113 |
114 | ```plsql
115 | exec tapi_gen2.create_tapi_package (p_table_name => 'EMP'
116 | , p_compile_table_api => FALSE
117 | , p_created_by_col_name => 'created_by'
118 | , p_created_date_col_name => 'created_date'
119 | , p_modified_by_col_name => 'modified_by'
120 | , p_modified_date_col_name => 'modified_date'
121 | , p_raise_exceptions => FALSE);
122 | ```
123 |
124 | Because `p_compile_table_api` is set to `FALSE` tapiGen2 show source via `DBMS_OUTPUT`:
125 |
126 | ```plsql
127 | CREATE OR REPLACE PACKAGE tapi_emp
128 | IS
129 | /**
130 | -- # TAPI_EMP
131 | -- Generated by: tapiGen2 - DO NOT MODIFY!
132 | -- Website: github.com/osalvador/tapiGen2
133 | -- Created On: 16-SEP-2015 12:45
134 | -- Created By: TEST
135 | */
136 |
137 | --Scalar/Column types
138 | SUBTYPE hash_t IS varchar2 (40);
139 | SUBTYPE empno IS emp.empno%TYPE;
140 | SUBTYPE ename IS emp.ename%TYPE;
141 | SUBTYPE job IS emp.job%TYPE;
142 | SUBTYPE mgr IS emp.mgr%TYPE;
143 | SUBTYPE hiredate IS emp.hiredate%TYPE;
144 | SUBTYPE sal IS emp.sal%TYPE;
145 | SUBTYPE comm IS emp.comm%TYPE;
146 | SUBTYPE deptno IS emp.deptno%TYPE;
147 |
148 | --Record type
149 | TYPE emp_rt
150 | IS
151 | RECORD (
152 | empno emp.empno%TYPE,
153 | ename emp.ename%TYPE,
154 | job emp.job%TYPE,
155 | mgr emp.mgr%TYPE,
156 | hiredate emp.hiredate%TYPE,
157 | sal emp.sal%TYPE,
158 | comm emp.comm%TYPE,
159 | deptno emp.deptno%TYPE,
160 | hash hash_t,
161 | row_id VARCHAR2(64)
162 | );
163 | .....
164 | ```
165 |
166 |
167 | ## Functions and procedures that exist within each package that tapiGen2 creates
168 |
169 | Here is a brief list of the various functions and procedures that exist within
170 | each package that tapiGen creates: *(f) = function and (p) = procedure
171 |
172 | 1. ``rt`` (f) - Returns a record from the table. Uses function result cache in
173 | 11g.
174 | 2. ``rt_for_update`` (f) - Returns a record from the table and places a row level
175 | lock on it.
176 | 3. ``tt`` (f) - Returns record Table as PIPELINED Function.
177 | Pipe-lining negates the need to build huge collections by piping rows out of the function as they are created, saving memory and allowing subsequent processing to start before all the rows are generated -- [Oracle Base Blog][1]
178 | 4. ``ins`` (p) - Inserts a row into the table. Automatically updates the audit
179 | columns: created_by, created_date, modified_by, and modified_date.
180 | 5. ``upd`` (p) - Updates a row in the table. Automatically updates the audit
181 | columns: modified_by, and modified_date.
182 | 6. ``web_upd`` (p) - Updates a row in the table. Performs an optimistic locking
183 | check prior to performing the update. Automatically updates the audit
184 | columns: modified_by, and modified_date.
185 | 7. ``del`` (p) - Deletes a row from the table.
186 | 8. ``web_del`` (p) - Deletes a row from the table. Performs an optimistic locking check prior to performing the update.
187 | 9. ``hash`` (f) - Returns an SHA1 hash of a row in the table.
188 | 10. `upd_rowid` (p) - Same as `upd` but access directly to the row by rowid.
189 | 11. `web_upd_rowid` (p) - Same as `web_upd` but access directly to the row by rowid.
190 | 12. `del_rowid` (p) - Same as `del` but access directly to the row by rowid.
191 | 13. `web_del_rowid` (p) - Same as `web_del` but access directly to the row by rowid.
192 | 14. `hash_rowid` (f) - Same as `hash` but access directly to the row by rowid.
193 |
194 |
195 | [1]:https://oracle-base.com/articles/misc/pipelined-table-functions#pipelined_table_functions
196 |
197 |
198 | ## tapiGen2 procedure description
199 | ### CREATE_TAPI_PACKAGE
200 |
201 | ```plsql
202 | PROCEDURE create_tapi_package (p_table_name IN VARCHAR2
203 | , p_compile_table_api IN BOOLEAN DEFAULT TRUE
204 | , p_unique_key IN VARCHAR2 DEFAULT NULL
205 | , p_created_by_col_name IN VARCHAR2 DEFAULT NULL
206 | , p_created_date_col_name IN VARCHAR2 DEFAULT NULL
207 | , p_modified_by_col_name IN VARCHAR2 DEFAULT NULL
208 | , p_modified_date_col_name IN VARCHAR2 DEFAULT NULL
209 | , p_raise_exceptions IN BOOLEAN DEFAULT FALSE);
210 | ```
211 |
212 | #### Description:
213 | Create PL/SQL Table API
214 |
215 | #### IN Parameters
216 |
217 | | Name | Type | Description
218 | |------|------|------------
219 | | p_table_name | VARCHAR2 | must be NOT NULL
220 | | p_compile_table_api | BOOLEAN | TRUE for compile generated package, FALSE to DBMS_OUTPUT the source
221 | | p_unique_key | VARCHAR2 | If the table has no primary key, it indicates the column that will be used as a unique key
222 | | p_created_by_col_name | VARCHAR2 | Custom audit column
223 | | p_created_date_col_name | VARCHAR2 | Custom audit column
224 | | p_modified_by_col_name | VARCHAR2 | Custom audit column
225 | | p_modified_date_col_name | VARCHAR2 | Custom audit column
226 | | p_raise_exceptions | BOOLEAN | TRUE to use logger for exception handling
227 |
228 |
229 | #### Amendments
230 |
231 | | When | Who | What
232 | |--------------|--------------------------|------------------
233 | |16-JUL-2015 | osalvador | Created
234 | |20-JUL-2015 | osalvador | Added logger exception handling
235 | |16-SEP-2015 | osalvador | The new version of tePLSQL is used. And the template is moved to the tapi_gen2 package spec.
236 |
237 |
238 | ## Special thanks
239 |
240 | tapiGen2 is the continuation of the Open Source project created by Daniel McGhan in 2008, [tapiGen](http://sourceforge.net/projects/tapigen/).
241 |
242 |
243 | ## Contributing
244 |
245 | If you have any ideas, get in touch directly.
246 |
247 | Please insert at the bottom of your commit message the following line, having in it your name and e-mail address .
248 |
249 | Signed-off-by: Your Name
250 |
251 | This can be automatically added to pull requests by committing with:
252 |
253 | git commit --signoff
254 |
255 |
256 | ## License
257 |
258 | Copyright 2015 Oscar Salvador Magallanes
259 |
260 | tapiGen2 is under MIT license.
261 |
--------------------------------------------------------------------------------
/source/packages/TAPI_GEN2.pks:
--------------------------------------------------------------------------------
1 | CREATE OR REPLACE PACKAGE tapi_gen2 authid current_user
2 | AS
3 |
4 | /**
5 | * TAPI_GEN2
6 | * Generated by: Oscar Salvador Magallanes
7 | * Website: github.com/osalvador/tapiGen2
8 | * Created On: 16-JUL-2015
9 | */
10 |
11 | --Global public data structures
12 | SUBTYPE dbo_name_t IS VARCHAR2 (30); -- Max size for a DB object name
13 |
14 | TYPE dbo_name_aat IS TABLE OF dbo_name_t;
15 |
16 | TYPE column_rt
17 | IS
18 | RECORD (
19 | table_name user_tab_columns.table_name%TYPE
20 | , column_name user_tab_columns.column_name%TYPE
21 | , nullable user_tab_columns.nullable%TYPE
22 | , constraint_type user_constraints.constraint_type%TYPE
23 | );
24 |
25 | --Collection types (record)
26 | TYPE column_tt IS TABLE OF column_rt;
27 |
28 | TYPE constraint_tt IS TABLE OF user_constraints%ROWTYPE;
29 |
30 | /**
31 | * Create PL/SQL Table API
32 | *
33 | * @param p_table_name must be NOT NULL
34 | * @param p_compile_table_api TRUE for compile generated package, FALSE to DBMS_OUTPUT the source
35 | * @param p_unique_key If the table has no primary key, it indicates the column that will be used as a unique key
36 | * @param p_created_by_col_name Custom audit column
37 | * @param p_created_date_col_name Custom audit column
38 | * @param p_modified_by_col_name Custom audit column
39 | * @param p_modified_date_col_name Custom audit column
40 | * @param p_raise_exceptions TRUE to use logger for exception handling
41 | */
42 | PROCEDURE create_tapi_package (p_table_name IN VARCHAR2
43 | , p_compile_table_api IN BOOLEAN DEFAULT TRUE
44 | , p_unique_key IN VARCHAR2 DEFAULT NULL
45 | , p_created_by_col_name IN VARCHAR2 DEFAULT NULL
46 | , p_created_date_col_name IN VARCHAR2 DEFAULT NULL
47 | , p_modified_by_col_name IN VARCHAR2 DEFAULT NULL
48 | , p_modified_date_col_name IN VARCHAR2 DEFAULT NULL
49 | , p_raise_exceptions IN BOOLEAN DEFAULT FALSE);
50 |
51 | --Public functions but for internal use.
52 | FUNCTION get_all_columns (p_tab_name VARCHAR2)
53 | RETURN column_tt;
54 |
55 | FUNCTION get_pk_columns (p_tab_name VARCHAR2)
56 | RETURN column_tt;
57 |
58 | FUNCTION get_noblob_columns (p_tab_name VARCHAR2)
59 | RETURN column_tt;
60 |
61 | --Spec Template
62 | $if false $then
63 | <%@ template
64 | name=spec
65 | %>
66 | <%! col tapi_gen2.column_tt := tapi_gen2.get_all_columns ('${table_name}'); %>
67 | <%! pk tapi_gen2.column_tt := tapi_gen2.get_pk_columns ('${table_name}'); %>
68 | <%! c pls_integer; %>
69 | <%! /* Separator procedure */
70 | procedure sep (p_cont in pls_integer, p_delimiter in varchar2)
71 | as
72 | begin
73 | if p_cont > 1
74 | then
75 | teplsql.p(p_delimiter);
76 | end if;
77 | end; %>
78 | CREATE OR REPLACE PACKAGE tapi_${table_name}
79 | IS
80 | /**
81 | * TAPI_<%= upper('${table_name}') %>\\n
82 | * Generated by: tapiGen2 - DO NOT MODIFY!
83 | * Website: github.com/osalvador/tapiGen2
84 | * Created On: ${date}
85 | * Created By: ${user}
86 | */
87 |
88 | --Scalar/Column types
89 | SUBTYPE hash_t IS varchar2 (40);
90 | <% for i in 1 .. col.last loop %>
91 | SUBTYPE <%= col(i).COLUMN_NAME%> IS ${table_name}.<%= col(i).COLUMN_NAME%>%TYPE;
92 | <% end loop; %>
93 |
94 | --Record type
95 | TYPE ${table_name}_rt
96 | IS
97 | RECORD (
98 | <% c := col.last+1;
99 | for i in 1 .. col.last loop %>
100 | <%= col(i).COLUMN_NAME%> ${table_name}.<%=col(i).COLUMN_NAME %>%TYPE,
101 | <% end loop; %>
102 | hash hash_t,
103 | row_id VARCHAR2(64)
104 | );
105 | --Collection types (record)
106 | TYPE ${table_name}_tt IS TABLE OF ${table_name}_rt;
107 |
108 | --Global exceptions
109 | e_ol_check_failed EXCEPTION; --Optimistic lock check failed
110 | e_row_missing EXCEPTION; --The cursor failed to get a row
111 | e_upd_failed EXCEPTION; --The update operation failed
112 | e_del_failed EXCEPTION; --The delete operation failed
113 |
114 | /**
115 | * Generates a SHA1 hash for optimistic locking purposes.
116 | *
117 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
118 | * @param p_<%= pk(i).COLUMN_NAME %> must be NOT NULL
119 | <% end loop; %>
120 | */
121 | FUNCTION hash (
122 | <% c := pk.last+1;
123 | for i in 1 .. pk.last loop %>
124 | p_<%= pk(i).COLUMN_NAME%> IN ${table_name}.<%=pk(i).COLUMN_NAME %>%TYPE<%sep(c-i,',');%>\\n
125 | <% end loop; %>
126 | )
127 | RETURN VARCHAR2;
128 |
129 | /**
130 | * This function generates a SHA1 hash for optimistic locking purposes.
131 | * Access directly to the row by rowid
132 | *
133 | * @param p_rowid must be NOT NULL
134 | */
135 | FUNCTION hash_rowid (p_rowid IN varchar2)
136 | RETURN varchar2;
137 |
138 | /**
139 | * This is a table encapsulation function designed to retrieve information from the ${table_name} table.
140 | *
141 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
142 | * @param p_<%= pk(i).COLUMN_NAME %> must be NOT NULL
143 | <% end loop; %>
144 | * @return ${table_name} Record Type
145 | */
146 | FUNCTION rt (
147 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
148 | p_<%= pk(i).COLUMN_NAME%> IN ${table_name}.<%=pk(i).COLUMN_NAME %>%TYPE <%sep(c-i,',');%>\\n
149 | <% end loop; %>
150 | )
151 | RETURN ${table_name}_rt ${result_cache};
152 |
153 | /**
154 | * This is a table encapsulation function designed to retrieve information
155 | * from the ${table_name} table while placing a lock on it for a potential
156 | * update/delete. Do not use this for updates in web based apps, instead use the
157 | * rt_for_web_update function to get a FOR_WEB_UPDATE_RT record which
158 | * includes all of the tables columns along with an md5 checksum for use in the
159 | * web_upd and web_del procedures.
160 | *
161 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
162 | * @param p_<%= pk(i).COLUMN_NAME %> must be NOT NULL
163 | <% end loop; %>
164 | * @return ${table_name} Record Type
165 | */
166 | FUNCTION rt_for_update (
167 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
168 | p_<%= pk(i).COLUMN_NAME%> IN ${table_name}.<%=pk(i).COLUMN_NAME %>%TYPE <%sep(c-i,',');%>\\n
169 | <% end loop; %>
170 | )
171 | RETURN ${table_name}_rt ${result_cache};
172 |
173 | /**
174 | * This is a table encapsulation function designed to retrieve information from the ${table_name} table.
175 | * This function return Record Table as PIPELINED Function
176 | *
177 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
178 | * @param p_<%= pk(i).COLUMN_NAME %> must be NOT NULL
179 | <% end loop; %>
180 | * @return ${table_name} Table Record Type
181 | */
182 | FUNCTION tt (
183 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
184 | p_<%= pk(i).COLUMN_NAME%> IN ${table_name}.<%=pk(i).COLUMN_NAME %>%TYPE DEFAULT NULL<%sep(c-i,',');%>\\n
185 | <% end loop; %>
186 | )
187 | RETURN ${table_name}_tt
188 | PIPELINED;
189 |
190 | /**
191 | * This is a table encapsulation function designed to insert a row into the ${table_name} table.
192 | *
193 | * @param p_${table_name}_rec Record Type
194 | * @return p_${table_name}_rec Record Type
195 | */
196 | PROCEDURE ins (p_${table_name}_rec IN OUT ${table_name}_rt);
197 |
198 | /**
199 | * This is a table encapsulation function designed to update a row in the ${table_name} table.
200 | *
201 | * @param p_${table_name}_rec Record Type
202 | * @param p_ignore_nulls IF TRUE then null values are ignored in the update
203 | */
204 | PROCEDURE upd (p_${table_name}_rec IN ${table_name}_rt, p_ignore_nulls IN boolean := FALSE);
205 |
206 | /**
207 | * This is a table encapsulation function designed to update a row in the ${table_name} table,
208 | * access directly to the row by rowid
209 | *
210 | * @param p_${table_name}_rec Record Type
211 | * @param p_ignore_nulls IF TRUE then null values are ignored in the update
212 | */
213 | PROCEDURE upd_rowid (p_${table_name}_rec IN ${table_name}_rt, p_ignore_nulls IN boolean := FALSE);
214 |
215 | /**
216 | * This is a table encapsulation function designed to update a row
217 | * in the ${table_name} table whith optimistic lock validation
218 | *
219 | * @param p_${table_name}_rec Record Type
220 | * @param p_ignore_nulls IF TRUE then null values are ignored in the update
221 | */
222 | PROCEDURE web_upd (p_${table_name}_rec IN ${table_name}_rt, p_ignore_nulls IN boolean := FALSE);
223 |
224 | /**
225 | * This is a table encapsulation function designed to update a row
226 | * in the ${table_name} table whith optimistic lock validation
227 | * access directly to the row by rowid
228 | *
229 | * @param p_${table_name}_rec Record Type
230 | * @param p_ignore_nulls IF TRUE then null values are ignored in the update
231 | */
232 | PROCEDURE web_upd_rowid (p_${table_name}_rec IN ${table_name}_rt, p_ignore_nulls IN boolean := FALSE);
233 |
234 | /**
235 | * This is a table encapsulation function designed to delete a row from the ${table_name} table.
236 | *
237 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
238 | * @param p_<%= pk(i).COLUMN_NAME %> must be NOT NULL
239 | <% end loop; %>
240 | */
241 | PROCEDURE del (
242 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
243 | p_<%=pk(i).COLUMN_NAME%> IN ${table_name}.<%=pk(i).COLUMN_NAME %>%TYPE<%sep(c-i,',');%>\\n
244 | <% end loop; %>
245 | );
246 |
247 | /**
248 | * This is a table encapsulation function designed to delete a row from the ${table_name} table
249 | * access directly to the row by rowid
250 | *
251 | * @param p_rowid must be NOT NULL
252 | */
253 | PROCEDURE del_rowid (p_rowid IN VARCHAR2);
254 |
255 | /**
256 | * This is a table encapsulation function designed to delete a row from the ${table_name} table
257 | * whith optimistic lock validation
258 | *
259 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
260 | * @param p_<%= pk(i).COLUMN_NAME %> must be NOT NULL
261 | <% end loop; %>
262 | * @param p_hash must be NOT NULL
263 | */
264 | PROCEDURE web_del (
265 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
266 | p_<%=pk(i).column_name%> IN ${table_name}.<%=pk(i).column_name %>%TYPE,
267 | <% end loop; %>
268 | p_hash IN varchar2
269 | );
270 |
271 | /**
272 | * This is a table encapsulation function designed to delete a row from the ${table_name} table
273 | * whith optimistic lock validation, access directly to the row by rowid
274 | *
275 | * @param p_rowid must be NOT NULL
276 | * @param p_hash must be NOT NULL
277 | */
278 | PROCEDURE web_del_rowid (p_rowid IN varchar2, p_hash IN varchar2);
279 |
280 | END tapi_${table_name};
281 | $end
282 |
283 |
284 | --Body Template
285 | $if false $then
286 | <%@ template
287 | name=body
288 | %>
289 | <%! col tapi_gen2.column_tt := tapi_gen2.get_all_columns ('${table_name}'); %>
290 | <%! pk tapi_gen2.column_tt := tapi_gen2.get_pk_columns ('${table_name}'); %>
291 | <%! noblob tapi_gen2.column_tt := tapi_gen2.get_noblob_columns ('${table_name}'); %>
292 | <%! c pls_integer; %>
293 | <%! /* Separator procedure */
294 | procedure sep (p_index in pls_integer, p_delimiter in varchar2)
295 | as
296 | begin
297 | if p_index > 1
298 | then
299 | teplsql.p(p_delimiter);
300 | end if;
301 | end; %>
302 | <%! /* User column for update */
303 | procedure column_for_update(p_column_name in varchar2,
304 | p_ignore_nulls in boolean,
305 | p_index in pls_integer,
306 | p_blanks in pls_integer default 16)
307 | as
308 | l_blanks varchar2(256);
309 | begin
310 | for i in 1 .. p_blanks
311 | loop
312 | l_blanks := l_blanks ||' ';
313 | end loop;
314 |
315 | if ('${created_by_col_name}' <> p_column_name or '${created_by_col_name}' is null)
316 | and ('${created_date_col_name}' <> p_column_name or '${created_date_col_name}' is null)
317 | then
318 | if '${modified_by_col_name}' = p_column_name
319 | then
320 | teplsql.p(p_column_name || ' = USER /*dbax_core.g$username or apex_application.g_user*/');
321 | elsif '${modified_date_col_name}' = p_column_name
322 | then
323 | teplsql.p(p_column_name || ' = SYSDATE');
324 | else
325 | if p_ignore_nulls
326 | then
327 | teplsql.p(p_column_name || ' = ' || 'NVL(p_${table_name}_rec.'|| p_column_name ||','|| p_column_name ||')');
328 | else
329 | teplsql.p(p_column_name || ' = p_${table_name}_rec.' || p_column_name);
330 | end if;
331 | end if;
332 |
333 | sep(p_index,',\\n' || l_blanks);
334 |
335 | end if;
336 | end; %>
337 | CREATE OR REPLACE PACKAGE BODY tapi_${table_name} IS
338 |
339 | /**
340 | * TAPI_<%= upper('${table_name}') %>\\n
341 | * Generated by: tapiGen2 - DO NOT MODIFY!
342 | * Website: github.com/osalvador/tapiGen2
343 | * Created On: ${date}
344 | * Created By: ${user}
345 | */
346 |
347 | <% if '${raise_exceptions}' is not null then %>
348 | --Global logger scope
349 | gc_scope_prefix CONSTANT varchar2(31) := LOWER($$plsql_unit)||'.';
350 | <% end if; %>
351 |
352 | --GLOBAL_PRIVATE_CURSORS
353 | --By PK
354 | CURSOR ${table_name}_cur (
355 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
356 | p_<%=pk(i).column_name%> IN ${table_name}.<%=pk(i).column_name %>%TYPE<%sep(c-i,',');%>\\n
357 | <% end loop; %>
358 | )
359 | IS
360 | SELECT
361 | <% c := col.last+1; for i in 1 .. col.last loop %>
362 | <%=col(i).column_name%>,
363 | <% end loop; %>
364 | tapi_${table_name}.hash(<% c := pk.last+1; for i in 1 .. pk.last loop %><%=pk(i).column_name%><%sep(c-i,','); end loop; %>),
365 | ROWID
366 | FROM ${table_name}
367 | WHERE
368 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
369 | <%=pk(i).column_name%> = ${table_name}_cur.p_<%=pk(i).column_name%><%sep(c-i,' AND ');%>\\n
370 | <% end loop; %>
371 | FOR UPDATE;
372 |
373 | --By Rowid
374 | CURSOR ${table_name}_rowid_cur (p_rowid IN VARCHAR2)
375 | IS
376 | SELECT
377 | <% c := col.last+1; for i in 1 .. col.last loop %>
378 | <%=col(i).column_name%>,
379 | <% end loop; %>
380 | tapi_${table_name}.hash(<% c := pk.last+1; for i in 1 .. pk.last loop %><%=pk(i).column_name%><%sep(c-i,','); end loop; %>),
381 | ROWID
382 | FROM ${table_name}
383 | WHERE ROWID = p_rowid
384 | FOR UPDATE;
385 |
386 |
387 | FUNCTION hash (
388 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
389 | p_<%=pk(i).column_name%> IN ${table_name}.<%=pk(i).column_name %>%TYPE<%sep(c-i,',');%>\\n
390 | <% end loop; %>
391 | )
392 | RETURN varchar2
393 | IS
394 | <% if '${raise_exceptions}' is not null then %>
395 | l_scope logger_logs.scope%TYPE := gc_scope_prefix || 'hash';
396 | l_params logger.tab_param;
397 | <% end if; %>
398 | l_retval hash_t;
399 | l_string CLOB;
400 | l_date_format VARCHAR2(64);
401 | BEGIN
402 |
403 | <% if '${raise_exceptions}' is not null then
404 | c := pk.last+1; for i in 1 .. pk.last loop %>
405 | logger.append_param(l_params, 'p_<%=pk(i).column_name%>', p_<%=pk(i).column_name%>);
406 | <% end loop; %>
407 | logger.LOG('START', l_scope, NULL, l_params);
408 | logger.LOG('Getting row data into one string', l_scope);
409 | <% end if; %>
410 |
411 | --Get actual NLS_DATE_FORMAT
412 | SELECT VALUE
413 | INTO l_date_format
414 | FROM v$nls_parameters
415 | WHERE parameter = 'NLS_DATE_FORMAT';
416 |
417 | --Alter session for date columns
418 | EXECUTE IMMEDIATE 'ALTER SESSION SET NLS_DATE_FORMAT=''YYYY/MM/DD hh24:mi:ss''';
419 |
420 | SELECT
421 | <% c := noblob.last+1; for i in 1 .. noblob.last loop %>
422 | <%=noblob(i).column_name%><%sep(c-i,'||');%>\\n
423 | <% end loop; %>
424 | INTO l_string
425 | FROM ${table_name}
426 | WHERE
427 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
428 | <%=pk(i).column_name%> = hash.p_<%=pk(i).column_name%><%sep(c-i,' AND ');%>\\n
429 | <% end loop; %>
430 | ;
431 |
432 | --Restore NLS_DATE_FORMAT to default
433 | EXECUTE IMMEDIATE 'ALTER SESSION SET NLS_DATE_FORMAT=''' || l_date_format|| '''';
434 |
435 | <% if '${raise_exceptions}' is not null then %>
436 | logger.LOG('Converting into SHA1 hash', l_scope);
437 | <%end if; %>
438 | l_retval := DBMS_CRYPTO.hash(l_string, DBMS_CRYPTO.hash_sh1);
439 | <% if '${raise_exceptions}' is not null then %>
440 | logger.LOG('END', l_scope);
441 | <%end if; %>
442 |
443 | RETURN l_retval;
444 |
445 | <% if '${raise_exceptions}' is not null then %>
446 | EXCEPTION
447 | WHEN OTHERS
448 | THEN
449 | logger.log_error('Unhandled Exception', l_scope, NULL, l_params);
450 | RAISE;
451 | <%end if; %>
452 | END hash;
453 |
454 | FUNCTION hash_rowid (p_rowid IN varchar2)
455 | RETURN varchar2
456 | IS
457 | <% if '${raise_exceptions}' is not null then %>
458 | l_scope logger_logs.scope%TYPE := gc_scope_prefix || 'hash_rowid';
459 | l_params logger.tab_param;
460 | <% end if; %>
461 | l_retval hash_t;
462 | l_string CLOB;
463 | l_date_format varchar2(64);
464 | BEGIN
465 | <% if '${raise_exceptions}' is not null then %>
466 | logger.append_param(l_params, 'p_rowid', p_rowid);
467 | logger.LOG('START', l_scope, NULL, l_params);
468 | logger.LOG('Getting row data into one string', l_scope);
469 | <% end if; %>
470 |
471 | --Get actual NLS_DATE_FORMAT
472 | SELECT VALUE INTO l_date_format FROM v$nls_parameters WHERE parameter ='NLS_DATE_FORMAT';
473 |
474 | --Alter session for date columns
475 | EXECUTE IMMEDIATE 'ALTER SESSION SET NLS_DATE_FORMAT=''YYYY/MM/DD hh24:mi:ss''';
476 |
477 | SELECT
478 | <% c := noblob.last+1; for i in 1 .. noblob.last loop %>
479 | <%=noblob(i).column_name%><%sep(c-i,'||');%>\\n
480 | <% end loop; %>
481 | INTO l_string
482 | FROM ${table_name}
483 | WHERE ROWID = hash_rowid.p_rowid;
484 |
485 | --Restore NLS_DATE_FORMAT to default
486 | EXECUTE IMMEDIATE 'ALTER SESSION SET NLS_DATE_FORMAT=''' || l_date_format|| '''';
487 |
488 | <% if '${raise_exceptions}' is not null then %>
489 | logger.LOG('Converting into SHA1 hash', l_scope);
490 | <% end if; %>
491 | l_retval := DBMS_CRYPTO.hash(l_string, DBMS_CRYPTO.hash_sh1);
492 |
493 | <% if '${raise_exceptions}' is not null then %>
494 | logger.LOG('END', l_scope);
495 | <% end if; %>
496 | RETURN l_retval;
497 |
498 | <% if '${raise_exceptions}' is not null then %>
499 | EXCEPTION
500 | WHEN OTHERS
501 | THEN
502 | logger.log_error('Unhandled Exception', l_scope, NULL, l_params);
503 | RAISE;
504 | <% end if; %>
505 | END hash_rowid;
506 |
507 | FUNCTION rt (
508 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
509 | p_<%=pk(i).column_name%> IN ${table_name}.<%=pk(i).column_name %>%TYPE<%sep(c-i,',');%>\\n
510 | <% end loop; %>
511 | )
512 | RETURN ${table_name}_rt ${result_cache}
513 | IS
514 | <% if '${raise_exceptions}' is not null then %>
515 | l_scope logger_logs.scope%TYPE := gc_scope_prefix || 'rt';
516 | l_params logger.tab_param;
517 | <% end if; %>
518 | l_${table_name}_rec ${table_name}_rt;
519 | BEGIN
520 | <% if '${raise_exceptions}' is not null then
521 | c := pk.last+1; for i in 1 .. pk.last loop %>
522 | logger.append_param(l_params, 'p_<%=pk(i).column_name%>', p_<%=pk(i).column_name%>);
523 | <% end loop; %>
524 | logger.LOG('START', l_scope, NULL, l_params);
525 | logger.LOG('Populating record type from DB', l_scope);
526 | <% end if; %>
527 |
528 | SELECT a.*,
529 | tapi_${table_name}.hash(<% c := pk.last+1; for i in 1 .. pk.last loop %><%=pk(i).column_name%><%sep(c-i,','); end loop; %>),
530 | rowid
531 | INTO l_${table_name}_rec
532 | FROM ${table_name} a
533 | WHERE
534 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
535 | <%=pk(i).column_name%> = rt.p_<%=pk(i).column_name%><%sep(c-i,' AND ' );%>\\n
536 | <% end loop; %>
537 | ;
538 |
539 | <% if '${raise_exceptions}' is not null then %>
540 | logger.LOG('END', l_scope);
541 | <% end if; %>
542 |
543 | RETURN l_${table_name}_rec;
544 |
545 | <% if '${raise_exceptions}' is not null then %>
546 | EXCEPTION
547 | WHEN OTHERS
548 | THEN
549 | logger.log_error('Unhandled Exception', l_scope, NULL, l_params);
550 | RAISE;
551 | <% end if; %>
552 | END rt;
553 |
554 | FUNCTION rt_for_update (
555 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
556 | p_<%=pk(i).column_name%> IN ${table_name}.<%=pk(i).column_name %>%TYPE<%sep(c-i,',');%>\\n
557 | <% end loop; %>
558 | )
559 | RETURN ${table_name}_rt ${result_cache}
560 | IS
561 | <% if '${raise_exceptions}' is not null then %>
562 | l_scope logger_logs.scope%TYPE := gc_scope_prefix || 'rt_for_update';
563 | l_params logger.tab_param;
564 | <% end if; %>
565 | l_${table_name}_rec ${table_name}_rt;
566 | BEGIN
567 |
568 | <% if '${raise_exceptions}' is not null then
569 | c := pk.last+1; for i in 1 .. pk.last loop %>
570 | logger.append_param(l_params, 'p_<%=pk(i).column_name%>', p_<%=pk(i).column_name%>);
571 | <% end loop; %>
572 | logger.LOG('START', l_scope, NULL, l_params);
573 | logger.LOG('Populating record type from DB', l_scope);
574 | <% end if; %>
575 |
576 | SELECT a.*,
577 | tapi_${table_name}.hash(<% c := pk.last+1; for i in 1 .. pk.last loop %><%=pk(i).column_name%><%sep(c-i,','); end loop; %>),
578 | rowid
579 | INTO l_${table_name}_rec
580 | FROM ${table_name} a
581 | WHERE
582 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
583 | <%=pk(i).column_name%> = rt_for_update.p_<%=pk(i).column_name%><%sep(c-i,' AND ');%>\\n
584 | <% end loop; %>
585 | FOR UPDATE;
586 |
587 | <% if '${raise_exceptions}' is not null then %>
588 | logger.LOG('END', l_scope);
589 | <% end if; %>
590 |
591 | RETURN l_${table_name}_rec;
592 |
593 | <% if '${raise_exceptions}' is not null then %>
594 | EXCEPTION
595 | WHEN OTHERS
596 | THEN
597 | logger.log_error('Unhandled Exception', l_scope, NULL, l_params);
598 | RAISE;
599 | <% end if; %>
600 | END rt_for_update;
601 |
602 | FUNCTION tt (
603 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
604 | p_<%=pk(i).column_name%> IN ${table_name}.<%=pk(i).column_name %>%TYPE DEFAULT NULL<%sep(c-i,',');%>\\n
605 | <% end loop; %>
606 | )
607 | RETURN ${table_name}_tt
608 | PIPELINED
609 | IS
610 | <% if '${raise_exceptions}' is not null then %>
611 | l_scope logger_logs.scope%TYPE := gc_scope_prefix || 'tt';
612 | l_params logger.tab_param;
613 | <% end if; %>
614 | l_${table_name}_rec ${table_name}_rt;
615 | BEGIN
616 | <% if '${raise_exceptions}' is not null then
617 | c := pk.last+1; for i in 1 .. pk.last loop %>
618 | logger.append_param(l_params, 'p_<%=pk(i).column_name%>', tt.p_<%=pk(i).column_name%>);
619 | <% end loop; %>
620 | logger.LOG('START', l_scope, NULL, l_params);
621 | logger.LOG('Populating record type from DB', l_scope);
622 | <% end if; %>
623 |
624 | FOR c1 IN (SELECT a.*, ROWID
625 | FROM ${table_name} a
626 | WHERE
627 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
628 | <%=pk(i).column_name%> = NVL(tt.p_<%=pk(i).column_name%>,<%=pk(i).column_name%>)<%sep(c-i,' AND ');%>\\n
629 | <% end loop; %>
630 | )
631 | LOOP
632 | <% for i in 1 .. col.last loop %>
633 | l_${table_name}_rec.<%=col(i).column_name%> := c1.<%=col(i).column_name%>;
634 | <% end loop; %>
635 | l_${table_name}_rec.hash := tapi_${table_name}.hash(<% c := pk.last+1; for i in 1 .. pk.last loop %> c1.<%=pk(i).column_name%><%sep(c-i,',');%><% end loop; %>);
636 | l_${table_name}_rec.row_id := c1.ROWID;
637 | PIPE ROW (l_${table_name}_rec);
638 | END LOOP;
639 | <% if '${raise_exceptions}' is not null then %>
640 |
641 | logger.LOG('END', l_scope);
642 | <% end if; %>
643 |
644 | RETURN;
645 |
646 | <% if '${raise_exceptions}' is not null then %>
647 | EXCEPTION
648 | WHEN OTHERS
649 | THEN
650 | logger.log_error('Unhandled Exception', l_scope, NULL, l_params);
651 | RAISE;
652 | <% end if; %>
653 | END tt;
654 |
655 |
656 | PROCEDURE ins (p_${table_name}_rec IN OUT ${table_name}_rt)
657 | IS
658 | <% if '${raise_exceptions}' is not null then %>
659 | l_scope logger_logs.scope%TYPE := gc_scope_prefix || 'ins';
660 | l_params logger.tab_param;
661 | <% end if; %>
662 | l_rowtype ${table_name}%ROWTYPE;
663 | <% if '${created_by_col_name}' is not null
664 | or '${modified_by_col_name}' is not null
665 | then
666 | if '${created_by_col_name}' is not null
667 | then%>
668 | l_user_name ${table_name}.${created_by_col_name}%TYPE := USER;/*dbax_core.g$username or apex_application.g_user*/
669 | <%else%>
670 | l_user_name ${table_name}.${modified_by_col_name}%TYPE := USER;/*dbax_core.g$username or apex_application.g_user*/
671 | <% end if;
672 | end if;
673 | if '${created_date_col_name}' is not null
674 | or '${modified_date_col_name}' is not null
675 | then
676 | if '${created_date_col_name}' is not null
677 | then %>
678 | l_date ${table_name}.${created_date_col_name}%TYPE := SYSDATE;
679 | <%else%>
680 | l_date ${table_name}.${modified_date_col_name}%TYPE := SYSDATE;
681 | <% end if;
682 | end if; %>
683 |
684 | BEGIN
685 | <% if '${raise_exceptions}' is not null then
686 | for i in 1 .. col.last loop %>
687 | logger.append_param(l_params, 'p_${table_name}_rec.<%=col(i).column_name%>', ins.p_${table_name}_rec.<%=col(i).column_name%>);
688 | <% end loop; %>
689 | logger.LOG('START', l_scope, NULL, l_params);
690 | logger.LOG('Inserting data', l_scope);
691 | <% end if;%>
692 |
693 | <% if '${created_by_col_name}'Is not null then%>
694 | p_${table_name}_rec.${created_by_col_name} := l_user_name;
695 | <% end if; %>!\n
696 | <% if '${created_date_col_name}' is not null then %>
697 | p_${table_name}_rec.${created_date_col_name} := l_date;
698 | <% end if; %>!\n
699 | <% if '${modified_by_col_name}' is not null then %>
700 | p_${table_name}_rec.${modified_by_col_name} := l_user_name;
701 | <% end if;%>!\n
702 | <% if '${modified_date_col_name}' is not null then %>
703 | p_${table_name}_rec.${modified_date_col_name} := l_date;
704 | <% end if; %>
705 |
706 | <% for i in 1 .. col.last loop %>
707 | l_rowtype.<%=col(i).column_name%> := ins.p_${table_name}_rec.<%=col(i).column_name%>;
708 | <% end loop; %>
709 |
710 | INSERT INTO ${table_name}
711 | VALUES l_rowtype
712 | RETURNING
713 | <% c := col.last+1; for i in 1 .. col.last loop %>
714 | <%=col(i).column_name%> <%sep(c-i,',');%>\\n
715 | <% end loop; %>
716 | INTO l_rowtype;
717 |
718 | <% for i in 1 .. col.last loop %>
719 | ins.p_${table_name}_rec.<%=col(i).column_name%> := l_rowtype.<%=col(i).column_name%>;
720 | <% end loop; %>
721 |
722 |
723 | <% if '${raise_exceptions}' is not null then %>
724 | logger.LOG('END', l_scope);
725 | <%end if; %>
726 |
727 | <% if '${raise_exceptions}' is not null then %>
728 | EXCEPTION
729 | WHEN OTHERS
730 | THEN
731 | logger.log_error('Unhandled Exception', l_scope, NULL, l_params);
732 | RAISE;
733 | <% end if; %>
734 | END ins;
735 |
736 | PROCEDURE upd (
737 | p_${table_name}_rec IN ${table_name}_rt,
738 | p_ignore_nulls IN boolean := FALSE
739 | )
740 | IS
741 | <% if '${raise_exceptions}' is not null then %>
742 | l_scope logger_logs.scope%TYPE := gc_scope_prefix || 'upd';
743 | l_params logger.tab_param;
744 | <% end if; %>
745 | BEGIN
746 | <% if '${raise_exceptions}' is not null then
747 | for i in 1 .. col.last loop %>
748 | logger.append_param(l_params, 'p_${table_name}_rec.<%=col(i).column_name%>', upd.p_${table_name}_rec.<%=col(i).column_name%>);
749 | <% end loop; %>
750 | logger.LOG('START', l_scope, NULL, l_params);
751 | logger.LOG('Updating table', l_scope);
752 | <% end if; %>
753 |
754 | IF NVL (p_ignore_nulls, FALSE)
755 | THEN
756 | UPDATE ${table_name}
757 | SET <% c := col.last+1; for i in 1 .. col.last loop
758 | column_for_update(col(i).column_name,true,c-i);
759 | end loop; %>\\n
760 | WHERE
761 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
762 | <%=pk(i).column_name%> = upd.p_${table_name}_rec.<%=pk(i).column_name%><%sep(c-i,' AND ');%>\\n
763 | <% end loop; %>
764 | ;
765 | ELSE
766 | UPDATE ${table_name}
767 | SET <% c := col.last+1; for i in 1 .. col.last loop
768 | column_for_update(col(i).column_name,false,c-i);
769 | end loop; %>\\n
770 | WHERE
771 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
772 | <%=pk(i).column_name%> = upd.p_${table_name}_rec.<%=pk(i).column_name%><%sep(c-i,' AND ');%>\\n
773 | <% end loop; %>
774 | ;
775 | END IF;
776 |
777 | IF SQL%ROWCOUNT != 1 THEN RAISE e_upd_failed; END IF;
778 | <% if '${raise_exceptions}' is not null then %>
779 | logger.LOG('END', l_scope);
780 | <%end if; %>
781 |
782 | EXCEPTION
783 | WHEN e_upd_failed
784 | THEN
785 | raise_application_error (-20000, 'No rows were updated. The update failed.');
786 | <% if '${raise_exceptions}' is not null then %>
787 | WHEN OTHERS
788 | THEN
789 | logger.log_error('Unhandled Exception', l_scope, NULL, l_params);
790 | RAISE;
791 | <% end if; %>
792 | END upd;
793 |
794 |
795 | PROCEDURE upd_rowid (
796 | p_${table_name}_rec IN ${table_name}_rt,
797 | p_ignore_nulls IN boolean := FALSE
798 | )
799 | IS
800 | <% if '${raise_exceptions}' is not null then %>
801 | l_scope logger_logs.scope%TYPE := gc_scope_prefix || 'upd_rowid';
802 | l_params logger.tab_param;
803 | <% end if; %>
804 | BEGIN
805 | <% if '${raise_exceptions}' is not null then
806 | for i in 1 .. col.last loop %>
807 | logger.append_param(l_params, 'p_${table_name}_rec.<%=col(i).column_name%>', upd_rowid.p_${table_name}_rec.<%=col(i).column_name%>);
808 | <% end loop; %>
809 | logger.LOG('START', l_scope, NULL, l_params);
810 | logger.LOG('Updating table', l_scope);
811 | <% end if; %>
812 |
813 | IF NVL (p_ignore_nulls, FALSE)
814 | THEN
815 | UPDATE ${table_name}
816 | SET <% c := col.last+1; for i in 1 .. col.last loop
817 | column_for_update(col(i).column_name,true,c-i);
818 | end loop; %>\\n
819 | WHERE ROWID = p_${table_name}_rec.row_id;
820 | ELSE
821 | UPDATE ${table_name}
822 | SET <% c := col.last+1; for i in 1 .. col.last loop
823 | column_for_update(col(i).column_name,false,c-i);
824 | end loop; %>\\n
825 | WHERE ROWID = p_${table_name}_rec.row_id;
826 | END IF;
827 |
828 | IF SQL%ROWCOUNT != 1 THEN RAISE e_upd_failed; END IF;
829 | <% if '${raise_exceptions}' is not null then %>
830 | logger.LOG('END', l_scope);
831 | <%end if; %>
832 |
833 | EXCEPTION
834 | WHEN e_upd_failed
835 | THEN
836 | raise_application_error (-20000, 'No rows were updated. The update failed.');
837 | <% if '${raise_exceptions}' is not null then %>
838 | WHEN OTHERS
839 | THEN
840 | logger.log_error('Unhandled Exception', l_scope, NULL, l_params);
841 | RAISE;
842 | <% end if; %>
843 | END upd_rowid;
844 |
845 | PROCEDURE web_upd (
846 | p_${table_name}_rec IN ${table_name}_rt,
847 | p_ignore_nulls IN boolean := FALSE
848 | )
849 | IS
850 | <% if '${raise_exceptions}' is not null then %>
851 | l_scope logger_logs.scope%TYPE := gc_scope_prefix || 'web_upd';
852 | l_params logger.tab_param;
853 | <% end if; %>
854 | l_${table_name}_rec ${table_name}_rt;
855 | BEGIN
856 | <% if '${raise_exceptions}' is not null then
857 | for i in 1 .. col.last loop %>
858 | logger.append_param(l_params, 'p_${table_name}_rec.<%=col(i).column_name%>', web_upd.p_${table_name}_rec.<%=col(i).column_name%>);
859 | <% end loop; %>
860 | logger.LOG('START', l_scope, NULL, l_params);
861 | logger.LOG('Updating table', l_scope);
862 | <% end if; %>
863 |
864 | OPEN ${table_name}_cur(
865 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
866 | web_upd.p_${table_name}_rec.<%=pk(i).column_name%><%sep(c-i,',');%>\\n
867 | <% end loop; %>
868 | );
869 |
870 | FETCH ${table_name}_cur INTO l_${table_name}_rec;
871 |
872 | IF ${table_name}_cur%NOTFOUND THEN
873 | CLOSE ${table_name}_cur;
874 | RAISE e_row_missing;
875 | ELSE
876 | IF p_${table_name}_rec.hash != l_${table_name}_rec.hash THEN
877 | CLOSE ${table_name}_cur;
878 | RAISE e_ol_check_failed;
879 | ELSE
880 | IF NVL(p_ignore_nulls, FALSE)
881 | THEN
882 |
883 | UPDATE ${table_name}
884 | SET <% c := col.last+1; for i in 1 .. col.last loop
885 | column_for_update(col(i).column_name,true,c-i, 23);
886 | end loop; %>\\n
887 | WHERE CURRENT OF ${table_name}_cur;
888 | ELSE
889 | UPDATE ${table_name}
890 | SET <% c := col.last+1; for i in 1 .. col.last loop
891 | column_for_update(col(i).column_name,false,c-i,23);
892 | end loop; %>\\n
893 | WHERE CURRENT OF ${table_name}_cur;
894 | END IF;
895 |
896 | CLOSE ${table_name}_cur;
897 | END IF;
898 | END IF;
899 |
900 | <% if '${raise_exceptions}' is not null then %>
901 | logger.LOG('END', l_scope);
902 | <%end if; %>
903 |
904 | EXCEPTION
905 | WHEN e_ol_check_failed
906 | THEN
907 | raise_application_error (-20000 , 'Current version of data in database has changed since last page refresh.');
908 | WHEN e_row_missing
909 | THEN
910 | raise_application_error (-20000 , 'Update operation failed because the row is no longer in the database.');
911 | <% if '${raise_exceptions}' is not null then %>
912 | WHEN OTHERS
913 | THEN
914 | logger.log_error('Unhandled Exception', l_scope, NULL, l_params);
915 | RAISE;
916 | <% end if; %>
917 | END web_upd;
918 |
919 | PROCEDURE web_upd_rowid (
920 | p_${table_name}_rec IN ${table_name}_rt,
921 | p_ignore_nulls IN boolean := FALSE
922 | )
923 | IS
924 | <% if '${raise_exceptions}' is not null then %>
925 | l_scope logger_logs.scope%TYPE := gc_scope_prefix || 'web_upd_rowid';
926 | l_params logger.tab_param;
927 | <% end if; %>
928 | l_${table_name}_rec ${table_name}_rt;
929 | BEGIN
930 | <% if '${raise_exceptions}' is not null then
931 | for i in 1 .. col.last loop %>
932 | logger.append_param(l_params, 'p_${table_name}_rec.<%=col(i).column_name%>', web_upd_rowid.p_${table_name}_rec.<%=col(i).column_name%>);
933 | <% end loop; %>
934 | logger.LOG('START', l_scope, NULL, l_params);
935 | logger.LOG('Updating table', l_scope);
936 | <% end if; %>
937 |
938 | OPEN ${table_name}_rowid_cur(web_upd_rowid.p_${table_name}_rec.row_id);
939 |
940 | FETCH ${table_name}_rowid_cur INTO l_${table_name}_rec;
941 |
942 | IF ${table_name}_rowid_cur%NOTFOUND THEN
943 | CLOSE ${table_name}_rowid_cur;
944 | RAISE e_row_missing;
945 | ELSE
946 | IF web_upd_rowid.p_${table_name}_rec.hash != l_${table_name}_rec.hash THEN
947 | CLOSE ${table_name}_rowid_cur;
948 | RAISE e_ol_check_failed;
949 | ELSE
950 | IF NVL(web_upd_rowid.p_ignore_nulls, FALSE)
951 | THEN
952 | UPDATE ${table_name}
953 | SET <% c := col.last+1; for i in 1 .. col.last loop
954 | column_for_update(col(i).column_name,true,c-i,23);
955 | end loop; %>\\n
956 | WHERE CURRENT OF ${table_name}_rowid_cur;
957 | ELSE
958 | UPDATE ${table_name}
959 | SET <% c := col.last+1; for i in 1 .. col.last loop
960 | column_for_update(col(i).column_name,false,c-i,23);
961 | end loop; %>\\n
962 | WHERE CURRENT OF ${table_name}_rowid_cur;
963 | END IF;
964 |
965 | CLOSE ${table_name}_rowid_cur;
966 | END IF;
967 | END IF;
968 |
969 | <% if '${raise_exceptions}' is not null then %>
970 | logger.LOG('END', l_scope);
971 | <%end if; %>
972 |
973 | EXCEPTION
974 | WHEN e_ol_check_failed
975 | THEN
976 | raise_application_error (-20000 , 'Current version of data in database has changed since last page refresh.');
977 | WHEN e_row_missing
978 | THEN
979 | raise_application_error (-20000 , 'Update operation failed because the row is no longer in the database.');
980 | <% if '${raise_exceptions}' is not null then %>
981 | WHEN OTHERS
982 | THEN
983 | logger.log_error('Unhandled Exception', l_scope, NULL, l_params);
984 | RAISE;
985 | <% end if; %>
986 | END web_upd_rowid;
987 |
988 | PROCEDURE del (
989 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
990 | p_<%=pk(i).column_name%> IN ${table_name}.<%=pk(i).column_name %>%TYPE<%sep(c-i,',');%>\\n
991 | <% end loop; %>
992 | )
993 | IS
994 | <% if '${raise_exceptions}' is not null then %>
995 | l_scope logger_logs.scope%TYPE := gc_scope_prefix || 'del';
996 | l_params logger.tab_param;
997 | <% end if; %>
998 | BEGIN
999 | <% if '${raise_exceptions}' is not null then
1000 | c := pk.last+1; for i in 1 .. pk.last loop %>
1001 | logger.append_param(l_params, 'p_<%=pk(i).column_name%>', del.p_<%=pk(i).column_name%>);
1002 | <% end loop; %>
1003 | logger.LOG('START', l_scope, NULL, l_params);
1004 | logger.LOG('Deleting record', l_scope);
1005 | <% end if; %>
1006 |
1007 | DELETE FROM ${table_name}
1008 | WHERE
1009 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
1010 | <%=pk(i).column_name%> = del.p_<%=pk(i).column_name%><%sep(c-i,' AND ');%>\\n
1011 | <% end loop; %>
1012 | ;
1013 |
1014 | IF sql%ROWCOUNT != 1
1015 | THEN
1016 | RAISE e_del_failed;
1017 | END IF;
1018 |
1019 | <% if '${raise_exceptions}' is not null then %>
1020 | logger.LOG('END', l_scope);
1021 | <%end if; %>
1022 |
1023 | EXCEPTION
1024 | WHEN e_del_failed
1025 | THEN
1026 | raise_application_error (-20000, 'No rows were deleted. The delete failed.');
1027 | <% if '${raise_exceptions}' is not null then %>
1028 | WHEN OTHERS
1029 | THEN
1030 | logger.log_error('Unhandled Exception', l_scope, NULL, l_params);
1031 | RAISE;
1032 | <% end if; %>
1033 | END del;
1034 |
1035 | PROCEDURE del_rowid (p_rowid IN varchar2)
1036 | IS
1037 | <% if '${raise_exceptions}' is not null then %>
1038 | l_scope logger_logs.scope%TYPE := gc_scope_prefix || 'del_rowid';
1039 | l_params logger.tab_param;
1040 | <% end if; %>
1041 | BEGIN
1042 | <% if '${raise_exceptions}' is not null then %>
1043 | logger.append_param(l_params, 'p_rowid', del_rowid.p_rowid);
1044 | logger.LOG('START', l_scope, NULL, l_params);
1045 | logger.LOG('Deleting record', l_scope);
1046 | <% end if; %>
1047 |
1048 | DELETE FROM ${table_name}
1049 | WHERE ROWID = del_rowid.p_rowid;
1050 |
1051 | IF sql%ROWCOUNT != 1
1052 | THEN
1053 | RAISE e_del_failed;
1054 | END IF;
1055 |
1056 | <% if '${raise_exceptions}' is not null then %>
1057 | logger.LOG('END', l_scope);
1058 | <%end if; %>
1059 |
1060 | EXCEPTION
1061 | WHEN e_del_failed
1062 | THEN
1063 | raise_application_error (-20000, 'No rows were deleted. The delete failed.');
1064 | <% if '${raise_exceptions}' is not null then %>
1065 | WHEN OTHERS
1066 | THEN
1067 | logger.log_error('Unhandled Exception', l_scope, NULL, l_params);
1068 | RAISE;
1069 | <% end if; %>
1070 | END del_rowid;
1071 |
1072 | PROCEDURE web_del (
1073 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
1074 | p_<%=pk(i).column_name%> IN ${table_name}.<%=pk(i).column_name %>%TYPE,
1075 | <% end loop; %>
1076 | p_hash IN varchar2
1077 | )
1078 | IS
1079 | <% if '${raise_exceptions}' is not null then %>
1080 | l_scope logger_logs.scope%TYPE := gc_scope_prefix || 'web_del';
1081 | l_params logger.tab_param;
1082 | <% end if; %>
1083 | l_${table_name}_rec ${table_name}_rt;
1084 | BEGIN
1085 |
1086 | <% if '${raise_exceptions}' is not null then
1087 | c := pk.last+1; for i in 1 .. pk.last loop %>
1088 | logger.append_param(l_params, 'p_<%=pk(i).column_name%>', web_del.p_<%=pk(i).column_name%>);
1089 | <% end loop; %>
1090 | logger.LOG('START', l_scope, NULL, l_params);
1091 | logger.LOG('Deleting record', l_scope);
1092 | <% end if; %>
1093 |
1094 | OPEN ${table_name}_cur(
1095 | <% c := pk.last+1; for i in 1 .. pk.last loop %>
1096 | web_del.p_<%=pk(i).column_name%><%sep(c-i,',');%>\\n
1097 | <% end loop; %>
1098 | );
1099 |
1100 | FETCH ${table_name}_cur INTO l_${table_name}_rec;
1101 |
1102 | IF ${table_name}_cur%NOTFOUND THEN
1103 | CLOSE ${table_name}_cur;
1104 | RAISE e_row_missing;
1105 | ELSE
1106 | IF web_del.p_hash != l_${table_name}_rec.hash THEN
1107 | CLOSE ${table_name}_cur;
1108 | RAISE e_ol_check_failed;
1109 | ELSE
1110 | DELETE FROM ${table_name}
1111 | WHERE CURRENT OF ${table_name}_cur;
1112 |
1113 | CLOSE ${table_name}_cur;
1114 | END IF;
1115 | END IF;
1116 |
1117 |
1118 | <% if '${raise_exceptions}' is not null then %>
1119 | logger.LOG('END', l_scope);
1120 | <%end if; %>
1121 |
1122 | EXCEPTION
1123 | WHEN e_ol_check_failed
1124 | THEN
1125 | raise_application_error (-20000 , 'Current version of data in database has changed since last page refresh.');
1126 | WHEN e_row_missing
1127 | THEN
1128 | raise_application_error (-20000 , 'Delete operation failed because the row is no longer in the database.');
1129 | <% if '${raise_exceptions}' is not null then %>
1130 | WHEN OTHERS
1131 | THEN
1132 | logger.log_error('Unhandled Exception', l_scope, NULL, l_params);
1133 | RAISE;
1134 | <% end if; %>
1135 | END web_del;
1136 |
1137 | PROCEDURE web_del_rowid (p_rowid IN varchar2, p_hash IN varchar2)
1138 | IS
1139 | <% if '${raise_exceptions}' is not null then %>
1140 | l_scope logger_logs.scope%TYPE := gc_scope_prefix || 'web_del_rowid';
1141 | l_params logger.tab_param;
1142 | <% end if; %>
1143 | l_${table_name}_rec ${table_name}_rt;
1144 | BEGIN
1145 |
1146 | <% if '${raise_exceptions}' is not null then %>
1147 | logger.append_param(l_params, 'p_rowid', web_del_rowid.p_rowid);
1148 | logger.LOG('START', l_scope, NULL, l_params);
1149 | logger.LOG('Deleting record', l_scope);
1150 | <% end if; %>
1151 |
1152 | OPEN ${table_name}_rowid_cur(web_del_rowid.p_rowid);
1153 |
1154 | FETCH ${table_name}_rowid_cur INTO l_${table_name}_rec;
1155 |
1156 | IF ${table_name}_rowid_cur%NOTFOUND THEN
1157 | CLOSE ${table_name}_rowid_cur;
1158 | RAISE e_row_missing;
1159 | ELSE
1160 | IF web_del_rowid.p_hash != l_${table_name}_rec.hash THEN
1161 | CLOSE ${table_name}_rowid_cur;
1162 | RAISE e_ol_check_failed;
1163 | ELSE
1164 | DELETE FROM ${table_name}
1165 | WHERE CURRENT OF ${table_name}_rowid_cur;
1166 |
1167 | CLOSE ${table_name}_rowid_cur;
1168 | END IF;
1169 | END IF;
1170 |
1171 | <% if '${raise_exceptions}' is not null then %>
1172 | logger.LOG('END', l_scope);
1173 | <%end if; %>
1174 | EXCEPTION
1175 | WHEN e_ol_check_failed
1176 | THEN
1177 | raise_application_error (-20000 , 'Current version of data in database has changed since last page refresh.');
1178 | WHEN e_row_missing
1179 | THEN
1180 | raise_application_error (-20000 , 'Delete operation failed because the row is no longer in the database.');
1181 | <% if '${raise_exceptions}' is not null then %>
1182 | WHEN OTHERS
1183 | THEN
1184 | logger.log_error('Unhandled Exception', l_scope, NULL, l_params);
1185 | RAISE;
1186 | <% end if; %>
1187 | END web_del_rowid;
1188 |
1189 | END tapi_${table_name};
1190 |
1191 | $end
1192 |
1193 | END tapi_gen2;
1194 | /
1195 |
--------------------------------------------------------------------------------