summaryrefslogtreecommitdiff
path: root/sql/legacy/Pg-upgrade-2.6.17-2.6.18.sql
blob: b73f4c35fddbe33f407d6cd45c7c525bcc3be518 (plain)
  1. ALTER TABLE chart ADD PRIMARY KEY (id);
  2. -- linuxpoet:
  3. -- adding primary key to acc_trans
  4. -- We are using standard postgresql names for the sequence for consistency as we move forward
  5. -- Do everything in a transaction in case it blows up
  6. LOCK acc_trans in EXCLUSIVE mode;
  7. ALTER TABLE acc_trans ADD COLUMN entry_id bigint;
  8. CREATE SEQUENCE acctrans_entry_id_seq;
  9. ALTER TABLE acc_trans ALTER COLUMN entry_id SET DEFAULT nextval('acctrans_entry_id_seq');
  10. UPDATE acc_trans SET entry_id = nextval('acctrans_entry_id_seq');
  11. ALTER TABLE acc_trans ADD PRIMARY key (entry_id);
  12. -- We should probably add a foreign key to chart.id
  13. ALTER TABLE acc_trans ADD FOREIGN KEY (chart_id) REFERENCES chart (id);
  14. -- Start changing floats
  15. ALTER TABLE acc_trans ALTER COLUMN amount TYPE NUMERIC;
  16. -- This may break someone if they for some reason have an actual float type in the qty column
  17. ALTER TABLE invoice ALTER COLUMN qty TYPE numeric;
  18. ALTER TABLE invoice ALTER COLUMN allocated TYPE numeric;
  19. ALTER TABLE invoice ALTER COLUMN sellprice TYPE NUMERIC;
  20. ALTER TABLE invoice ALTER COLUMN fxsellprice TYPE NUMERIC;
  21. ALTER TABLE customer ALTER COLUMN discount TYPE numeric;
  22. ALTER TABLE customer ALTER COLUMN creditlimit TYPE NUMERIC;
  23. ALTER TABLE parts ALTER COLUMN listprice TYPE NUMERIC;
  24. ALTER TABLE parts ALTER COLUMN sellprice TYPE NUMERIC;
  25. ALTER TABLE parts ALTER COLUMN lastcost TYPE NUMERIC;
  26. ALTER TABLE parts ALTER COLUMN weight TYPE numeric;
  27. ALTER TABLE parts ALTER COLUMN onhand TYPE numeric;
  28. ALTER TABLE parts ALTER COLUMN avgcost TYPE NUMERIC;
  29. ALTER TABLE assembly ALTER COLUMN qty TYPE numeric;
  30. ALTER TABLE ar ALTER COLUMN amount TYPE NUMERIC;
  31. ALTER TABLE ar ALTER COLUMN netamount TYPE NUMERIC;
  32. ALTER TABLE ar ALTER COLUMN paid TYPE NUMERIC;
  33. ALTER TABLE ap ALTER COLUMN amount TYPE NUMERIC;
  34. ALTER TABLE ap ALTER COLUMN netamount TYPE NUMERIC;
  35. ALTER TABLE ap ALTER COLUMN paid TYPE NUMERIC;
  36. ALTER TABLE tax ALTER COLUMN rate TYPE numeric;
  37. ALTER TABLE oe ALTER COLUMN amount TYPE NUMERIC;
  38. ALTER TABLE oe ALTER COLUMN netamount TYPE NUMERIC;
  39. ALTER TABLE orderitems ALTER COLUMN qty TYPE numeric;
  40. ALTER TABLE orderitems ALTER COLUMN sellprice TYPE NUMERIC;
  41. ALTER TABLE orderitems ALTER COLUMN discount TYPE numeric;
  42. ALTER TABLE orderitems ALTER COLUMN ship TYPE numeric;
  43. ALTER TABLE exchangerate ALTER COLUMN buy TYPE numeric;
  44. ALTER TABLE exchangerate ALTER COLUMN sell TYPE numeric;
  45. ALTER TABLE vendor ALTER COLUMN discount TYPE numeric;
  46. ALTER TABLE vendor ALTER COLUMN creditlimit TYPE numeric;
  47. ALTER TABLE project ALTER COLUMN production TYPE numeric;
  48. ALTER TABLE project ALTER COLUMN completed TYPE numeric;
  49. ALTER TABLE business ALTER COLUMN discount TYPE numeric;
  50. ALTER TABLE inventory ALTER COLUMN qty TYPE numeric;
  51. ALTER TABLE partsvendor ALTER COLUMN lastcost TYPE NUMERIC;
  52. ALTER TABLE partscustomer ALTER COLUMN pricebreak TYPE numeric;
  53. ALTER TABLE partscustomer ALTER COLUMN sellprice TYPE NUMERIC;
  54. ALTER TABLE jcitems ALTER COLUMN qty TYPE numeric;
  55. ALTER TABLE jcitems ALTER COLUMN allocated TYPE numeric;
  56. ALTER TABLE jcitems ALTER COLUMN sellprice TYPE NUMERIC;
  57. ALTER TABLE jcitems ALTER COLUMN fxsellprice TYPE NUMERIC;
  58. -- The query rewrite rule necessary to notify the email app that a new report
  59. -- needs to be sent to the designated administrator.
  60. -- By Chris Travers
  61. -- chris@metatrontech.com
  62. -- Licensed under the GNU GPL 2.0 or later at your option. See accompanying
  63. -- GPL.txt
  64. CREATE OR REPLACE FUNCTION trigger_parts_short() RETURNS TRIGGER
  65. AS
  66. '
  67. BEGIN
  68. IF NEW.onhand >= NEW.rop THEN
  69. NOTIFY parts_short;
  70. END IF;
  71. RETURN NEW;
  72. END;
  73. ' LANGUAGE PLPGSQL;
  74. -- end function
  75. CREATE TRIGGER parts_short AFTER UPDATE ON parts
  76. FOR EACH ROW EXECUTE PROCEDURE trigger_parts_short();
  77. create table transactions (
  78. id int PRIMARY KEY,
  79. table_name text
  80. );
  81. insert into transactions (id, table_name) SELECT id, 'ap' FROM ap;
  82. CREATE RULE ap_id_track_i AS ON insert TO ap
  83. DO INSERT INTO transactions (id, table_name) VALUES (new.id, 'ap');
  84. CREATE RULE ap_id_track_u AS ON update TO ap
  85. DO UPDATE transactions SET id = new.id WHERE id = old.id;
  86. insert into transactions (id, table_name) SELECT id, 'ar' FROM ar;
  87. CREATE RULE ar_id_track_i AS ON insert TO ar
  88. DO INSERT INTO transactions (id, table_name) VALUES (new.id, 'ar');
  89. CREATE RULE ar_id_track_u AS ON update TO ar
  90. DO UPDATE transactions SET id = new.id WHERE id = old.id;
  91. INSERT INTO transactions (id, table_name) SELECT id, 'business' FROM business;
  92. CREATE RULE business_id_track_i AS ON insert TO business
  93. DO INSERT INTO transactions (id, table_name) VALUES (new.id, 'business');
  94. CREATE RULE business_id_track_u AS ON update TO business
  95. DO UPDATE transactions SET id = new.id WHERE id = old.id;
  96. INSERT INTO transactions (id, table_name) SELECT id, 'chart' FROM chart;
  97. CREATE RULE chart_id_track_i AS ON insert TO chart
  98. DO INSERT INTO transactions (id, table_name) VALUES (new.id, 'chart');
  99. CREATE RULE chart_id_track_u AS ON update TO chart
  100. DO UPDATE transactions SET id = new.id WHERE id = old.id;
  101. INSERT INTO transactions (id, table_name) SELECT id, 'customer' FROM customer;
  102. CREATE RULE customer_id_track_i AS ON insert TO customer
  103. DO INSERT INTO transactions (id, table_name) VALUES (new.id, 'customer');
  104. CREATE RULE customer_id_track_u AS ON update TO customer
  105. DO UPDATE transactions SET id = new.id WHERE id = old.id;
  106. INSERT INTO transactions (id, table_name) SELECT id, 'department' FROM department;
  107. CREATE RULE department_id_track_i AS ON insert TO department
  108. DO INSERT INTO transactions (id, table_name) VALUES (new.id, 'department');
  109. CREATE RULE department_id_track_u AS ON update TO department
  110. DO UPDATE transactions SET id = new.id WHERE id = old.id;
  111. INSERT INTO transactions (id, table_name) SELECT id, 'employee' FROM employee;
  112. CREATE RULE employee_id_track_i AS ON insert TO employee
  113. DO INSERT INTO transactions (id, table_name) VALUES (new.id, 'employee');
  114. CREATE RULE employee_id_track_u AS ON update TO employee
  115. DO UPDATE transactions SET id = new.id WHERE id = old.id;
  116. INSERT INTO transactions (id, table_name) SELECT id, 'gl' FROM gl;
  117. CREATE RULE gl_id_track_i AS ON insert TO gl
  118. DO INSERT INTO transactions (id, table_name) VALUES (new.id, 'gl');
  119. CREATE RULE gl_id_track_u AS ON update TO gl
  120. DO UPDATE transactions SET id = new.id WHERE id = old.id;
  121. INSERT INTO transactions (id, table_name) SELECT id, 'oe' FROM oe;
  122. CREATE RULE oe_id_track_i AS ON insert TO oe
  123. DO INSERT INTO transactions (id, table_name) VALUES (new.id, 'oe');
  124. CREATE RULE oe_id_track_u AS ON update TO oe
  125. DO UPDATE transactions SET id = new.id WHERE id = old.id;
  126. INSERT INTO transactions (id, table_name) SELECT id, 'parts' FROM parts;
  127. CREATE RULE parts_id_track_i AS ON insert TO parts
  128. DO INSERT INTO transactions (id, table_name) VALUES (new.id, 'parts');
  129. CREATE RULE parts_id_track_u AS ON update TO parts
  130. DO UPDATE transactions SET id = new.id WHERE id = old.id;
  131. INSERT INTO transactions (id, table_name) SELECT id, 'partsgroup' FROM partsgroup;
  132. CREATE RULE partsgroup_id_track_i AS ON insert TO partsgroup
  133. DO INSERT INTO transactions (id, table_name) VALUES (new.id, 'partsgroup');
  134. CREATE RULE partsgroup_id_track_u AS ON update TO partsgroup
  135. DO UPDATE transactions SET id = new.id WHERE id = old.id;
  136. INSERT INTO transactions (id, table_name) SELECT id, 'pricegroup' FROM pricegroup;
  137. CREATE RULE pricegroup_id_track_i AS ON insert TO pricegroup
  138. DO INSERT INTO transactions (id, table_name) VALUES (new.id, 'pricegroup');
  139. CREATE RULE pricegroup_id_track_u AS ON update TO pricegroup
  140. DO UPDATE transactions SET id = new.id WHERE id = old.id;
  141. INSERT INTO transactions (id, table_name) SELECT id, 'project' FROM project;
  142. CREATE RULE project_id_track_i AS ON insert TO project
  143. DO INSERT INTO transactions (id, table_name) VALUES (new.id, 'project');
  144. CREATE RULE project_id_track_u AS ON update TO project
  145. DO UPDATE transactions SET id = new.id WHERE id = old.id;
  146. INSERT INTO transactions (id, table_name) SELECT id, 'vendor' FROM vendor;
  147. CREATE RULE vendor_id_track_i AS ON insert TO vendor
  148. DO INSERT INTO transactions (id, table_name) VALUES (new.id, 'vendor');
  149. CREATE RULE employee_id_track_u AS ON update TO vendor
  150. DO UPDATE transactions SET id = new.id WHERE id = old.id;
  151. INSERT INTO transactions (id, table_name) SELECT id, 'warehouse' FROM warehouse;
  152. CREATE RULE warehouse_id_track_i AS ON insert TO warehouse
  153. DO INSERT INTO transactions (id, table_name) VALUES (new.id, 'employee');
  154. CREATE RULE warehouse_id_track_u AS ON update TO warehouse
  155. DO UPDATE transactions SET id = new.id WHERE id = old.id;
  156. CREATE TABLE custom_table_catalog (
  157. table_id SERIAL PRIMARY KEY,
  158. extends TEXT,
  159. table_name TEXT
  160. );
  161. CREATE TABLE custom_field_catalog (
  162. field_id SERIAL PRIMARY KEY,
  163. table_id INT REFERENCES custom_table_catalog,
  164. field_name TEXT
  165. );
  166. CREATE OR REPLACE FUNCTION add_custom_field (VARCHAR, VARCHAR, VARCHAR)
  167. RETURNS BOOL AS
  168. '
  169. DECLARE
  170. table_name ALIAS FOR $1;
  171. new_field_name ALIAS FOR $2;
  172. field_datatype ALIAS FOR $3;
  173. BEGIN
  174. EXECUTE ''SELECT TABLE_ID FROM custom_table_catalog
  175. WHERE extends = '''''' || table_name || '''''' '';
  176. IF NOT FOUND THEN
  177. BEGIN
  178. INSERT INTO custom_table_catalog (extends) VALUES (table_name);
  179. EXECUTE ''CREATE TABLE custom_''||table_name ||
  180. '' (row_id INT)'';
  181. EXCEPTION WHEN duplicate_table THEN
  182. -- do nothing
  183. END;
  184. END IF;
  185. EXECUTE ''INSERT INTO custom_field_catalog (field_name, table_id)
  186. VALUES ( '''''' || new_field_name ||'''''', (SELECT table_id FROM custom_table_catalog
  187. WHERE extends = ''''''|| table_name || ''''''))'';
  188. EXECUTE ''ALTER TABLE custom_''||table_name || '' ADD COLUMN ''
  189. || new_field_name || '' '' || field_datatype;
  190. RETURN TRUE;
  191. END;
  192. ' LANGUAGE PLPGSQL;
  193. -- end function
  194. CREATE OR REPLACE FUNCTION drop_custom_field (VARCHAR, VARCHAR)
  195. RETURNS BOOL AS
  196. '
  197. DECLARE
  198. table_name ALIAS FOR $1;
  199. custom_field_name ALIAS FOR $2;
  200. BEGIN
  201. DELETE FROM custom_field_catalog
  202. WHERE field_name = custom_field_name AND
  203. table_id = (SELECT table_id FROM custom_table_catalog
  204. WHERE extends = table_name);
  205. EXECUTE ''ALTER TABLE custom_'' || table_name ||
  206. '' DROP COLUMN '' || custom_field_name;
  207. RETURN TRUE;
  208. END;
  209. ' LANGUAGE PLPGSQL;
  210. -- end function
  211. UPDATE defaults SET version = '2.6.18';