e26484e9c64f179639f75a0c425b4209e8b29918
[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, COALESCE(quhead_custponumber, ''), cohead_id INTO _qunumber, _ponumber, _soheadid
69     FROM quhead LEFT OUTER JOIN cohead ON ( (cohead_cust_id=quhead_cust_id) AND
70                                             (UPPER(cohead_custponumber)=UPPER(quhead_custponumber)) )
71     WHERE (quhead_id=pQuheadid);
72     IF (_ponumber = '') THEN
73       RAISE EXCEPTION 'Customer PO required for Quote % [xtuple: convertQuote, -7, %]',
74                       _qunumber, _qunumber;
75     END IF;
76   
77     IF ( (NOT _blanketpos) AND (_soheadid IS NOT NULL) ) THEN
78       RAISE EXCEPTION 'Duplicate Customer PO % for Quote % [xtuple: convertQuote, -8, %, %]',
79                       _ponumber, _qunumber,
80                       _ponumber, _qunumber;
81     END IF;
82   END IF;
83   
84   PERFORM quhead_number, cohead_id 
85   FROM quhead, cohead 
86   WHERE quhead_id = pQuheadid
87   AND cohead_number = quhead_number;
88
89   IF (FOUND) THEN
90     SELECT fetchSoNumber() INTO _soNum;
91   ELSE
92     SELECT quhead_number INTO _soNum
93     FROM quhead
94     WHERE quhead_id = pQuheadid;
95   END IF;
96
97   SELECT NEXTVAL('cohead_cohead_id_seq') INTO _soheadid;
98   INSERT INTO cohead
99   ( cohead_id, cohead_number, cohead_cust_id,
100     cohead_orderdate, cohead_packdate,
101     cohead_custponumber, cohead_warehous_id,
102     cohead_billtoname, cohead_billtoaddress1,
103     cohead_billtoaddress2, cohead_billtoaddress3,
104     cohead_billtocity, cohead_billtostate, cohead_billtozipcode,
105     cohead_billtocountry,
106     cohead_shipto_id, cohead_shiptoname, cohead_shiptoaddress1,
107     cohead_shiptoaddress2, cohead_shiptoaddress3,
108     cohead_shiptocity, cohead_shiptostate, cohead_shiptozipcode,
109     cohead_shiptocountry,
110     cohead_salesrep_id, cohead_commission,
111     cohead_terms_id, cohead_shipchrg_id, cohead_shipform_id,
112     cohead_fob, cohead_shipvia,
113     cohead_ordercomments, cohead_shipcomments,
114     cohead_freight, cohead_misc, cohead_misc_accnt_id, cohead_misc_descrip,
115     cohead_holdtype, cohead_wasquote, cohead_quote_number, cohead_prj_id,
116     cohead_curr_id, cohead_taxzone_id, cohead_taxtype_id,
117     cohead_shipto_cntct_id, cohead_shipto_cntct_honorific, cohead_shipto_cntct_first_name,
118     cohead_shipto_cntct_middle, cohead_shipto_cntct_last_name, cohead_shipto_cntct_suffix,
119     cohead_shipto_cntct_phone, cohead_shipto_cntct_title, cohead_shipto_cntct_fax, 
120     cohead_shipto_cntct_email,
121     cohead_billto_cntct_id, cohead_billto_cntct_honorific,
122     cohead_billto_cntct_first_name, cohead_billto_cntct_middle, cohead_billto_cntct_last_name, 
123     cohead_billto_cntct_suffix, cohead_billto_cntct_phone, cohead_billto_cntct_title, 
124     cohead_billto_cntct_fax, cohead_billto_cntct_email, cohead_ophead_id,
125     cohead_calcfreight, cohead_saletype_id, cohead_shipzone_id )
126   SELECT _soheadid, _soNum, quhead_cust_id,
127          CURRENT_DATE, quhead_packdate,
128          quhead_custponumber, quhead_warehous_id,
129          quhead_billtoname, quhead_billtoaddress1,
130          quhead_billtoaddress2, quhead_billtoaddress3,
131          quhead_billtocity, quhead_billtostate, quhead_billtozip,
132          quhead_billtocountry,
133          quhead_shipto_id, quhead_shiptoname, quhead_shiptoaddress1,
134          quhead_shiptoaddress2, quhead_shiptoaddress3,
135          quhead_shiptocity, quhead_shiptostate, quhead_shiptozipcode,
136          quhead_shiptocountry,
137          quhead_salesrep_id, quhead_commission,
138          quhead_terms_id, cust_shipchrg_id, cust_shipform_id,
139          quhead_fob, quhead_shipvia,
140          quhead_ordercomments, quhead_shipcomments,
141          quhead_freight, quhead_misc, quhead_misc_accnt_id, quhead_misc_descrip,
142          'N', TRUE, quhead_number, quhead_prj_id,
143          quhead_curr_id, quhead_taxzone_id, quhead_taxtype_id,
144          quhead_shipto_cntct_id, quhead_shipto_cntct_honorific,
145          quhead_shipto_cntct_first_name, quhead_shipto_cntct_middle, quhead_shipto_cntct_last_name,
146          quhead_shipto_cntct_suffix, quhead_shipto_cntct_phone, quhead_shipto_cntct_title,
147          quhead_shipto_cntct_fax, quhead_shipto_cntct_email, quhead_billto_cntct_id,
148          quhead_billto_cntct_honorific, quhead_billto_cntct_first_name, quhead_billto_cntct_middle,
149          quhead_billto_cntct_last_name, quhead_billto_cntct_suffix, quhead_billto_cntct_phone,
150          quhead_billto_cntct_title, quhead_billto_cntct_fax, quhead_billto_cntct_email, quhead_ophead_id,
151          quhead_calcfreight, quhead_saletype_id, quhead_shipzone_id
152   FROM quhead JOIN custinfo ON (cust_id=quhead_cust_id)
153   WHERE (quhead_id=pQuheadid);
154
155   -- Move Documents
156   UPDATE url SET url_source_id = _soheadid,
157                  url_source = 'S'
158   WHERE ((url_source='Q') AND (url_source_id = pQuheadid));
159
160   UPDATE imageass SET imageass_source_id = _soheadid,
161                       imageass_source = 'S'
162   WHERE ((imageass_source='Q') AND (imageass_source_id = pQuheadid));
163
164   UPDATE docass SET docass_source_id = _soheadid,
165                     docass_source_type = 'S'
166   WHERE ((docass_source_type='Q') AND (docass_source_id = pQuheadid));
167
168   -- Move Email
169   IF (fetchMetricBool('EnableBatchManager')) THEN
170     UPDATE xtbatch.emlassc SET emlassc_type='S',
171                                emlassc_assc_id=_soheadid
172     WHERE ((emlassc_type='Q') AND (emlassc_assc_id=pQuheadid));
173   END IF;
174
175   -- Copy Characteristics
176   INSERT INTO charass
177         (charass_target_type, charass_target_id, charass_char_id, charass_value, charass_default, charass_price)
178   SELECT 'SO', _soheadid, charass_char_id, charass_value, charass_default, charass_price
179     FROM charass
180    WHERE ((charass_target_type='QU')
181      AND  (charass_target_id=pQuheadid));
182
183   -- Copy Comments
184   INSERT INTO comment
185   ( comment_cmnttype_id, comment_source, comment_source_id, comment_date, comment_user, comment_text, comment_public )
186   SELECT comment_cmnttype_id, 'S', _soheadid, comment_date, comment_user, ('Quote-' || comment_text), comment_public
187   FROM comment
188   WHERE ( (comment_source='Q')
189     AND   (comment_source_id=pQuheadid) );
190
191   FOR _r IN SELECT quitem.*,
192                    quhead_number, quhead_prj_id, quhead_saletype_id,
193                    itemsite_item_id, itemsite_leadtime,
194                    itemsite_createsopo, itemsite_createsopr,
195                    item_type, COALESCE(quitem_itemsrc_id, itemsrc_id, -1) AS itemsrcid
196             FROM quhead JOIN quitem ON (quitem_quhead_id=quhead_id)
197                         JOIN itemsite ON (itemsite_id=quitem_itemsite_id)
198                         JOIN item ON (item_id=itemsite_item_id)
199                         LEFT OUTER JOIN itemsrc ON ( (itemsrc_item_id=item_id) AND
200                                                      (itemsrc_default) )
201             WHERE (quhead_id=pQuheadid)
202             ORDER BY quitem_linenumber LOOP
203
204     SELECT NEXTVAL('coitem_coitem_id_seq') INTO _soitemid;
205
206     INSERT INTO coitem
207     ( coitem_id, coitem_cohead_id, coitem_linenumber, coitem_itemsite_id,
208       coitem_status, coitem_scheddate, coitem_promdate,
209       coitem_price, coitem_custprice, 
210       coitem_qtyord, coitem_qtyshipped, coitem_qtyreturned,
211       coitem_qty_uom_id, coitem_qty_invuomratio,
212       coitem_price_uom_id, coitem_price_invuomratio,
213       coitem_unitcost, coitem_prcost,
214       coitem_custpn, coitem_memo, coitem_taxtype_id, coitem_order_id )
215     VALUES
216     ( _soitemid, _soheadid, _r.quitem_linenumber, _r.quitem_itemsite_id,
217       'O', _r.quitem_scheddate, _r.quitem_promdate,
218       _r.quitem_price, _r.quitem_custprice,
219       _r.quitem_qtyord, 0, 0,
220       _r.quitem_qty_uom_id, _r.quitem_qty_invuomratio,
221       _r.quitem_price_uom_id, _r.quitem_price_invuomratio,
222       stdcost(_r.itemsite_item_id), _r.quitem_prcost,
223       _r.quitem_custpn, _r.quitem_memo, _r.quitem_taxtype_id, -1 );
224
225     IF (fetchMetricBool('enablextcommissionission')) THEN
226       PERFORM xtcommission.getSalesReps(quhead_cust_id, quhead_shipto_id,
227                                         _r.itemsite_item_id, _r.quhead_saletype_id,
228                                         _r.quitem_price, _r.quitem_custprice,
229                                         _soitemid, 'SalesItem')
230       FROM quhead
231       WHERE (quhead_id=pQuheadid);
232     END IF;
233
234     -- Copy Characteristics
235     INSERT INTO charass
236           (charass_target_type, charass_target_id, charass_char_id, charass_value, charass_default, charass_price)
237     SELECT 'SI', _soitemid, charass_char_id, charass_value, charass_default, charass_price
238       FROM charass
239      WHERE ((charass_target_type='QI')
240        AND  (charass_target_id=_r.quitem_id));
241
242     -- Copy Comments
243     INSERT INTO comment
244     ( comment_cmnttype_id, comment_source, comment_source_id, comment_date, comment_user, comment_text )
245     SELECT comment_cmnttype_id, 'SI', _soitemid, comment_date, comment_user, ('Quote-' || comment_text)
246     FROM comment
247     WHERE ( (comment_source='QI')
248       AND   (comment_source_id=_r.quitem_id) );
249
250     _orderid := -1;
251     _ordertype := '';
252     IF (_r.quitem_createorder) THEN
253
254       IF (_r.item_type IN ('M')) THEN
255         SELECT createWo( CAST(_r.quhead_number AS INTEGER), supply.itemsite_id, 1, (_r.quitem_qtyord * _r.quitem_qty_invuomratio),
256                          _r.itemsite_leadtime, _r.quitem_scheddate, _r.quitem_memo, 'S', _soitemid, _r.quhead_prj_id ) INTO _orderId
257         FROM itemsite sold, itemsite supply
258         WHERE ((sold.itemsite_item_id=supply.itemsite_item_id)
259          AND (supply.itemsite_warehous_id=_r.quitem_order_warehous_id)
260          AND (sold.itemsite_id=_r.quitem_itemsite_id) );
261         _orderType := 'W';
262
263         INSERT INTO charass
264               (charass_target_type, charass_target_id, charass_char_id, charass_value)
265         SELECT 'W', _orderId, charass_char_id, charass_value
266           FROM charass
267          WHERE ((charass_target_type='QI')
268            AND  (charass_target_id=_r.quitem_id));
269
270       ELSIF ( (_r.item_type IN ('P', 'O')) AND (_r.itemsite_createsopr) ) THEN
271         SELECT createPr( CAST(_r.quhead_number AS INTEGER), _r.quitem_itemsite_id, (_r.quitem_qtyord * _r.quitem_qty_invuomratio),
272                          _r.quitem_scheddate, '', 'S', _soitemid ) INTO _orderId;
273         _orderType := 'R';
274         UPDATE pr SET pr_prj_id=_r.quhead_prj_id WHERE pr_id=_orderId;
275       ELSIF ( (_r.item_type IN ('P', 'O')) AND (_r.itemsite_createsopo) ) THEN
276         IF (_r.quitem_prcost=0) THEN
277           SELECT createPurchaseToSale(_soitemid, _r.itemsrcid, _r.quitem_dropship) INTO _orderId;
278         ELSE
279           SELECT createPurchaseToSale(_soitemid, _r.itemsrcid, _r.quitem_dropship, _r.quitem_prcost) INTO _orderId;
280         END IF;
281         _orderType := 'P';
282       END IF;
283
284       UPDATE coitem SET coitem_order_type=_ordertype, coitem_order_id=_orderid
285       WHERE (coitem_id=_soitemid);
286
287     END IF;
288
289   END LOOP;
290
291   SELECT metric_value INTO _showConvertedQuote
292   FROM metric WHERE metric_name = 'ShowQuotesAfterSO';
293
294   IF (_showConvertedQuote) THEN
295     UPDATE quhead
296     SET quhead_status= 'C'
297     WHERE (quhead_id = pQuheadid);
298   ELSE
299   PERFORM deleteQuote(pQuheadid);
300   END IF;
301
302   RETURN _soheadid;
303
304 END;
305 $$ LANGUAGE 'plpgsql';
306