mip_bulk_load.pck - initial stage of producing bulk load routines.

mip_quotation.pck - move bases and housings from main 'install' query to allow a more comprehensive 'reasoning' to be produced. Removed references to 'logger' for 'install'. Added 'lifting gear' to all 'install' quotations.

git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@3173 248e525c-4dfb-0310-94bc-949c084e9493
This commit is contained in:
hardya
2008-01-08 18:20:27 +00:00
parent f3c3bb281f
commit c9c4299917
2 changed files with 323 additions and 167 deletions

102
Modules/mip_bulk_load.pck Normal file
View File

@@ -0,0 +1,102 @@
CREATE OR REPLACE PACKAGE mip_bulk_load IS
-- Author : HARDYA
-- Created : 08/01/2008 14:26:14
-- Purpose : Bulk data load routines
PROCEDURE load_meters;
END mip_bulk_load;
/
CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
PROCEDURE load_manufacturers IS
BEGIN
MERGE INTO parties prty
USING (SELECT field_1
FROM ext_meter) e_metr
ON (upper(e_metr.field_1) = upper(prty.manu_ref))
WHEN NOT MATCHED THEN
INSERT
(prty.manu_ref
,NAME
,description
,created_on
,created_by
,prty_type
,id)
VALUES
(upper(e_metr.field_1)
,e_metr.field_1
,'Inserted missing manufacturer (EXT_METR)'
,SYSDATE
,USER
,'MANU'
,prty_seq.NEXTVAL) log errors reject LIMIT unlimited;
END load_manufacturers;
PROCEDURE load_meters IS
BEGIN
load_manufacturers;
MERGE INTO meters metr
USING (SELECT field_1
,field_2
,field_3
,field_4
,field_5
,field_6
,field_7
,field_8
,field_9
,field_10
,field_11
,field_12
FROM ext_meter) e_metr
ON (e_metr.field_2 = metr.code)
WHEN MATCHED THEN
UPDATE
SET prty_id = (SELECT id
FROM parties p
WHERE upper(p.manu_ref) = upper(e_metr.field_1)
AND p.prty_type = 'MANU')
,mety_code = e_metr.field_4
WHEN NOT MATCHED THEN
INSERT
(metr.code
,metr.prty_id
,metr.mety_code
,metr.dim_a
,metr.dim_b
,metr.centres
,metr.dim_c
,metr.weight
,metr.qmax
,metr.valid_from
,metr.qnom
,metr.qmin)
VALUES
(e_metr.field_2
,(SELECT id
FROM parties p
WHERE upper(p.manu_ref) = upper(e_metr.field_1)
AND p.prty_type = 'MANU')
,e_metr.field_4
,e_metr.field_5
,e_metr.field_6
,e_metr.field_7
,e_metr.field_8
,e_metr.field_9
,e_metr.field_10
,SYSDATE
,e_metr.field_11
,e_metr.field_12) log errors reject LIMIT unlimited;
END load_meters;
BEGIN
-- Initialization
NULL;
END mip_bulk_load;
/

View File

