1 -- Updatescript von Version 1.02/1.03 auf 2.00
2 -- H.Lindemann Lx-System GbR
6 LOCK TABLE gl IN ACCESS EXCLUSIVE MODE;
7 LOCK TABLE ar IN ACCESS EXCLUSIVE MODE;
8 LOCK TABLE ap IN ACCESS EXCLUSIVE MODE;
10 CREATE SEQUENCE glid start 1 increment 1 maxvalue 9223372036854775807 minvalue 1 cache 1;
12 CREATE FUNCTION _glid()
14 AS 'DECLARE lv record;
16 SELECT INTO lv last_value from id;
17 execute ''SELECT pg_catalog.setval(''''glid'''', '' || lv.last_value || '' , true)'';
18 return cast(lv.last_value as text);
22 drop function _glid();
24 --execute ''CREATE SEQUENCE glid start '' || lv.last_value || ''increment 1 maxvalue 9223372036854775807 minvalue 1 cache 1'';
25 --update glid set last_value = (select last_value from id);
28 ALTER TABLE acc_trans ADD COLUMN gldate date;
29 ALTER TABLE acc_trans ALTER COLUMN gldate SET DEFAULT date('now'::text);
32 ALTER TABLE gl ALTER COLUMN id SET DEFAULT nextval('glid'::text);
33 ALTER TABLE gl ADD COLUMN gldate date;
34 ALTER TABLE gl ALTER COLUMN gldate SET DEFAULT date('now'::text);
35 ALTER TABLE gl ADD COLUMN taxincluded boolean;
38 ALTER TABLE ar ALTER COLUMN id SET DEFAULT nextval('glid'::text);
39 ALTER TABLE ar ADD COLUMN gldate date;
40 ALTER TABLE ar ALTER COLUMN gldate SET DEFAULT date('now'::text);
43 ALTER TABLE ap ALTER COLUMN id SET DEFAULT nextval('glid'::text);
44 ALTER TABLE ap ADD COLUMN gldate date;
45 ALTER TABLE ap ALTER COLUMN gldate SET DEFAULT date('now'::text);
48 ALTER TABLE parts ADD COLUMN shop boolean;
49 ALTER TABLE parts ALTER COLUMN shop SET DEFAULT false;
51 update defaults set version = '2.0.0';
57 CREATE INDEX acc_trans_trans_id_key ON acc_trans USING btree (trans_id);
59 CREATE INDEX acc_trans_chart_id_key ON acc_trans USING btree (chart_id);
61 CREATE INDEX acc_trans_transdate_key ON acc_trans USING btree (transdate);
63 CREATE INDEX acc_trans_source_key ON acc_trans USING btree (lower(source));
65 CREATE INDEX ap_id_key ON ap USING btree (id);
67 CREATE INDEX ap_transdate_key ON ap USING btree (transdate);
69 CREATE INDEX ap_invnumber_key ON ap USING btree (lower(invnumber));
71 CREATE INDEX ap_ordnumber_key ON ap USING btree (lower(ordnumber));
73 CREATE INDEX ap_vendor_id_key ON ap USING btree (vendor_id);
75 CREATE INDEX ap_employee_id_key ON ap USING btree (employee_id);
77 CREATE INDEX ar_id_key ON ar USING btree (id);
79 CREATE INDEX ar_transdate_key ON ar USING btree (transdate);
81 CREATE INDEX ar_invnumber_key ON ar USING btree (lower(invnumber));
83 CREATE INDEX ar_ordnumber_key ON ar USING btree (lower(ordnumber));
85 CREATE INDEX ar_customer_id_key ON ar USING btree (customer_id);
87 CREATE INDEX ar_employee_id_key ON ar USING btree (employee_id);
89 CREATE INDEX assembly_id_key ON assembly USING btree (id);
91 CREATE INDEX chart_id_key ON chart USING btree (id);
93 CREATE UNIQUE INDEX chart_accno_key ON chart USING btree (accno);
95 CREATE INDEX chart_category_key ON chart USING btree (category);
97 CREATE INDEX chart_link_key ON chart USING btree (link);
99 CREATE INDEX chart_gifi_accno_key ON chart USING btree (gifi_accno);
101 CREATE INDEX customer_id_key ON customer USING btree (id);
103 CREATE INDEX customer_customer_id_key ON customertax USING btree (customer_id);
105 CREATE INDEX customer_customernumber_key ON customer USING btree (customernumber);
107 CREATE INDEX customer_name_key ON customer USING btree (name);
109 CREATE INDEX customer_contact_key ON customer USING btree (contact);
111 CREATE INDEX employee_id_key ON employee USING btree (id);
113 CREATE UNIQUE INDEX employee_login_key ON employee USING btree (login);
115 CREATE INDEX employee_name_key ON employee USING btree (name);
117 CREATE INDEX exchangerate_ct_key ON exchangerate USING btree (curr, transdate);
119 CREATE UNIQUE INDEX gifi_accno_key ON gifi USING btree (accno);
121 CREATE INDEX gl_id_key ON gl USING btree (id);
123 CREATE INDEX gl_transdate_key ON gl USING btree (transdate);
125 CREATE INDEX gl_reference_key ON gl USING btree (lower(reference));
127 CREATE INDEX gl_description_key ON gl USING btree (lower(description));
129 CREATE INDEX gl_employee_id_key ON gl USING btree (employee_id);
131 CREATE INDEX invoice_id_key ON invoice USING btree (id);
133 CREATE INDEX invoice_trans_id_key ON invoice USING btree (trans_id);
135 CREATE INDEX oe_id_key ON oe USING btree (id);
137 CREATE INDEX oe_transdate_key ON oe USING btree (transdate);
139 CREATE INDEX oe_ordnumber_key ON oe USING btree (lower(ordnumber));
141 CREATE INDEX oe_employee_id_key ON oe USING btree (employee_id);
143 CREATE INDEX orderitems_trans_id_key ON orderitems USING btree (trans_id);
145 CREATE INDEX parts_id_key ON parts USING btree (id);
147 CREATE INDEX parts_partnumber_key ON parts USING btree (lower(partnumber));
149 CREATE INDEX parts_description_key ON parts USING btree (lower(description));
151 CREATE INDEX partstax_parts_id_key ON partstax USING btree (parts_id);
153 CREATE INDEX vendor_id_key ON vendor USING btree (id);
155 CREATE INDEX vendor_name_key ON vendor USING btree (name);
157 CREATE INDEX vendor_vendornumber_key ON vendor USING btree (vendornumber);
159 CREATE INDEX vendor_contact_key ON vendor USING btree (contact);
161 CREATE INDEX vendortax_vendor_id_key ON vendortax USING btree (vendor_id);
163 CREATE INDEX shipto_trans_id_key ON shipto USING btree (trans_id);
165 CREATE INDEX project_id_key ON project USING btree (id);
167 CREATE INDEX ar_quonumber_key ON ar USING btree (lower(quonumber));
169 CREATE INDEX ap_quonumber_key ON ap USING btree (lower(quonumber));
171 CREATE INDEX makemodel_parts_id_key ON makemodel USING btree (parts_id);
173 CREATE INDEX makemodel_make_key ON makemodel USING btree (lower(make));
175 CREATE INDEX makemodel_model_key ON makemodel USING btree (lower(model));
177 CREATE INDEX status_trans_id_key ON status USING btree (trans_id);
179 CREATE INDEX department_id_key ON department USING btree (id);
181 CREATE INDEX orderitems_id_key ON orderitems USING btree (id);
183 CREATE INDEX contact_name_key ON contacts USING btree (cp_name);
186 SET check_function_bodies = false;
188 CREATE FUNCTION del_yearend() RETURNS "trigger"
191 delete from yearend where trans_id = old.id;
197 CREATE FUNCTION del_department() RETURNS "trigger"
200 delete from dpt_trans where trans_id = old.id;
206 CREATE FUNCTION del_customer() RETURNS "trigger"
209 delete from shipto where trans_id = old.id;
210 delete from customertax where customer_id = old.id;
216 CREATE FUNCTION del_vendor() RETURNS "trigger"
219 delete from shipto where trans_id = old.id;
220 delete from vendortax where vendor_id = old.id;
226 CREATE FUNCTION del_exchangerate() RETURNS "trigger"
234 select into d_curr substr(curr,1,3) from defaults;
235 if TG_RELNAME = ''ar'' then
236 select into t_curr, t_transdate curr, transdate from ar where id = old.id;
238 if TG_RELNAME = ''ap'' then
239 select into t_curr, t_transdate curr, transdate from ap where id = old.id;
241 if TG_RELNAME = ''oe'' then
242 select into t_curr, t_transdate curr, transdate from oe where id = old.id;
244 if d_curr != t_curr then
245 select into t_id a.id from acc_trans ac
246 join ar a on (a.id = ac.trans_id)
247 where a.curr = t_curr
248 and ac.transdate = t_transdate
249 except select a.id from ar a where a.id = old.id
251 select a.id from acc_trans ac
252 join ap a on (a.id = ac.trans_id)
253 where a.curr = t_curr
254 and ac.transdate = t_transdate
255 except select a.id from ap a where a.id = old.id
257 select o.id from oe o
258 where o.curr = t_curr
259 and o.transdate = t_transdate
260 except select o.id from oe o where o.id = old.id;
262 delete from exchangerate where curr = t_curr and transdate = t_transdate;
270 CREATE FUNCTION check_inventory() RETURNS "trigger"
274 row_data inventory%rowtype;
276 if not old.quotation then
277 for row_data in select * from inventory where oe_id = old.id loop
278 select into itemid id from orderitems where trans_id = old.id and id = row_data.orderitems_id;
279 if itemid is null then
280 delete from inventory where oe_id = old.id and orderitems_id = row_data.orderitems_id;
289 CREATE FUNCTION check_department() RETURNS "trigger"
294 if new.department_id = 0 then
295 delete from dpt_trans where trans_id = new.id;
298 select into dpt_id trans_id from dpt_trans where trans_id = new.id;
300 update dpt_trans set department_id = new.department_id where trans_id = dpt_id;
302 insert into dpt_trans (trans_id, department_id) values (new.id, new.department_id);
310 CREATE TRIGGER del_yearend
313 EXECUTE PROCEDURE del_yearend();
315 CREATE TRIGGER del_department
318 EXECUTE PROCEDURE del_department();
320 CREATE TRIGGER del_department
323 EXECUTE PROCEDURE del_department();
325 CREATE TRIGGER del_department
328 EXECUTE PROCEDURE del_department();
330 CREATE TRIGGER del_department
333 EXECUTE PROCEDURE del_department();
335 CREATE TRIGGER del_customer
336 AFTER DELETE ON customer
338 EXECUTE PROCEDURE del_customer();
340 CREATE TRIGGER del_vendor
341 AFTER DELETE ON vendor
343 EXECUTE PROCEDURE del_vendor();
345 CREATE TRIGGER del_exchangerate
348 EXECUTE PROCEDURE del_exchangerate();
350 CREATE TRIGGER del_exchangerate
353 EXECUTE PROCEDURE del_exchangerate();
355 CREATE TRIGGER del_exchangerate
358 EXECUTE PROCEDURE del_exchangerate();
360 CREATE TRIGGER check_inventory
363 EXECUTE PROCEDURE check_inventory();
365 CREATE TRIGGER check_department
366 AFTER INSERT OR UPDATE ON ar
368 EXECUTE PROCEDURE check_department();
370 CREATE TRIGGER check_department
371 AFTER INSERT OR UPDATE ON ap
373 EXECUTE PROCEDURE check_department();
375 CREATE TRIGGER check_department
376 AFTER INSERT OR UPDATE ON gl
378 EXECUTE PROCEDURE check_department();
380 CREATE TRIGGER check_department
381 AFTER INSERT OR UPDATE ON oe
383 EXECUTE PROCEDURE check_department();