Add routines to mip_quotation.pck and mip_*_helper (via gen_mandatory.prc) packages to set to NULL fields in the enquiry that are not relevant for that enquiry type (following issue raised in UAT).

git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@13609 248e525c-4dfb-0310-94bc-949c084e9493
This commit is contained in:
andrew.hardy
2009-11-20 15:59:47 +00:00
parent 651a1ab38c
commit 81db2835f2
2 changed files with 108 additions and 38 deletions

View File

@@ -7,7 +7,7 @@ CREATE OR REPLACE PROCEDURE gen_mandatory IS
PROCEDURE add_sql(p_sqla IN OUT dbms_sql.varchar2a
,p_sql IN VARCHAR2) IS
l_idx BINARY_INTEGER := p_sqla.COUNT + 1;
l_idx BINARY_INTEGER := p_sqla.count + 1;
BEGIN
p_sqla(l_idx) := p_sql;
END add_sql;
@@ -20,7 +20,7 @@ BEGIN
FROM enquiry_types) LOOP
BEGIN
l_cursor_id := dbms_sql.open_cursor;
l_sql.DELETE;
l_sql.delete;
add_sql(l_sql
,'INSERT INTO DATA_ITEM_ROLES');
add_sql(l_sql
@@ -69,11 +69,11 @@ BEGIN
--dbms_output.put_line(l_sql);
dbms_sql.parse(l_cursor_id
,l_sql
,l_sql.FIRST
,l_sql.LAST
,l_sql.first
,l_sql.last
,TRUE
,dbms_sql.native);
l_rows_inserted := dbms_sql.EXECUTE(l_cursor_id);
l_rows_inserted := dbms_sql.execute(l_cursor_id);
dbms_sql.close_cursor(l_cursor_id);
EXCEPTION
WHEN OTHERS THEN
@@ -104,7 +104,7 @@ BEGIN
-- START OF PACKAGE SPECIFICATION
--
l_sql.DELETE;
l_sql.delete;
add_sql(l_sql
,'CREATE OR REPLACE PACKAGE MIP_' || l_tables.table_name ||
@@ -113,7 +113,7 @@ BEGIN
,' ');
add_sql(l_sql
,' -- AUTOMATICALLY GENERATED BY GEN_MANDATORY AT ' ||
to_char(SYSDATE
TO_CHAR(SYSDATE
,'DD-MON-YYYY HH24:MI:SS'));
add_sql(l_sql
,' ');
@@ -139,8 +139,8 @@ BEGIN
add_sql(l_sql
,'FUNCTION check_mandatory (');
FOR l_idx IN l_pk_cols.FIRST .. l_pk_cols.LAST LOOP
IF l_idx != l_pk_cols.FIRST THEN
FOR l_idx IN l_pk_cols.first .. l_pk_cols.last LOOP
IF l_idx != l_pk_cols.first THEN
add_sql(l_sql
,' ,P_' || l_pk_cols(l_idx) || ' IN ' ||
l_tables.table_name || '.' || l_pk_cols(l_idx) || '%TYPE');
@@ -177,8 +177,8 @@ BEGIN
add_sql(l_sql
,'FUNCTION record_exists (');
FOR l_idx IN l_pk_cols.FIRST .. l_pk_cols.LAST LOOP
IF l_idx != l_pk_cols.FIRST THEN
FOR l_idx IN l_pk_cols.first .. l_pk_cols.last LOOP
IF l_idx != l_pk_cols.first THEN
add_sql(l_sql
,' ,P_' || l_pk_cols(l_idx) || ' IN ' ||
l_tables.table_name || '.' || l_pk_cols(l_idx) || '%TYPE');
@@ -213,17 +213,37 @@ BEGIN
,' RETURN VARCHAR2;');
add_sql(l_sql
,' ');
add_sql(l_sql
,'PROCEDURE purge_fields (');
FOR l_idx IN l_pk_cols.first .. l_pk_cols.last LOOP
IF l_idx != l_pk_cols.first THEN
add_sql(l_sql
,' ,P_' || l_pk_cols(l_idx) || ' IN ' ||
l_tables.table_name || '.' || l_pk_cols(l_idx) || '%TYPE');
ELSE
add_sql(l_sql
,' P_' || l_pk_cols(l_idx) || ' IN ' ||
l_tables.table_name || '.' || l_pk_cols(l_idx) || '%TYPE');
END IF;
END LOOP;
add_sql(l_sql
,' );');
add_sql(l_sql
,' ');
add_sql(l_sql
,'END MIP_' || l_tables.table_name || '_HELPER;');
l_cursor_id := dbms_sql.open_cursor;
dbms_sql.parse(l_cursor_id
,l_sql
,l_sql.FIRST
,l_sql.LAST
,l_sql.first
,l_sql.last
,TRUE
,dbms_sql.native);
l_rows_inserted := dbms_sql.EXECUTE(l_cursor_id);
l_rows_inserted := dbms_sql.execute(l_cursor_id);
dbms_sql.close_cursor(l_cursor_id);
--
@@ -233,7 +253,7 @@ BEGIN
--
-- START OF PACKAGE BODY
--
l_sql.DELETE;
l_sql.delete;
add_sql(l_sql
,'CREATE OR REPLACE PACKAGE BODY MIP_' || l_tables.table_name ||
'_HELPER IS');
@@ -241,7 +261,7 @@ BEGIN
,' ');
add_sql(l_sql
,' -- AUTOMATICALLY GENERATED BY GEN_MANDATORY AT ' ||
to_char(SYSDATE
TO_CHAR(SYSDATE
,'DD-MON-YYYY HH24:MI:SS'));
add_sql(l_sql
,' ');
@@ -274,7 +294,7 @@ BEGIN
add_sql(l_sql
,' cout_assert.isnotnull(p_rec.enty_code,''NULL enquiry ENTY_CODE'');');
FOR l_checks IN (SELECT field_name
,substr(condition
,SUBSTR(condition
,1
,1) AS condition
,enty_code
@@ -326,8 +346,8 @@ BEGIN
add_sql(l_sql
,'FUNCTION check_mandatory (');
FOR l_idx IN l_pk_cols.FIRST .. l_pk_cols.LAST LOOP
IF l_idx != l_pk_cols.FIRST THEN
FOR l_idx IN l_pk_cols.first .. l_pk_cols.last LOOP
IF l_idx != l_pk_cols.first THEN
add_sql(l_sql
,' ,P_' || l_pk_cols(l_idx) || ' IN ' ||
l_tables.table_name || '.' || l_pk_cols(l_idx) || '%TYPE');
@@ -357,8 +377,8 @@ BEGIN
add_sql(l_sql
,' FROM ' || l_tables.table_name);
FOR l_idx IN l_pk_cols.FIRST .. l_pk_cols.LAST LOOP
IF l_idx != l_pk_cols.FIRST THEN
FOR l_idx IN l_pk_cols.first .. l_pk_cols.last LOOP
IF l_idx != l_pk_cols.first THEN
add_sql(l_sql
,' AND ' || l_pk_cols(l_idx) || ' = P_' ||
l_pk_cols(l_idx));
@@ -428,8 +448,8 @@ BEGIN
add_sql(l_sql
,'FUNCTION record_exists (');
FOR l_idx IN l_pk_cols.FIRST .. l_pk_cols.LAST LOOP
IF l_idx != l_pk_cols.FIRST THEN
FOR l_idx IN l_pk_cols.first .. l_pk_cols.last LOOP
IF l_idx != l_pk_cols.first THEN
add_sql(l_sql
,' ,P_' || l_pk_cols(l_idx) || ' IN ' ||
l_tables.table_name || '.' || l_pk_cols(l_idx) || '%TYPE');
@@ -459,8 +479,8 @@ BEGIN
add_sql(l_sql
,' FROM ' || l_tables.table_name);
FOR l_idx IN l_pk_cols.FIRST .. l_pk_cols.LAST LOOP
IF l_idx != l_pk_cols.FIRST THEN
FOR l_idx IN l_pk_cols.first .. l_pk_cols.last LOOP
IF l_idx != l_pk_cols.first THEN
add_sql(l_sql
,' AND ' || l_pk_cols(l_idx) || ' = P_' ||
l_pk_cols(l_idx));
@@ -510,7 +530,7 @@ BEGIN
,' cout_assert.isnotnull(p_field_name,''NULL enquiry FIELD_NAME'');');
FOR l_checks IN (SELECT upper(field_name) AS field_name
,substr(condition
,SUBSTR(condition
,1
,2) AS condition
,enty_code
@@ -572,6 +592,53 @@ BEGIN
add_sql(l_sql
,' ');
add_sql(l_sql
,'PROCEDURE purge_fields (');
FOR l_idx IN l_pk_cols.first .. l_pk_cols.last LOOP
IF l_idx != l_pk_cols.first THEN
add_sql(l_sql
,' ,P_' || l_pk_cols(l_idx) || ' IN ' ||
l_tables.table_name || '.' || l_pk_cols(l_idx) || '%TYPE');
ELSE
add_sql(l_sql
,' P_' || l_pk_cols(l_idx) || ' IN ' ||
l_tables.table_name || '.' || l_pk_cols(l_idx) || '%TYPE');
END IF;
END LOOP;
add_sql(l_sql
,' ) IS');
add_sql(l_sql
,'BEGIN');
add_sql(l_sql
,' NULL;');
FOR l_rec_update IN (SELECT upper(field_name) AS field_name
,enty_code
FROM data_item_roles
WHERE condition = 'H'
AND table_name = l_tables.table_name) LOOP
add_sql(l_sql
,' UPDATE ' || l_tables.table_name);
add_sql(l_sql
,' SET ' || l_rec_update.field_name || ' = NULL');
add_sql(l_sql
,' WHERE ENTY_CODE = ''' || l_rec_update.enty_code||'''');
FOR l_idx IN l_pk_cols.first .. l_pk_cols.last LOOP
add_sql(l_sql
,' AND ' || l_pk_cols(l_idx) || ' = P_' ||
l_pk_cols(l_idx));
END LOOP;
add_sql(l_sql
,' ;');
END LOOP;
add_sql(l_sql
,'END purge_fields;');
add_sql(l_sql
,'END MIP_' || l_tables.table_name || '_HELPER;');
@@ -582,11 +649,11 @@ BEGIN
l_cursor_id := dbms_sql.open_cursor;
dbms_sql.parse(l_cursor_id
,l_sql
,l_sql.FIRST
,l_sql.LAST
,l_sql.first
,l_sql.last
,TRUE
,dbms_sql.native);
l_rows_inserted := dbms_sql.EXECUTE(l_cursor_id);
l_rows_inserted := dbms_sql.execute(l_cursor_id);
dbms_sql.close_cursor(l_cursor_id);
END LOOP;

View File

@@ -3872,6 +3872,9 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.');
mark_enquiry_submitted(p_enqu_id);
-- remove any spurious values
mip_enquiries_helper.purge_fields(p_id => p_enqu_id);
SELECT *
INTO l_enqu
FROM enquiries