diff --git a/Modules/mip_quotation.pck b/Modules/mip_quotation.pck
index 4e0972f..1f46191 100644
--- a/Modules/mip_quotation.pck
+++ b/Modules/mip_quotation.pck
@@ -27,8 +27,13 @@ CREATE OR REPLACE PACKAGE mip_quotation IS
%param p_id the id of the enquiry to be checked
*/
- PROCEDURE produce_quotes(p_id IN enquiries.id%TYPE);
-
+ PROCEDURE produce_quotes(p_enqu_id IN enquiries.id%TYPE
+ ,p_rfq_prty_id IN parties.id%TYPE
+ ,p_owner_prty_id IN parties.id%TYPE DEFAULT NULL);
+ /** Make quote available
+ %param p_qute_id id of the quote to be marked as available
+ */
+ PROCEDURE make_quote_available(p_qute_id IN quotes.id%TYPE);
/** Accept a quote
%param p_qute_id id of the quote to be accepted
%param p_description optional description to be recorded with the event
@@ -62,7 +67,16 @@ CREATE OR REPLACE PACKAGE mip_quotation IS
PROCEDURE select_quote(p_qute_id IN quotes.id%TYPE
,p_description quote_events.description%TYPE DEFAULT NULL
,p_event_date IN DATE DEFAULT SYSDATE);
+ /** Lapse a quote
+ %param p_qute_id id of the quote to be selected
+ %param p_description optional description to be recorded with the event
+ %param p_event_date optional date for this event (defaults to now)
+ */
+ PROCEDURE lapse_quote(p_qute_id IN quotes.id%TYPE
+ ,p_description quote_events.description%TYPE DEFAULT NULL
+ ,p_event_date IN DATE DEFAULT SYSDATE);
+ PROCEDURE lapse_quotes_job;
END mip_quotation;
/
CREATE OR REPLACE PACKAGE BODY mip_quotation IS
@@ -73,12 +87,12 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
g_internal_reason CONSTANT t_internal_or_external := 'INTERNAL';
g_external_reason CONSTANT t_internal_or_external := 'EXTERNAL';
- SUBTYPE t_manual_or_automatic_quote IS VARCHAR2(9);
+ SUBTYPE t_manual_or_automatic_quote IS VARCHAR2(2);
SUBTYPE t_enqu IS enquiries%ROWTYPE;
- g_manual_quote CONSTANT t_manual_or_automatic_quote := 'MANUAL';
- g_automatic_quote CONSTANT t_manual_or_automatic_quote := 'AUTOMATIC';
+ g_manual_quote CONSTANT t_manual_or_automatic_quote := 'MQ';
+ g_automatic_quote CONSTANT t_manual_or_automatic_quote := 'AQ';
TYPE t_rec_additional_costs IS RECORD(
adit_code additional_items.code%TYPE
@@ -93,7 +107,16 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
,p_description quote_events.description%TYPE DEFAULT NULL
,p_event_date DATE DEFAULT SYSDATE) IS
BEGIN
- NULL; --IF p_qust_code = 'ACCEPTED' THEN;
+ INSERT INTO quote_events
+ (qute_id
+ ,qust_code
+ ,event_date
+ ,description)
+ VALUES
+ (p_qute_id
+ ,p_qust_code
+ ,p_event_date
+ ,p_description);
END add_quote_event;
PROCEDURE accept_quote(p_qute_id IN quotes.id%TYPE
@@ -117,6 +140,16 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
,p_description => p_description);
END reject_quote;
+ PROCEDURE lapse_quote(p_qute_id IN quotes.id%TYPE
+ ,p_description quote_events.description%TYPE DEFAULT NULL
+ ,p_event_date IN DATE DEFAULT SYSDATE) IS
+ BEGIN
+ add_quote_event(p_qute_id => p_qute_id
+ ,p_qust_code => 'LAPSED'
+ ,p_event_date => p_event_date
+ ,p_description => p_description);
+ END lapse_quote;
+
PROCEDURE reject_all_quotes(p_enqu_id IN enquiries.id%TYPE
,p_description quote_events.description%TYPE DEFAULT NULL
,p_event_date IN DATE DEFAULT SYSDATE) IS
@@ -153,9 +186,31 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
END select_quote;
- PROCEDURE request_manual_quote(p_enqu_id IN enquiries.id%TYPE) IS
+ PROCEDURE lapse_quotes_job IS
+ l_current_date DATE := trunc(SYSDATE);
+ l_quote_expiry_date DATE;
+ BEGIN
+ FOR cur_quote IN (SELECT v.qute_id
+ FROM v_current_quote_status v
+ ,quotes q
+ WHERE v.qust_code IN ('AV', 'SELECTED')
+ AND v.qute_id = q.id
+ AND q.valid_until < l_current_date) LOOP
+
+ lapse_quote(p_qute_id => cur_quote.qute_id
+ ,p_description => 'Quote lapsed automatically by system.');
+
+ END LOOP;
+ END lapse_quotes_job;
+
+ FUNCTION start_quote(p_enqu_id IN enquiries.id%TYPE
+ ,p_manual_or_automatic IN VARCHAR2 DEFAULT g_automatic_quote
+ ,p_rfq_prty_id IN parties.id%TYPE
+ ,p_owner_prty_id IN parties.id%TYPE)
+ RETURN quotes.id%TYPE IS
l_qute_id quotes.id%TYPE;
BEGIN
+
INSERT INTO quotes
(id
,qute_type
@@ -166,10 +221,12 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
,created_by)
VALUES
(qute_seq.NEXTVAL
- ,'MQ' -- manual quote
+ ,p_manual_or_automatic
,p_enqu_id
,trunc(SYSDATE)
- ,trunc(SYSDATE + 90)
+ ,(SELECT VALUE + trunc(SYSDATE)
+ FROM system_configuration syco
+ WHERE syco.parameter = 'QUOTE_LAPSE_LIMIT')
,SYSDATE
,USER)
RETURNING id INTO l_qute_id;
@@ -183,6 +240,210 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
,'INP' -- In Progress
,l_qute_id);
+ INSERT INTO quote_roles
+ (prty_id
+ ,qute_id
+ ,rt_code
+ ,start_date)
+ VALUES
+ (p_rfq_prty_id
+ ,l_qute_id
+ ,'Q RFQ'
+ ,SYSDATE);
+
+ INSERT INTO quote_roles
+ (prty_id
+ ,qute_id
+ ,rt_code
+ ,start_date)
+ VALUES
+ (nvl(p_owner_prty_id
+ ,p_rfq_prty_id)
+ ,l_qute_id
+ ,'Q OWN'
+ ,SYSDATE);
+
+ RETURN l_qute_id;
+
+ END start_quote;
+
+ PROCEDURE make_quote_available(p_qute_id IN quotes.id%TYPE) IS
+ BEGIN
+ INSERT INTO quote_events
+ (event_date
+ ,qust_code
+ ,qute_id)
+ VALUES
+ (SYSDATE
+ ,'AV' -- Available
+ ,p_qute_id);
+ END make_quote_available;
+
+ PROCEDURE produce_email(p_enqu_id IN enquiries.id%TYPE) IS
+ l_manual_or_automatic t_manual_or_automatic_quote;
+ l_recipient VARCHAR(240);
+ l_subject VARCHAR2(240);
+ lg_body CLOB;
+ lg_html_body CLOB;
+ lgc_newline CONSTANT CHAR(1) DEFAULT chr(13);
+ l_description enquiry_types.description%TYPE;
+
+ PROCEDURE open_body IS
+ BEGIN
+ dbms_lob.createtemporary(lob_loc => lg_body
+ ,cache => TRUE);
+ dbms_lob.OPEN(lob_loc => lg_body
+ ,open_mode => dbms_lob.lob_readwrite);
+
+ dbms_lob.createtemporary(lob_loc => lg_html_body
+ ,cache => TRUE);
+ dbms_lob.OPEN(lob_loc => lg_html_body
+ ,open_mode => dbms_lob.lob_readwrite);
+ dbms_lob.writeappend(lg_html_body
+ ,length('
')
+ ,'');
+ END open_body;
+
+ PROCEDURE close_body IS
+ BEGIN
+ dbms_lob.writeappend(lg_html_body
+ ,length('')
+ ,'');
+ END close_body;
+
+ PROCEDURE al(p_in IN VARCHAR2) IS
+ BEGIN
+ dbms_lob.writeappend(lg_body
+ ,length(p_in || lgc_newline)
+ ,p_in || lgc_newline);
+
+ dbms_lob.writeappend(lg_html_body
+ ,length(p_in || '
')
+ ,p_in || '
');
+
+ END al;
+ BEGIN
+
+ open_body;
+
+ SELECT description
+ INTO l_description
+ FROM enquiry_types enty
+ ,enquiries enqu
+ WHERE enty.code = enqu.enty_code
+ AND enqu.id = p_enqu_id;
+
+ al('This email has been produced automatically by the WEBMIP quotation system');
+ al(' ');
+ al('Quotations produced in response to Enquiry refererence: ' ||
+ p_enqu_id || ' (' || l_description || ')');
+
+ FOR l_qute IN (SELECT *
+ FROM quotes
+ WHERE enqu_id = p_enqu_id) LOOP
+ l_manual_or_automatic := l_qute.qute_type;
+ IF l_qute.qute_type = g_automatic_quote THEN
+ al('Automatic Quote Reference: ' || l_qute.id);
+ al('Quote Summary:');
+ al('This quote is valid from ' ||
+ to_char(l_qute.valid_from
+ ,'Dth Month YYYY') || ' to ' ||
+ to_char(l_qute.valid_until
+ ,'Dth Month YYYY'));
+
+ FOR l_sum IN (SELECT *
+ FROM v_quote_details
+ WHERE quote_id = l_qute.id) LOOP
+
+ IF l_sum.module_code IS NOT NULL THEN
+ al('Module code: ' || l_sum.module_code);
+ END IF;
+ IF l_sum.lead_time IS NOT NULL THEN
+ al('Lead time: ' || l_sum.module_code || ' days');
+ END IF;
+ IF l_sum.additional_items IS NOT NULL THEN
+ al('Additional items: ' || l_sum.additional_items);
+ END IF;
+ IF l_sum.bas_code IS NOT NULL THEN
+ al('Base code: ' || l_sum.bas_code);
+ END IF;
+ IF l_sum.qmax IS NOT NULL THEN
+ al('Qmax: ' || l_sum.qmax);
+ END IF;
+ IF l_sum.qmin IS NOT NULL THEN
+ al('Qmin: ' || l_sum.module_code);
+ END IF;
+ IF l_sum.inlet_orientation IS NOT NULL THEN
+ al('Inlet orientation: ' || l_sum.inlet_orientation);
+ END IF;
+ IF l_sum.outlet_orientation IS NOT NULL THEN
+ al('Outlet orientation: ' || l_sum.outlet_orientation);
+ END IF;
+ IF l_sum.total_cost IS NOT NULL THEN
+ al('Total cost: £' || l_sum.total_cost);
+ END IF;
+ END LOOP;
+ ELSE
+ al('Manual Quote to be completed against Quote Reference: ' ||
+ l_qute.id);
+ al('This quote will be valid from ' ||
+ to_char(l_qute.valid_from
+ ,'Dth Month YYYY') || ' to ' ||
+ to_char(l_qute.valid_until
+ ,'Dth Month YYYY'));
+ al(' ');
+ al('Current Service Level Agreements dictate that a manual quote be provided with 6 days');
+ END IF;
+ al(' ');
+ END LOOP;
+ al('WEBMIP used the following reasoning in reaching this decision:');
+ FOR l_rec IN (SELECT reason
+ ,internal_or_external
+ FROM quote_reasoning
+ WHERE enqu_id = p_enqu_id
+ ORDER BY id) LOOP
+ al(l_rec.reason);
+ END LOOP;
+ al(' ');
+ al('*** DO NOT REPLY TO THIS EMAIL ***');
+
+ close_body;
+
+ IF l_manual_or_automatic = g_automatic_quote THEN
+ l_subject := 'WEBMIP: Notification of generation of automatic quotes for Enquiry reference: ' ||
+ p_enqu_id;
+ SELECT VALUE
+ INTO l_recipient
+ FROM system_configuration
+ WHERE parameter = 'EMAIL_ADDRESS_AUTOMATIC_QUOTE';
+ ELSE
+ l_subject := 'WEBMIP: Request for a Manual Quote for Enquiry reference: ' ||
+ p_enqu_id;
+ SELECT VALUE
+ INTO l_recipient
+ FROM system_configuration
+ WHERE parameter = 'EMAIL_ADDRESS_MANUAL_QUOTE';
+ END IF;
+
+ mip_email.send_email_clob(p_recipient => l_recipient
+ ,p_body => lg_body
+ ,p_body_html => lg_html_body
+ ,p_subject => l_subject);
+ END produce_email;
+
+ PROCEDURE request_manual_quote(p_enqu_id IN enquiries.id%TYPE
+ ,p_rfq_prty_id IN parties.id%TYPE
+ ,p_owner_prty_id IN parties.id%TYPE DEFAULT NULL) IS
+ l_qute_id quotes.id%TYPE;
+ BEGIN
+
+ l_qute_id := start_quote(p_enqu_id => p_enqu_id
+ ,p_manual_or_automatic => g_manual_quote
+ ,p_rfq_prty_id => p_rfq_prty_id
+ ,p_owner_prty_id => p_owner_prty_id);
+
+ produce_email(p_enqu_id => p_enqu_id);
+
END request_manual_quote;
PROCEDURE ready_for_quote(p_id IN enquiries.id%TYPE
@@ -536,6 +797,8 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
END get_laco;
PROCEDURE produce_install_quotes(p_enqu IN t_enqu
+ ,p_rfq_prty_id IN parties.id%TYPE
+ ,p_owner_prty_id IN parties.id%TYPE DEFAULT NULL
,p_manual_or_automatic_quote IN OUT t_manual_or_automatic_quote) IS
l_produced_automatic_quote BOOLEAN;
l_this_is_automatic_quote BOOLEAN;
@@ -552,7 +815,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
,'Attempted to produce an install quote for enquiry for a installation postcode (' ||
p_enqu.install_postcode || ') without a region.');
add_quote_reason(p_enqu.id
- ,p_reason => 'Attempting an automatic quote for ' ||
+ ,p_reason => 'Attempting an automatic installation quote for ' ||
p_enqu.id || '.' || ' Required SVCP ' ||
p_enqu.required_svcp_code || ', QMAX=' ||
p_enqu.qmax || ', Outlet Pressure=' ||
@@ -860,32 +1123,10 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
,p_reason => 'Producing an automatic quote.'
,p_internal_or_external => g_internal_reason);
- INSERT INTO quotes
- (id
- ,qute_type
- ,enqu_id
- ,valid_from
- ,valid_until
- ,created_on
- ,created_by)
- VALUES
- (qute_seq.NEXTVAL
- ,'AQ' -- automatic quote
- ,p_enqu.id
- ,trunc(SYSDATE)
- ,trunc(SYSDATE + 90)
- ,SYSDATE
- ,USER)
- RETURNING id INTO l_qute_id;
-
- INSERT INTO quote_events
- (event_date
- ,qust_code
- ,qute_id)
- VALUES
- (SYSDATE
- ,'INP' -- In Progress
- ,l_qute_id);
+ l_qute_id := start_quote(p_enqu_id => p_enqu.id
+ ,p_manual_or_automatic => g_automatic_quote
+ ,p_rfq_prty_id => p_rfq_prty_id
+ ,p_owner_prty_id => p_owner_prty_id);
INSERT INTO quote_items
(id
@@ -915,6 +1156,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
,qute_id
,modu_code
,qmax
+ ,qmin
,inlet_orientation
,outlet_orientation
,cost_price
@@ -926,6 +1168,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
,l_qute_id
,l_rec_module.modu_code
,l_rec_module.qmax
+ ,l_rec_module.qmin
,l_rec_module.modu_inlet_orientation
,l_rec_module.modu_outlet_orientation
,l_rec_module.modu_cost_price
@@ -1068,14 +1311,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
l_quote_document || '.'
,p_internal_or_external => g_internal_reason);
- INSERT INTO quote_events
- (event_date
- ,qust_code
- ,qute_id)
- VALUES
- (SYSDATE
- ,'AV' -- Available
- ,l_qute_id);
+ make_quote_available(l_qute_id);
END IF; -- automatic quote
@@ -1086,6 +1322,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
add_quote_reason(p_enqu_id => p_enqu.id
,p_reason => '-- Produced an automatic quote.'
,p_internal_or_external => g_internal_reason);
+ produce_email(p_enqu.id);
ELSE
p_manual_or_automatic_quote := g_manual_quote;
add_quote_reason(p_enqu_id => p_enqu.id
@@ -1096,7 +1333,125 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
END produce_install_quotes;
+ PROCEDURE produce_removal_quotes(p_enqu IN t_enqu
+ ,p_rfq_prty_id IN parties.id%TYPE
+ ,p_owner_prty_id IN parties.id%TYPE DEFAULT NULL
+ ,p_manual_or_automatic_quote IN OUT t_manual_or_automatic_quote) IS
+ l_produced_automatic_quote BOOLEAN;
+ l_this_is_automatic_quote BOOLEAN;
+ l_regi_code regions.code%TYPE := mip_regions.get_region_for_postcode(p_enqu.install_postcode);
+ l_qute_id quotes.id%TYPE;
+ l_additional_costs t_rec_additional_costs;
+ l_quote_document VARCHAR2(240);
+ BEGIN
+ cout_assert.istrue(p_enqu.enty_code IN ('REMOVE', 'STD REMOVE')
+ ,'Attempted to produce a removal quote for enquiry of type ' ||
+ p_enqu.enty_code);
+
+ cout_assert.isnotnull(l_regi_code
+ ,'Attempted to produce an removal quote for enquiry for a installation postcode (' ||
+ p_enqu.install_postcode || ') without a region.');
+ add_quote_reason(p_enqu.id
+ ,p_reason => 'Attempting an automatic removal quote for ' ||
+ p_enqu.id || '.' || ' Required SVCP ' ||
+ p_enqu.required_svcp_code ||
+ ', Meter Type Code=' || p_enqu.mety_code ||
+ ', Meter Size Code=' ||
+ p_enqu.existing_mesc_code || '.'
+ ,p_internal_or_external => g_internal_reason);
+
+ l_this_is_automatic_quote := TRUE;
+
+ l_additional_costs := get_laco(p_enty_code => p_enqu.enty_code
+ ,p_regi_code => l_regi_code
+ ,p_mety_code => p_enqu.mety_code
+ ,p_mesc_code => p_enqu.existing_mesc_code
+ ,p_svcp_code => p_enqu.required_svcp_code);
+ IF l_additional_costs.selling_price IS NULL THEN
+ l_this_is_automatic_quote := FALSE;
+ add_quote_reason(p_enqu.id
+ ,p_reason => 'Unable to find Labour Cost (selling price) for this Enquiry Type Code: ' ||
+ p_enqu.enty_code || ', Meter Type Code:' ||
+ p_enqu.mety_code || ', Meter Size Code:' ||
+ p_enqu.existing_mesc_code ||
+ ', Service Pressure Code:' ||
+ p_enqu.required_svcp_code || CASE
+ l_regi_code WHEN NULL THEN '' ELSE ' for region code ' || l_regi_code END || '.'
+
+ ,p_internal_or_external => g_internal_reason);
+ END IF;
+
+ IF l_this_is_automatic_quote THEN
+ l_produced_automatic_quote := TRUE;
+
+ add_quote_reason(p_enqu_id => p_enqu.id
+ ,p_reason => 'Producing an automatic quote.'
+ ,p_internal_or_external => g_internal_reason);
+
+ l_qute_id := start_quote(p_enqu_id => p_enqu.id
+ ,p_manual_or_automatic => g_automatic_quote
+ ,p_rfq_prty_id => p_rfq_prty_id
+ ,p_owner_prty_id => p_owner_prty_id);
+
+ INSERT INTO quote_items
+ (id
+ ,qute_id
+ ,enty_code
+ ,svcpt_code
+ ,mesc_code
+ ,mety_code
+ ,cost_price
+ ,selling_price
+ ,delivery_price
+ ,quit_type)
+ VALUES
+ (quit_seq.NEXTVAL
+ ,l_qute_id
+ ,p_enqu.enty_code
+ ,l_additional_costs.svcpt_code
+ ,p_enqu.existing_mesc_code
+ ,p_enqu.mety_code
+ ,l_additional_costs.cost_price
+ ,l_additional_costs.selling_price
+ ,l_additional_costs.delivery_cost
+ ,'LQI');
+
+ -- Generate the quote PDF
+ /*BEGIN*/
+ l_quote_document := mip_quotation_document.generate_quote_pdf(p_quote_id => l_qute_id);
+ /* EXCEPTION
+ WHEN OTHERS THEN
+ cout_err.report_and_stop;
+ END;
+ */
+ add_quote_reason(p_enqu_id => p_enqu.id
+ ,p_reason => 'Produced Quote Document ' ||
+ l_quote_document || '.'
+ ,p_internal_or_external => g_internal_reason);
+
+ make_quote_available(l_qute_id);
+
+ END IF; -- automatic quote
+
+ IF l_produced_automatic_quote THEN
+ p_manual_or_automatic_quote := g_automatic_quote;
+ add_quote_reason(p_enqu_id => p_enqu.id
+ ,p_reason => '-- Produced an automatic quote.'
+ ,p_internal_or_external => g_internal_reason);
+ produce_email(p_enqu.id);
+ ELSE
+ p_manual_or_automatic_quote := g_manual_quote;
+ add_quote_reason(p_enqu_id => p_enqu.id
+ ,p_reason => '-- Automatic quote failed - Manual quote required.'
+ ,p_internal_or_external => g_internal_reason);
+
+ END IF;
+
+ END produce_removal_quotes;
+
PROCEDURE produce_automatic_quotes(p_enqu IN t_enqu
+ ,p_rfq_prty_id IN parties.id%TYPE
+ ,p_owner_prty_id IN parties.id%TYPE DEFAULT NULL
,p_manual_or_automatic_quote IN OUT t_manual_or_automatic_quote) IS
BEGIN
cout_assert.istrue(p_manual_or_automatic_quote = g_automatic_quote
@@ -1104,37 +1459,53 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
IF p_enqu.enty_code IN ('INSTALL', 'STD INSTALL') THEN
produce_install_quotes(p_enqu => p_enqu
+ ,p_rfq_prty_id => p_rfq_prty_id
+ ,p_owner_prty_id => p_owner_prty_id
,p_manual_or_automatic_quote => p_manual_or_automatic_quote);
+ ELSIF p_enqu.enty_code IN ('REMOVE', 'STD REMOVE') THEN
+ produce_removal_quotes(p_enqu => p_enqu
+ ,p_rfq_prty_id => p_rfq_prty_id
+ ,p_owner_prty_id => p_owner_prty_id
+ ,p_manual_or_automatic_quote => p_manual_or_automatic_quote);
+
ELSE
cout_err.report_and_stop(p_exception_message => 'Attempted to produce automatic quote for unexpected enquiry type of ' ||
p_enqu.enty_code);
END IF;
END produce_automatic_quotes;
- PROCEDURE produce_quotes(p_id IN enquiries.id%TYPE) IS
+ PROCEDURE produce_quotes(p_enqu_id IN enquiries.id%TYPE
+ ,p_rfq_prty_id IN parties.id%TYPE
+ ,p_owner_prty_id IN parties.id%TYPE DEFAULT NULL) IS
l_manual_or_automatic_quote t_manual_or_automatic_quote;
l_enqu t_enqu;
BEGIN
- cout_assert.istrue(ready_for_quote(p_id)
- ,'Not all mandatory fields for Enquiry ID=' || p_id ||
- ' have been completed');
+ cout_assert.istrue(ready_for_quote(p_enqu_id)
+ ,'Not all mandatory fields for Enquiry ID=' ||
+ p_enqu_id || ' have been completed');
SELECT *
INTO l_enqu
FROM enquiries
- WHERE id = p_id;
+ WHERE id = p_enqu_id;
manual_or_automatic_quote(p_enqu => l_enqu
,p_manual_or_automatic_quote => l_manual_or_automatic_quote);
IF l_manual_or_automatic_quote = g_manual_quote THEN
- request_manual_quote(p_enqu_id => l_enqu.id);
+ request_manual_quote(p_enqu_id => l_enqu.id
+ ,p_rfq_prty_id => p_rfq_prty_id
+ ,p_owner_prty_id => p_owner_prty_id);
ELSE
produce_automatic_quotes(p_enqu => l_enqu
+ ,p_rfq_prty_id => p_rfq_prty_id
+ ,p_owner_prty_id => p_owner_prty_id
,p_manual_or_automatic_quote => l_manual_or_automatic_quote);
IF l_manual_or_automatic_quote = g_manual_quote THEN
- request_manual_quote(p_enqu_id => l_enqu.id);
+ request_manual_quote(p_enqu_id => l_enqu.id
+ ,p_rfq_prty_id => p_rfq_prty_id
+ ,p_owner_prty_id => p_owner_prty_id);
END IF;
--