@@ -45,7 +45,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
g_manual_quote CONSTANT t_manual_or_automatic_quote := 'MANUAL';
g_automatic_quote CONSTANT t_manual_or_automatic_quote := 'AUTOMATIC';
TYPE t_rec_additional_item_costs IS RECORD(
TYPE t_rec_additional_costs IS RECORD(
adit_code additional_items.code%TYPE
,lead_time additional_items.lead_time%TYPE
,selling_price costs.selling_price%TYPE
@@ -230,10 +230,79 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
END IF;
END manual_or_automatic_quote;
FUNCTION get_housing(p_hou_code IN modules.hou_code%TYPE
,p_regi_code regions.code%TYPE)
RETURN t_rec_additional_costs IS
l_rec_costs t_rec_additional_costs;
BEGIN
SELECT selling_price
,cost_price
,delivery_cost
INTO l_rec_costs.selling_price
,l_rec_costs.cost_price
,l_rec_costs.delivery_cost
FROM (SELECT selling_price
,cost_price
,delivery_cost
FROM (SELECT row_number() over(PARTITION BY hou_code ORDER BY(decode(regi_code, p_regi_code, 1, 999))) AS accuracy
,hou_code
,selling_price
,cost_price
,delivery_cost
,ROWID
FROM v_hoco cost
WHERE hou_code = p_hou_code
AND SYSDATE BETWEEN cost.effective_from AND
cost.effective_to
AND regi_code = p_regi_code
OR regi_code IS NULL)
WHERE accuracy <= 1);
RETURN l_rec_costs;
EXCEPTION
WHEN no_data_found THEN
RETURN l_rec_costs;
END get_housing;
FUNCTION get_base(p_bas_code IN modules.hou_code%TYPE
,p_regi_code regions.code%TYPE)
RETURN t_rec_additional_costs IS
l_rec_costs t_rec_additional_costs;
BEGIN
SELECT selling_price
,cost_price
,delivery_cost
INTO l_rec_costs.selling_price
,l_rec_costs.cost_price
,l_rec_costs.delivery_cost
FROM (SELECT selling_price
,cost_price
,delivery_cost
FROM (SELECT row_number() over(PARTITION BY bas_code ORDER BY(decode(regi_code, p_regi_code, 1, 999))) AS accuracy
,bas_code
,selling_price
,cost_price
,delivery_cost
,ROWID
FROM v_baco cost
WHERE bas_code = p_bas_code
AND SYSDATE BETWEEN cost.effective_from AND
cost.effective_to
AND regi_code = p_regi_code
OR regi_code IS NULL)
WHERE accuracy <= 1);
RETURN l_rec_costs;
EXCEPTION
WHEN no_data_found THEN
RETURN l_rec_costs;
END get_base;
FUNCTION get_aico(p_adit_code IN costs.adit_code%TYPE
,p_regi_code IN regions.code%TYPE)
RETURN t_rec_additional_item_costs IS
l_rec_costs t_rec_additional_item_costs;
RETURN t_rec_additional_costs IS
l_rec_costs t_rec_additional_costs;
BEGIN
SELECT lead_time
,selling_price
@@ -279,7 +348,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
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_aico_costs t_rec_additional_item_costs;
l_additional_costs t_rec_additional_costs;
BEGIN
cout_assert.istrue(p_enqu.enty_code IN ('INSTALL', 'STD INSTALL')
,'Attempted to produce an install quote for enquiry of type ' ||
@@ -290,7 +359,10 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
p_enqu.install_postcode || ') without a region.');
add_quote_reason(p_enqu.id
,p_reason => 'Attempting an automatic quote for ' ||
p_enqu.id || '.'
p_enqu.id || '.' || ' Required SVCP ' ||
p_enqu.required_svcp_code || ', QMAX=' ||
p_enqu.qmax || ', Outlet Pressure=' ||
p_enqu.required_metering_pressure || '.'
,p_internal_or_external => g_internal_reason);
FOR l_rec_module IN (SELECT modu.code AS modu_code
@@ -298,14 +370,14 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
,modu.cost_price AS modu_cost_price
,modu.delivery_cost AS modu_delivery_cost
,modu.lead_time AS modu_lead_time
,hou.code AS hou_code
,hou.selling_price AS hou_selling_price
,hou.cost_price AS hou_cost_price
,hou.delivery_cost AS hou_delivery_cost
,bas.code AS bas_code
,bas.selling_price AS bas_selling_price
,bas.cost_price AS bas_cost_price
,bas.delivery_cost AS bas_delivery_cost
,modu.hou_code AS hou_code
,NULL AS hou_selling_price
,NULL AS hou_cost_price
,NULL AS hou_delivery_cost
,modu.bas_code AS bas_code
,NULL AS bas_selling_price
,NULL AS bas_cost_price
,NULL AS bas_delivery_cost
,metr.code AS metr_code
,metr.qnom
,metr.qmax
@@ -314,6 +386,10 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
,metr.cost_price AS metr_cost_price
,metr.delivery_cost AS metr_delivery_cost
,metr.mety_code
,laco.mety_code AS laco_mety_code
,laco.svcp_code AS laco_svcp_code
,laco.svcpt_code AS laco_svcpt_code
,laco.mesc_code AS laco_mesc_code
,laco.selling_price /*NULL*/ AS laco_selling_price
,laco.cost_price /*NULL*/ AS laco_cost_price
,laco.delivery_cost /*NULL*/ AS laco_delivery_cost
@@ -332,11 +408,11 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
,NULL AS bypass_cost_price
,NULL AS bypass_delivery_cost
,NULL AS bypass_lead_time
,NULL AS logger_cost_id
,NULL AS logger_selling_price
,NULL AS logger_cost_price
,NULL AS logger_delivery_cost
,NULL AS logger_lead_time
,NULL AS lifting_gear_cost_id
,NULL AS lifting_gear_selling_price
,NULL AS lifting_gear_cost_price
,NULL AS lifting_gear_delivery_cost
,NULL AS lifting_gear_lead_time
FROM (SELECT modu.code
,modu.metr_code
,modu.hou_code
@@ -406,54 +482,6 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
svcp.svcpt_code(+))
WHERE accuracy <= 1) cost
WHERE enty.code = cost.enty_code(+)) laco
,(SELECT code
,selling_price
,cost_price
,delivery_cost
FROM housings hou
,(SELECT hou_code
,selling_price
,cost_price
,delivery_cost
FROM (SELECT row_number() over(PARTITION BY hou_code ORDER BY(decode(regi_code, l_regi_code, 1, 999))) AS accuracy
,hou_code
,selling_price
,cost_price
,delivery_cost
,ROWID
FROM v_hoco cost
WHERE SYSDATE BETWEEN
cost.effective_from AND
cost.effective_to
AND regi_code =
l_regi_code
OR regi_code IS NULL)
WHERE accuracy <= 1) cost
WHERE hou.code = cost.hou_code(+)) hou
,(SELECT code
,selling_price
,cost_price
,delivery_cost
FROM bases bas
,(SELECT bas_code
,selling_price
,cost_price
,delivery_cost
FROM (SELECT row_number() over(PARTITION BY bas_code ORDER BY(decode(regi_code, l_regi_code, 1, 999))) AS accuracy
,bas_code
,selling_price
,cost_price
,delivery_cost
,ROWID
FROM v_baco cost
WHERE SYSDATE BETWEEN
cost.effective_from AND
cost.effective_to
AND regi_code =
l_regi_code
OR regi_code IS NULL)
WHERE accuracy <= 1) cost
WHERE bas.code = cost.bas_code(+)) bas
,(SELECT metr.code
,metr.qmax
,metr.qmin
@@ -496,17 +524,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
((laco.mesc_code =
p_enqu.required_mesc_code) OR
(laco.mesc_code IS NULL AND
p_enqu.required_mesc_code IS NULL)))
AND ((bas_code IS NULL AND
p_enqu.base_required <> 'YES') OR
(bas_code IS NOT NULL AND
p_enqu.base_required <> 'YES'))
AND modu.bas_code = bas.code(+)
AND ((hou_code IS NULL AND
p_enqu.housing_required <> 'YES') OR
(hou_code IS NOT NULL AND
p_enqu.housing_required <> 'YES'))
AND modu.hou_code = hou.code(+)) LOOP
p_enqu.required_mesc_code IS NULL)))) LOOP
l_this_is_automatic_quote := TRUE;
add_quote_reason(p_enqu.id
,p_reason => 'Considering module : ' ||
@@ -531,53 +549,67 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
l_rec_module.modu_code || '.'
,p_internal_or_external => g_internal_reason);
END IF;
/* Meters do not have a price, they are rented
IF l_rec_module.metr_selling_price IS NULL THEN
l_this_is_automatic_quote := FALSE;
add_quote_reason(p_enqu.id
,p_reason => 'Unable to find selling price for meter ' ||
l_rec_module.metr_code || '.'
,p_internal_or_external => g_internal_reason);
END IF;*/
IF l_rec_module.laco_selling_price IS NULL THEN
l_this_is_automatic_quote := FALSE;
add_quote_reason(p_enqu.id
,p_reason => 'Labour costs: enty_code=' ||
p_enqu.enty_code || ', svcp_code=' ||
p_enqu.required_svcp_code ||
', mesc_code=' ||
p_enqu.required_mesc_code ||
', mety_code=' ||
l_rec_module.mety_code || '.'
/*
,p_reason => 'Unable to find Labour Cost (selling price) for enquiry type ' ||
p_enqu.enty_code || CASE l_regi_code WHEN NULL THEN '' ELSE ' for region code ' || l_regi_code END || '.'
*/
,p_reason => 'Unable to find Labour Cost (selling price) for enquiry type ' ||
p_enqu.enty_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 p_enqu.base_required = 'YES'
AND l_rec_module.bas_selling_price IS NULL THEN
l_this_is_automatic_quote := FALSE;
add_quote_reason(p_enqu.id
,p_reason => 'Unable to find selling price for base ' ||
l_rec_module.bas_code || '.'
,p_internal_or_external => g_internal_reason);
IF p_enqu.base_required = 'YES' THEN
IF l_rec_module.bas_code IS NOT NULL THEN
l_additional_costs := get_base(p_bas_code => l_rec_module.bas_code
,p_regi_code => l_regi_code);
l_rec_module.bas_selling_price := l_additional_costs.selling_price;
l_rec_module.bas_cost_price := l_additional_costs.cost_price;
l_rec_module.bas_delivery_cost := l_additional_costs.delivery_cost;
IF l_rec_module.bas_selling_price IS NULL THEN
l_this_is_automatic_quote := FALSE;
add_quote_reason(p_enqu.id
,p_reason => 'Unable to find selling price for base ' ||
l_rec_module.bas_code || '.'
,p_internal_or_external => g_internal_reason);
END IF;
ELSE
l_this_is_automatic_quote := FALSE;
add_quote_reason(p_enqu.id
,p_reason => 'Module is not available with base.'
,p_internal_or_external => g_internal_reason);
END IF;
END IF;
IF p_enqu.housing_required = 'YES'
AND l_rec_module.hou_selling_price IS NULL THEN
l_this_is_automatic_quote := FALSE;
add_quote_reason(p_enqu.id
,p_reason => 'Unable to find selling price for housing ' ||
l_rec_module.hou_code || '.'
,p_internal_or_external => g_internal_reason);
IF p_enqu.housing_required = 'YES' THEN
IF l_rec_module.hou_code IS NOT NULL THEN
l_additional_costs := get_housing(p_hou_code => l_rec_module.hou_code
,p_regi_code => l_regi_code);
l_rec_module.hou_selling_price := l_additional_costs.selling_price;
l_rec_module.hou_cost_price := l_additional_costs.cost_price;
l_rec_module.hou_delivery_cost := l_additional_costs.delivery_cost;
IF l_rec_module.hou_selling_price IS NULL THEN
l_this_is_automatic_quote := FALSE;
add_quote_reason(p_enqu.id
,p_reason => 'Unable to find selling price for housing ' ||
l_rec_module.hou_code || '.'
,p_internal_or_external => g_internal_reason);
END IF;
ELSE
l_this_is_automatic_quote := FALSE;
add_quote_reason(p_enqu.id
,p_reason => 'Module is not available with housing.'
,p_internal_or_external => g_internal_reason);
END IF;
END IF;
IF p_enqu.amr_required = 'YES' THEN
l_aico_costs := get_aico(p_adit_code => 'AMR'
l_additional_costs := get_aico(p_adit_code => 'AMR'
,p_regi_code => l_regi_code);
l_rec_module.amr_selling_price := l_aico_costs.selling_price;
l_rec_module.amr_cost_price := l_aico_costs.cost_price;
l_rec_module.amr_delivery_cost := l_aico_costs.delivery_cost;
l_rec_module.amr_lead_time := l_aico_costs.lead_time;
l_rec_module.amr_selling_price := l_additional_costs.selling_price;
l_rec_module.amr_cost_price := l_additional_costs.cost_price;
l_rec_module.amr_delivery_cost := l_additional_costs.delivery_cost;
l_rec_module.amr_lead_time := l_additional_costs.lead_time;
IF l_rec_module.amr_selling_price IS NULL THEN
l_this_is_automatic_quote := FALSE;
add_quote_reason(p_enqu.id
@@ -592,12 +624,12 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
END IF;
END IF;
IF p_enqu.ems_required = 'YES' THEN
l_aico_costs := get_aico(p_adit_code => 'EMS'
l_additional_costs := get_aico(p_adit_code => 'EMS'
,p_regi_code => l_regi_code);
l_rec_module.ems_selling_price := l_aico_costs.selling_price;
l_rec_module.ems_cost_price := l_aico_costs.cost_price;
l_rec_module.ems_delivery_cost := l_aico_costs.delivery_cost;
l_rec_module.ems_lead_time := l_aico_costs.lead_time;
l_rec_module.ems_selling_price := l_additional_costs.selling_price;
l_rec_module.ems_cost_price := l_additional_costs.cost_price;
l_rec_module.ems_delivery_cost := l_additional_costs.delivery_cost;
l_rec_module.ems_lead_time := l_additional_costs.lead_time;
IF l_rec_module.ems_selling_price IS NULL THEN
l_this_is_automatic_quote := FALSE;
add_quote_reason(p_enqu.id
@@ -612,12 +644,12 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
END IF;
END IF;
IF p_enqu.bypass_required = 'YES' THEN
l_aico_costs := get_aico(p_adit_code => 'BYPASS'
l_additional_costs := get_aico(p_adit_code => 'BYPASS'
,p_regi_code => l_regi_code);
l_rec_module.bypass_selling_price := l_aico_costs.selling_price;
l_rec_module.bypass_cost_price := l_aico_costs.cost_price;
l_rec_module.bypass_delivery_cost := l_aico_costs.delivery_cost;
l_rec_module.bypass_lead_time := l_aico_costs.lead_time;
l_rec_module.bypass_selling_price := l_additional_costs.selling_price;
l_rec_module.bypass_cost_price := l_additional_costs.cost_price;
l_rec_module.bypass_delivery_cost := l_additional_costs.delivery_cost;
l_rec_module.bypass_lead_time := l_additional_costs.lead_time;
IF l_rec_module.bypass_selling_price IS NULL THEN
l_this_is_automatic_quote := FALSE;
add_quote_reason(p_enqu.id
@@ -632,31 +664,34 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
END IF;
END IF;
IF p_enqu.logger_required = 'YES' THEN
l_aico_costs := get_aico(p_adit_code => 'LOGGER'
,p_regi_code => l_regi_code);
l_rec_module.logger_selling_price := l_aico_costs.selling_price;
l_rec_module.logger_cost_price := l_aico_costs.cost_price;
l_rec_module.logger_delivery_cost := l_aico_costs.delivery_cost;
l_rec_module.logger_lead_time := l_aico_costs.lead_time;
IF l_rec_module.logger_selling_price IS NULL THEN
l_this_is_automatic_quote := FALSE;
add_quote_reason(p_enqu.id
,p_reason => 'Unable to find selling price for LOGGER.'
,p_internal_or_external => g_internal_reason);
END IF;
IF l_rec_module.logger_lead_time IS NULL THEN
l_this_is_automatic_quote := FALSE;
add_quote_reason(p_enqu.id
,p_reason => 'Unable to find lead time for LOGGER.'
,p_internal_or_external => g_internal_reason);
END IF;
/* Always get costs for LIFTING GEAR */
l_additional_costs := get_aico(p_adit_code => 'LIFTING GEAR'
,p_regi_code => l_regi_code);
l_rec_module.lifting_gear_selling_price := l_additional_costs.selling_price;
l_rec_module.lifting_gear_cost_price := l_additional_costs.cost_price;
l_rec_module.lifting_gear_delivery_cost := l_additional_costs.delivery_cost;
l_rec_module.lifting_gear_lead_time := l_additional_costs.lead_time;
IF l_rec_module.lifting_gear_selling_price IS NULL THEN
l_this_is_automatic_quote := FALSE;
add_quote_reason(p_enqu.id
,p_reason => 'Unable to find selling price for LIFTING GEAR.'
,p_internal_or_external => g_internal_reason);
END IF;
IF l_rec_module.lifting_gear_lead_time IS NULL THEN
l_this_is_automatic_quote := FALSE;
add_quote_reason(p_enqu.id
,p_reason => 'Unable to find lead time for LIFTING GEAR.'
,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);
INSERT INTO quotes
(id
,qute_type
@@ -705,6 +740,9 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
(id
,qute_id
,enty_code
,mety_code
,svcpt_code
,mesc_code
,cost_price
,selling_price
,delivery_price
@@ -713,11 +751,15 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
(quit_seq.NEXTVAL
,l_qute_id
,p_enqu.enty_code
,l_rec_module.laco_mety_code
,l_rec_module.laco_svcpt_code
,l_rec_module.laco_mesc_code
,l_rec_module.laco_cost_price
,l_rec_module.laco_selling_price
,l_rec_module.laco_delivery_cost
,'LQI');
IF l_rec_module.hou_code IS NOT NULL THEN
IF p_enqu.housing_required = 'YES' THEN
INSERT INTO quote_items
(id
,qute_id
@@ -736,7 +778,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
,'HQI');
END IF;
IF l_rec_module.bas_code IS NOT NULL THEN
IF p_enqu.base_required = 'YES' THEN
INSERT INTO quote_items
(id
,qute_id
@@ -818,30 +860,42 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
,'AQI');
END IF;
IF p_enqu.logger_required = 'YES' THEN
INSERT INTO quote_items
(id
,qute_id
,adit_code
,cost_price
,selling_price
,delivery_price
,lead_time
,quit_type)
VALUES
(quit_seq.NEXTVAL
,l_qute_id
,'LOGGER'
,l_rec_module.logger_cost_price
,l_rec_module.logger_selling_price
,l_rec_module.logger_delivery_cost
,l_rec_module.logger_lead_time
,'AQI');
END IF;
/* Always include LIFTING GEAR */
INSERT INTO quote_items
(id
,qute_id
,adit_code
,cost_price
,selling_price
,delivery_price
,lead_time
,quit_type)
VALUES
(quit_seq.NEXTVAL
,l_qute_id
,'LIFTING GEAR'
,l_rec_module.lifting_gear_cost_price
,l_rec_module.lifting_gear_selling_price
,l_rec_module.lifting_gear_delivery_cost
,l_rec_module.lifting_gear_lead_time
,'AQI');
END IF; -- automatic quote
END LOOP;
IF l_produced_automatic_quote THEN
add_quote_reason(p_enqu_id => p_enqu.id
,p_reason => 'Produced an automatic quote.'
,p_internal_or_external => g_internal_reason);
ELSE
add_quote_reason(p_enqu_id => p_enqu.id
,p_reason => 'Manual quote required.'
,p_internal_or_external => g_internal_reason);
END IF;
END produce_install_quotes;
PROCEDURE produce_automatic_quotes(p_enqu IN t_enqu