Issue #24315:improve missing/duplicate po number message
[xtuple] / foundation-database / public / functions / convertquote.sql
1
2 CREATE OR REPLACE FUNCTION convertQuote(INTEGER) RETURNS INTEGER AS $$
3 -- Copyright (c) 1999-2014 by OpenMFG LLC, d/b/a xTuple. 
4 -- See www.xtuple.com/CPAL for the full text of the software license.
5 DECLARE
6   pQuheadid ALIAS FOR $1;
7   _qunumber TEXT;
8   _ponumber TEXT;
9   _soheadid INTEGER;
10   _soitemid INTEGER;
11   _orderid INTEGER;
12   _ordertype CHARACTER(1);
13   _creditstatus TEXT;
14   _usespos BOOLEAN := false;
15   _blanketpos BOOLEAN := true;
16   _showConvertedQuote BOOLEAN := false;
17   _prospectid   INTEGER;
18   _r RECORD;
19   _soNum TEXT;
20
21 BEGIN
22
23 -- Check to make sure the quote has not expired
24   IF (SELECT COALESCE(quhead_expire, endOfTime()) < CURRENT_DATE
25         FROM quhead
26        WHERE(quhead_id=pQuheadid)) THEN
27     RETURN -6;
28   END IF;
29
30 --  Check to make sure that all of the quote items have a valid itemsite
31   SELECT quitem_id INTO _r
32     FROM quitem LEFT OUTER JOIN itemsite ON (quitem_itemsite_id=itemsite_id)
33    WHERE ((itemsite_id IS NULL)
34      AND  (quitem_quhead_id=pQuheadid));
35   IF (FOUND) THEN
36     PERFORM postEvent('CannotConvertQuote', 'Q', quhead_id,
37                       quhead_warehous_id, quhead_number,
38                       NULL, NULL, NULL, NULL)
39     FROM quhead
40     WHERE (quhead_id=pQuheadid);
41
42     RETURN -1;
43   END IF;
44
45   SELECT cust_creditstatus, cust_usespos, cust_blanketpos
46     INTO _creditstatus, _usespos, _blanketpos
47   FROM quhead, custinfo
48   WHERE ((quhead_cust_id=cust_id)
49     AND  (quhead_id=pQuheadid));
50
51   IF (NOT FOUND) THEN
52     SELECT prospect_id INTO _prospectid
53     FROM quhead, prospect
54     WHERE ((quhead_cust_id=prospect_id)
55       AND  (quhead_id=pQuheadid));
56     IF (NOT FOUND) THEN
57       RETURN -2;
58     ELSE
59       RETURN -3;
60     END IF;
61   ELSIF (_creditstatus = 'H' AND NOT checkPrivilege('CreateSOForHoldCustomer')) THEN
62     RETURN -4;
63   ELSIF (_creditstatus = 'W' AND NOT checkPrivilege('CreateSOForWarnCustomer')) THEN
64     RETURN -5;
65   END IF;
66
67   IF (_usespos) THEN
68     SELECT quhead_number INTO _qunumber
69     FROM quhead
70     WHERE (quhead_id=pQuheadid)
71       AND (COALESCE(quhead_custponumber, '') = '');
72     IF (FOUND) THEN
73       RAISE EXCEPTION 'Customer PO required for Quote %', _qunumber;
74     END IF;
75   END IF;
76   
77   IF ( (_usespos) AND (NOT _blanketpos) ) THEN
78     SELECT quhead_number, quhead_custponumber INTO _qunumber, _ponumber
79     FROM quhead JOIN cohead ON ( (cohead_cust_id=quhead_cust_id) AND
80                                  (UPPER(cohead_custponumber)=UPPER(quhead_custponumber)) )
81     WHERE (quhead_id=pQuheadid);
82     IF (FOUND) THEN
83       RAISE EXCEPTION 'Duplicate Customer PO % for Quote %', _ponumber, _qunumber;
84     END IF;
85   END IF;
86   
87   PERFORM quhead_number, cohead_id 
88   FROM quhead, cohead 
89   WHERE quhead_id = pQuheadid
90   AND cohead_number = quhead_number;
91
92   IF (FOUND) THEN
93     SELECT fetchSoNumber() INTO _soNum;
94   ELSE
95     SELECT quhead_number INTO _soNum
96     FROM quhead
97     WHERE quhead_id = pQuheadid;
98   END IF;
99
100   SELECT NEXTVAL('cohead_cohead_id_seq') INTO _soheadid;
101   INSERT INTO cohead
102   ( cohead_id, cohead_number, cohead_cust_id,
103     cohead_orderdate, cohead_packdate,
104     cohead_custponumber, cohead_warehous_id,
105     cohead_billtoname, cohead_billtoaddress1,
106     cohead_billtoaddress2, cohead_billtoaddress3,
107     cohead_billtocity, cohead_billtostate, cohead_billtozipcode,
108     cohead_billtocountry,
109     cohead_shipto_id, cohead_shiptoname, cohead_shiptoaddress1,
110     cohead_shiptoaddress2, cohead_shiptoaddress3,
111     cohead_shiptocity, cohead_shiptostate, cohead_shiptozipcode,
112     cohead_shiptocountry,
113     cohead_salesrep_id, cohead_commission,
114     cohead_terms_id, cohead_shipchrg_id, cohead_shipform_id,
115     cohead_fob, cohead_shipvia,
116     cohead_ordercomments, cohead_shipcomments,
117     cohead_freight, cohead_misc, cohead_misc_accnt_id, cohead_misc_descrip,
118     cohead_holdtype, cohead_wasquote, cohead_quote_number, cohead_prj_id,
119     cohead_curr_id, cohead_taxzone_id, cohead_taxtype_id,
120     cohead_shipto_cntct_id, cohead_shipto_cntct_honorific, cohead_shipto_cntct_first_name,
121     cohead_shipto_cntct_middle, cohead_shipto_cntct_last_name, cohead_shipto_cntct_suffix,
122     cohead_shipto_cntct_phone, cohead_shipto_cntct_title, cohead_shipto_cntct_fax, 
123     cohead_shipto_cntct_email,
124     cohead_billto_cntct_id, cohead_billto_cntct_honorific,
125     cohead_billto_cntct_first_name, cohead_billto_cntct_middle, cohead_billto_cntct_last_name, 
126     cohead_billto_cntct_suffix, cohead_billto_cntct_phone, cohead_billto_cntct_title, 
127     cohead_billto_cntct_fax, cohead_billto_cntct_email, cohead_ophead_id,
128     cohead_calcfreight, cohead_saletype_id, cohead_shipzone_id )
129   SELECT _soheadid, _soNum, quhead_cust_id,
130          CURRENT_DATE, quhead_packdate,
131          quhead_custponumber, quhead_warehous_id,
132          quhead_billtoname, quhead_billtoaddress1,
133          quhead_billtoaddress2, quhead_billtoaddress3,
134          quhead_billtocity, quhead_billtostate, quhead_billtozip,
135          quhead_billtocountry,
136          quhead_shipto_id, quhead_shiptoname, quhead_shiptoaddress1,
137          quhead_shiptoaddress2, quhead_shiptoaddress3,
138          quhead_shiptocity, quhead_shiptostate, quhead_shiptozipcode,
139          quhead_shiptocountry,
140          quhead_salesrep_id, quhead_commission,
141          quhead_terms_id, cust_shipchrg_id, cust_shipform_id,
142          quhead_fob, quhead_shipvia,
143          quhead_ordercomments, quhead_shipcomments,
144          quhead_freight, quhead_misc, quhead_misc_accnt_id, quhead_misc_descrip,
145          'N', TRUE, quhead_number, quhead_prj_id,
146          quhead_curr_id, quhead_taxzone_id, quhead_taxtype_id,
147          quhead_shipto_cntct_id, quhead_shipto_cntct_honorific,
148          quhead_shipto_cntct_first_name, quhead_shipto_cntct_middle, quhead_shipto_cntct_last_name,
149          quhead_shipto_cntct_suffix, quhead_shipto_cntct_phone, quhead_shipto_cntct_title,
150          quhead_shipto_cntct_fax, quhead_shipto_cntct_email, quhead_billto_cntct_id,
151          quhead_billto_cntct_honorific, quhead_billto_cntct_first_name, quhead_billto_cntct_middle,
152          quhead_billto_cntct_last_name, quhead_billto_cntct_suffix, quhead_billto_cntct_phone,
153          quhead_billto_cntct_title, quhead_billto_cntct_fax, quhead_billto_cntct_email, quhead_ophead_id,
154          quhead_calcfreight, quhead_saletype_id, quhead_shipzone_id
155   FROM quhead JOIN custinfo ON (cust_id=quhead_cust_id)
156   WHERE (quhead_id=pQuheadid);
157
158   -- Move Documents
159   UPDATE url SET url_source_id = _soheadid,
160                  url_source = 'S'
161   WHERE ((url_source='Q') AND (url_source_id = pQuheadid));
162
163   UPDATE imageass SET imageass_source_id = _soheadid,
164                       imageass_source = 'S'
165   WHERE ((imageass_source='Q') AND (imageass_source_id = pQuheadid));
166
167   UPDATE docass SET docass_source_id = _soheadid,
168                     docass_source_type = 'S'
169   WHERE ((docass_source_type='Q') AND (docass_source_id = pQuheadid));
170
171   -- Move Email
172   IF (fetchMetricBool('EnableBatchManager')) THEN
173     UPDATE xtbatch.emlassc SET emlassc_type='S',
174                                emlassc_assc_id=_soheadid
175     WHERE ((emlassc_type='Q') AND (emlassc_assc_id=pQuheadid));
176   END IF;
177
178   -- Copy Characteristics
179   INSERT INTO charass
180         (charass_target_type, charass_target_id, charass_char_id, charass_value, charass_default, charass_price)
181   SELECT 'SO', _soheadid, charass_char_id, charass_value, charass_default, charass_price
182     FROM charass
183    WHERE ((charass_target_type='QU')
184      AND  (charass_target_id=pQuheadid));
185
186   -- Copy Comments
187   INSERT INTO comment
188   ( comment_cmnttype_id, comment_source, comment_source_id, comment_date, comment_user, comment_text, comment_public )
189   SELECT comment_cmnttype_id, 'S', _soheadid, comment_date, comment_user, ('Quote-' || comment_text), comment_public
190   FROM comment
191   WHERE ( (comment_source='Q')
192     AND   (comment_source_id=pQuheadid) );
193
194   FOR _r IN SELECT quitem.*,
195                    quhead_number, quhead_prj_id, quhead_saletype_id,
196                    itemsite_item_id, itemsite_leadtime,
197                    itemsite_createsopo, itemsite_createsopr,
198                    item_type, COALESCE(quitem_itemsrc_id, itemsrc_id, -1) AS itemsrcid
199             FROM quhead JOIN quitem ON (quitem_quhead_id=quhead_id)
200                         JOIN itemsite ON (itemsite_id=quitem_itemsite_id)
201                         JOIN item ON (item_id=itemsite_item_id)
202                         LEFT OUTER JOIN itemsrc ON ( (itemsrc_item_id=item_id) AND
203                                                      (itemsrc_default) )
204             WHERE (quhead_id=pQuheadid)
205             ORDER BY quitem_linenumber LOOP
206
207     SELECT NEXTVAL('coitem_coitem_id_seq') INTO _soitemid;
208
209     INSERT INTO coitem
210     ( coitem_id, coitem_cohead_id, coitem_linenumber, coitem_itemsite_id,
211       coitem_status, coitem_scheddate, coitem_promdate,
212       coitem_price, coitem_custprice, 
213       coitem_qtyord, coitem_qtyshipped, coitem_qtyreturned,
214       coitem_qty_uom_id, coitem_qty_invuomratio,
215       coitem_price_uom_id, coitem_price_invuomratio,
216       coitem_unitcost, coitem_prcost,
217       coitem_custpn, coitem_memo, coitem_taxtype_id, coitem_order_id )
218     VALUES
219     ( _soitemid, _soheadid, _r.quitem_linenumber, _r.quitem_itemsite_id,
220       'O', _r.quitem_scheddate, _r.quitem_promdate,
221       _r.quitem_price, _r.quitem_custprice,
222       _r.quitem_qtyord, 0, 0,
223       _r.quitem_qty_uom_id, _r.quitem_qty_invuomratio,
224       _r.quitem_price_uom_id, _r.quitem_price_invuomratio,
225       stdcost(_r.itemsite_item_id), _r.quitem_prcost,
226       _r.quitem_custpn, _r.quitem_memo, _r.quitem_taxtype_id, -1 );
227
228     IF (fetchMetricBool('enablextcommissionission')) THEN
229       PERFORM xtcommission.getSalesReps(quhead_cust_id, quhead_shipto_id,
230                                         _r.itemsite_item_id, _r.quhead_saletype_id,
231                                         _r.quitem_price, _r.quitem_custprice,
232                                         _soitemid, 'SalesItem')
233       FROM quhead
234       WHERE (quhead_id=pQuheadid);
235     END IF;
236
237     -- Copy Characteristics
238     INSERT INTO charass
239           (charass_target_type, charass_target_id, charass_char_id, charass_value, charass_default, charass_price)
240     SELECT 'SI', _soitemid, charass_char_id, charass_value, charass_default, charass_price
241       FROM charass
242      WHERE ((charass_target_type='QI')
243        AND  (charass_target_id=_r.quitem_id));
244
245     -- Copy Comments
246     INSERT INTO comment
247     ( comment_cmnttype_id, comment_source, comment_source_id, comment_date, comment_user, comment_text )
248     SELECT comment_cmnttype_id, 'SI', _soitemid, comment_date, comment_user, ('Quote-' || comment_text)
249     FROM comment
250     WHERE ( (comment_source='QI')
251       AND   (comment_source_id=_r.quitem_id) );
252
253     _orderid := -1;
254     _ordertype := '';
255     IF (_r.quitem_createorder) THEN
256
257       IF (_r.item_type IN ('M')) THEN
258         SELECT createWo( CAST(_r.quhead_number AS INTEGER), supply.itemsite_id, 1, (_r.quitem_qtyord * _r.quitem_qty_invuomratio),
259                          _r.itemsite_leadtime, _r.quitem_scheddate, _r.quitem_memo, 'S', _soitemid, _r.quhead_prj_id ) INTO _orderId
260         FROM itemsite sold, itemsite supply
261         WHERE ((sold.itemsite_item_id=supply.itemsite_item_id)
262          AND (supply.itemsite_warehous_id=_r.quitem_order_warehous_id)
263          AND (sold.itemsite_id=_r.quitem_itemsite_id) );
264         _orderType := 'W';
265
266         INSERT INTO charass
267               (charass_target_type, charass_target_id, charass_char_id, charass_value)
268         SELECT 'W', _orderId, charass_char_id, charass_value
269           FROM charass
270          WHERE ((charass_target_type='QI')
271            AND  (charass_target_id=_r.quitem_id));
272
273       ELSIF ( (_r.item_type IN ('P', 'O')) AND (_r.itemsite_createsopr) ) THEN
274         SELECT createPr( CAST(_r.quhead_number AS INTEGER), _r.quitem_itemsite_id, (_r.quitem_qtyord * _r.quitem_qty_invuomratio),
275                          _r.quitem_scheddate, '', 'S', _soitemid ) INTO _orderId;
276         _orderType := 'R';
277         UPDATE pr SET pr_prj_id=_r.quhead_prj_id WHERE pr_id=_orderId;
278       ELSIF ( (_r.item_type IN ('P', 'O')) AND (_r.itemsite_createsopo) ) THEN
279         IF (_r.quitem_prcost=0) THEN
280           SELECT createPurchaseToSale(_soitemid, _r.itemsrcid, _r.quitem_dropship) INTO _orderId;
281         ELSE
282           SELECT createPurchaseToSale(_soitemid, _r.itemsrcid, _r.quitem_dropship, _r.quitem_prcost) INTO _orderId;
283         END IF;
284         _orderType := 'P';
285       END IF;
286
287       UPDATE coitem SET coitem_order_type=_ordertype, coitem_order_id=_orderid
288       WHERE (coitem_id=_soitemid);
289
290     END IF;
291
292   END LOOP;
293
294   SELECT metric_value INTO _showConvertedQuote
295   FROM metric WHERE metric_name = 'ShowQuotesAfterSO';
296
297   IF (_showConvertedQuote) THEN
298     UPDATE quhead
299     SET quhead_status= 'C'
300     WHERE (quhead_id = pQuheadid);
301   ELSE
302   PERFORM deleteQuote(pQuheadid);
303   END IF;
304
305   RETURN _soheadid;
306
307 END;
308 $$ LANGUAGE 'plpgsql';
309