summaryrefslogtreecommitdiff
path: root/sql/Pg-tables.sql
blob: f523bcba5acbadfcc8399d4c0e376ca972b3499c (plain)
  1. --
  2. CREATE SEQUENCE id start 10000;
  3. SELECT nextval ('id');
  4. --
  5. CREATE SEQUENCE invoiceid;
  6. SELECT nextval ('invoiceid');
  7. --
  8. CREATE SEQUENCE orderitemsid;
  9. SELECT nextval ('orderitemsid');
  10. --
  11. CREATE SEQUENCE jcitemsid;
  12. SELECT nextval ('jcitemsid');
  13. --
  14. CREATE TABLE makemodel (
  15. parts_id int,
  16. make text,
  17. model text
  18. );
  19. --
  20. CREATE TABLE gl (
  21. id int DEFAULT nextval ( 'id' ),
  22. reference text,
  23. description text,
  24. transdate date DEFAULT current_date,
  25. employee_id int,
  26. notes text,
  27. department_id int default 0
  28. );
  29. --
  30. CREATE TABLE chart (
  31. id int DEFAULT nextval ( 'id' ),
  32. accno text NOT NULL,
  33. description text,
  34. charttype char(1) DEFAULT 'A',
  35. category char(1),
  36. link text,
  37. gifi_accno text,
  38. contra bool DEFAULT 'f'
  39. );
  40. --
  41. CREATE TABLE gifi (
  42. accno text,
  43. description text
  44. );
  45. --
  46. CREATE TABLE defaults (
  47. inventory_accno_id int,
  48. income_accno_id int,
  49. expense_accno_id int,
  50. fxgain_accno_id int,
  51. fxloss_accno_id int,
  52. sinumber text,
  53. sonumber text,
  54. yearend varchar(5),
  55. weightunit varchar(5),
  56. businessnumber text,
  57. version varchar(8),
  58. curr text,
  59. closedto date,
  60. revtrans bool DEFAULT 'f',
  61. ponumber text,
  62. sqnumber text,
  63. rfqnumber text,
  64. audittrail bool default 'f',
  65. vinumber text,
  66. employeenumber text,
  67. partnumber text,
  68. customernumber text,
  69. vendornumber text,
  70. glnumber text,
  71. projectnumber text
  72. );
  73. INSERT INTO defaults (version) VALUES ('2.6.17');
  74. --
  75. CREATE TABLE acc_trans (
  76. trans_id int,
  77. chart_id int NOT NULL REFERENCES chart (id),
  78. amount numeric(10,2),
  79. transdate date DEFAULT current_date,
  80. source text,
  81. cleared bool DEFAULT 'f',
  82. fx_transaction bool DEFAULT 'f',
  83. project_id int,
  84. memo text,
  85. invoice_id int
  86. );
  87. --
  88. CREATE TABLE invoice (
  89. id int DEFAULT nextval ( 'invoiceid' ),
  90. trans_id int,
  91. parts_id int,
  92. description text,
  93. qty integer,
  94. allocated integer,
  95. sellprice numeric(10,2),
  96. fxsellprice numeric(10,2),
  97. discount float4, -- jd: check into this
  98. assemblyitem bool DEFAULT 'f',
  99. unit varchar(5),
  100. project_id int,
  101. deliverydate date,
  102. serialnumber text,
  103. notes text
  104. );
  105. --
  106. CREATE TABLE customer (
  107. id int default nextval('id'),
  108. name varchar(64),
  109. address1 varchar(32),
  110. address2 varchar(32),
  111. city varchar(32),
  112. state varchar(32),
  113. zipcode varchar(10),
  114. country varchar(32),
  115. contact varchar(64),
  116. phone varchar(20),
  117. fax varchar(20),
  118. email text,
  119. notes text,
  120. discount numeric,
  121. taxincluded bool default 'f',
  122. creditlimit numeric(10,2) default 0,
  123. terms int2 default 0,
  124. customernumber varchar(32),
  125. cc text,
  126. bcc text,
  127. business_id int,
  128. taxnumber varchar(32),
  129. sic_code varchar(6),
  130. iban varchar(34),
  131. bic varchar(11),
  132. employee_id int,
  133. language_code varchar(6),
  134. pricegroup_id int,
  135. curr char(3),
  136. startdate date,
  137. enddate date
  138. );
  139. --
  140. --
  141. CREATE TABLE parts (
  142. id int DEFAULT nextval ( 'id' ),
  143. partnumber text,
  144. description text,
  145. unit varchar(5),
  146. listprice numeric(10,2),
  147. sellprice numeric(10,2),
  148. lastcost numeric(10,2),
  149. priceupdate date DEFAULT current_date,
  150. weight numeric,
  151. onhand numeric DEFAULT 0,
  152. notes text,
  153. makemodel bool DEFAULT 'f',
  154. assembly bool DEFAULT 'f',
  155. alternate bool DEFAULT 'f',
  156. rop float4, -- jd: what is this
  157. inventory_accno_id int,
  158. income_accno_id int,
  159. expense_accno_id int,
  160. bin text,
  161. obsolete bool DEFAULT 'f',
  162. bom bool DEFAULT 'f',
  163. image text,
  164. drawing text,
  165. microfiche text,
  166. partsgroup_id int,
  167. project_id int,
  168. avgcost numeric(10,2)
  169. );
  170. --
  171. CREATE TABLE assembly (
  172. id int,
  173. parts_id int,
  174. qty numeric,
  175. bom bool,
  176. adj bool
  177. ) WITH OIDS;
  178. --
  179. CREATE TABLE ar (
  180. id int DEFAULT nextval ( 'id' ),
  181. invnumber text,
  182. transdate date DEFAULT current_date,
  183. customer_id int,
  184. taxincluded bool,
  185. amount numeric(10,2),
  186. netamount numeric(10,2),
  187. paid numeric(10,2),
  188. datepaid date,
  189. duedate date,
  190. invoice bool DEFAULT 'f',
  191. shippingpoint text,
  192. terms int2 DEFAULT 0,
  193. notes text,
  194. curr char(3),
  195. ordnumber text,
  196. employee_id int,
  197. till varchar(20),
  198. quonumber text,
  199. intnotes text,
  200. department_id int default 0,
  201. shipvia text,
  202. language_code varchar(6),
  203. ponumber text
  204. );
  205. --
  206. CREATE TABLE ap (
  207. id int DEFAULT nextval ( 'id' ),
  208. invnumber text,
  209. transdate date DEFAULT current_date,
  210. vendor_id int,
  211. taxincluded bool DEFAULT 'f',
  212. amount numeric(10,2),
  213. netamount numeric(10,2),
  214. paid numeric(10,2),
  215. datepaid date,
  216. duedate date,
  217. invoice bool DEFAULT 'f',
  218. ordnumber text,
  219. curr char(3),
  220. notes text,
  221. employee_id int,
  222. till varchar(20),
  223. quonumber text,
  224. intnotes text,
  225. department_id int DEFAULT 0,
  226. shipvia text,
  227. language_code varchar(6),
  228. ponumber text,
  229. shippingpoint text,
  230. terms int2 DEFAULT 0
  231. );
  232. --
  233. CREATE TABLE partstax (
  234. parts_id int,
  235. chart_id int
  236. );
  237. --
  238. CREATE TABLE tax (
  239. chart_id int,
  240. rate numeric,
  241. taxnumber text,
  242. validto date
  243. );
  244. --
  245. CREATE TABLE customertax (
  246. customer_id int,
  247. chart_id int
  248. );
  249. --
  250. CREATE TABLE vendortax (
  251. vendor_id int,
  252. chart_id int
  253. );
  254. --
  255. CREATE TABLE oe (
  256. id int default nextval('id'),
  257. ordnumber text,
  258. transdate date default current_date,
  259. vendor_id int,
  260. customer_id int,
  261. amount numeric(10,2),
  262. netamount numeric(10,2),
  263. reqdate date,
  264. taxincluded bool,
  265. shippingpoint text,
  266. notes text,
  267. curr char(3),
  268. employee_id int,
  269. closed bool default 'f',
  270. quotation bool default 'f',
  271. quonumber text,
  272. intnotes text,
  273. department_id int default 0,
  274. shipvia text,
  275. language_code varchar(6),
  276. ponumber text,
  277. terms int2 DEFAULT 0
  278. );
  279. --
  280. CREATE TABLE orderitems (
  281. id int default nextval('orderitemsid'),
  282. trans_id int,
  283. parts_id int,
  284. description text,
  285. qty numeric,
  286. sellprice numeric(10,2),
  287. discount numeric,
  288. unit varchar(5),
  289. project_id int,
  290. reqdate date,
  291. ship numeric,
  292. serialnumber text,
  293. notes text
  294. ) WITH OIDS;
  295. --
  296. CREATE TABLE exchangerate (
  297. curr char(3),
  298. transdate date,
  299. buy numeric,
  300. sell numeric
  301. );
  302. --
  303. create table employee (
  304. id int default nextval('id'),
  305. login text,
  306. name varchar(64),
  307. address1 varchar(32),
  308. address2 varchar(32),
  309. city varchar(32),
  310. state varchar(32),
  311. zipcode varchar(10),
  312. country varchar(32),
  313. workphone varchar(20),
  314. homephone varchar(20),
  315. startdate date default current_date,
  316. enddate date,
  317. notes text,
  318. role varchar(20),
  319. sales bool default 'f',
  320. email text,
  321. ssn varchar(20),
  322. iban varchar(34),
  323. bic varchar(11),
  324. managerid int,
  325. employeenumber varchar(32),
  326. dob date
  327. );
  328. --
  329. create table shipto (
  330. trans_id int,
  331. shiptoname varchar(64),
  332. shiptoaddress1 varchar(32),
  333. shiptoaddress2 varchar(32),
  334. shiptocity varchar(32),
  335. shiptostate varchar(32),
  336. shiptozipcode varchar(10),
  337. shiptocountry varchar(32),
  338. shiptocontact varchar(64),
  339. shiptophone varchar(20),
  340. shiptofax varchar(20),
  341. shiptoemail text
  342. );
  343. --
  344. CREATE TABLE vendor (
  345. id int default nextval('id'),
  346. name varchar(64),
  347. address1 varchar(32),
  348. address2 varchar(32),
  349. city varchar(32),
  350. state varchar(32),
  351. zipcode varchar(10),
  352. country varchar(32),
  353. contact varchar(64),
  354. phone varchar(20),
  355. fax varchar(20),
  356. email text,
  357. notes text,
  358. terms int2 default 0,
  359. taxincluded bool default 'f',
  360. vendornumber varchar(32),
  361. cc text,
  362. bcc text,
  363. gifi_accno varchar(30),
  364. business_id int,
  365. taxnumber varchar(32),
  366. sic_code varchar(6),
  367. discount numeric,
  368. creditlimit numeric default 0,
  369. iban varchar(34),
  370. bic varchar(11),
  371. employee_id int,
  372. language_code varchar(6),
  373. pricegroup_id int,
  374. curr char(3),
  375. startdate date,
  376. enddate date
  377. );
  378. --
  379. CREATE TABLE project (
  380. id int default nextval('id'),
  381. projectnumber text,
  382. description text,
  383. startdate date,
  384. enddate date,
  385. parts_id int,
  386. production numeric default 0,
  387. completed numeric default 0,
  388. customer_id int
  389. );
  390. --
  391. CREATE TABLE partsgroup (
  392. id int default nextval('id'),
  393. partsgroup text
  394. );
  395. --
  396. CREATE TABLE status (
  397. trans_id int,
  398. formname text,
  399. printed bool default 'f',
  400. emailed bool default 'f',
  401. spoolfile text
  402. );
  403. --
  404. CREATE TABLE department (
  405. id int default nextval('id'),
  406. description text,
  407. role char(1) default 'P'
  408. );
  409. --
  410. -- department transaction table
  411. CREATE TABLE dpt_trans (
  412. trans_id int,
  413. department_id int
  414. );
  415. --
  416. -- business table
  417. CREATE TABLE business (
  418. id int default nextval('id'),
  419. description text,
  420. discount numeric
  421. );
  422. --
  423. -- SIC
  424. CREATE TABLE sic (
  425. code varchar(6),
  426. sictype char(1),
  427. description text
  428. );
  429. --
  430. CREATE TABLE warehouse (
  431. id int default nextval('id'),
  432. description text
  433. );
  434. --
  435. CREATE TABLE inventory (
  436. warehouse_id int,
  437. parts_id int,
  438. trans_id int,
  439. orderitems_id int,
  440. qty numeric,
  441. shippingdate date,
  442. employee_id int
  443. ) WITH OIDS;
  444. --
  445. CREATE TABLE yearend (
  446. trans_id int,
  447. transdate date
  448. );
  449. --
  450. CREATE TABLE partsvendor (
  451. vendor_id int,
  452. parts_id int,
  453. partnumber text,
  454. leadtime int2,
  455. lastcost numeric(10,2),
  456. curr char(3)
  457. );
  458. --
  459. CREATE TABLE pricegroup (
  460. id int default nextval('id'),
  461. pricegroup text
  462. );
  463. --
  464. CREATE TABLE partscustomer (
  465. parts_id int,
  466. customer_id int,
  467. pricegroup_id int,
  468. pricebreak numeric,
  469. sellprice numeric(10,2),
  470. validfrom date,
  471. validto date,
  472. curr char(3)
  473. );
  474. --
  475. CREATE TABLE language (
  476. code varchar(6),
  477. description text
  478. );
  479. --
  480. CREATE TABLE audittrail (
  481. trans_id int,
  482. tablename text,
  483. reference text,
  484. formname text,
  485. action text,
  486. transdate timestamp default current_timestamp,
  487. employee_id int
  488. );
  489. --
  490. CREATE TABLE translation (
  491. trans_id int,
  492. language_code varchar(6),
  493. description text
  494. );
  495. --
  496. CREATE TABLE recurring (
  497. id int,
  498. reference text,
  499. startdate date,
  500. nextdate date,
  501. enddate date,
  502. repeat int2,
  503. unit varchar(6),
  504. howmany int,
  505. payment bool default 'f'
  506. );
  507. --
  508. CREATE TABLE recurringemail (
  509. id int,
  510. formname text,
  511. format text,
  512. message text
  513. );
  514. --
  515. CREATE TABLE recurringprint (
  516. id int,
  517. formname text,
  518. format text,
  519. printer text
  520. );
  521. --
  522. CREATE TABLE jcitems (
  523. id int default nextval('jcitemsid'),
  524. project_id int,
  525. parts_id int,
  526. description text,
  527. qty numeric,
  528. allocated numeric,
  529. sellprice numeric(10,2),
  530. fxsellprice numeric(10,2),
  531. serialnumber text,
  532. checkedin timestamp with time zone,
  533. checkedout timestamp with time zone,
  534. employee_id int,
  535. notes text
  536. );
  537. -- Session tracking table
  538. CREATE SEQUENCE session_session_id_seq;
  539. CREATE TABLE session(
  540. session_id INTEGER PRIMARY KEY DEFAULT nextval('session_session_id_seq'),
  541. sl_login VARCHAR(50),
  542. token CHAR(32),
  543. last_used TIMESTAMP default now()
  544. );
  545. create table transaction_ledger (
  546. id int PRIMARY KEY,
  547. table_name text
  548. );
  549. insert into transaction_ledger (id, table_name) SELECT id, 'ap' FROM ap;
  550. CREATE RULE ap_id_track_i AS ON insert TO ap
  551. DO ALSO INSERT INTO transaction_ledger (id, table_name) VALUES (new.id, 'ap');
  552. CREATE RULE ap_id_track_u AS ON update TO ap
  553. DO ALSO UPDATE transaction_ledger SET id = new.id WHERE id = old.id;
  554. insert into transaction_ledger (id, table_name) SELECT id, 'ar' FROM ap;
  555. CREATE RULE ar_id_track_i AS ON insert TO ar
  556. DO ALSO INSERT INTO transaction_ledger (id, table_name) VALUES (new.id, 'ar');
  557. CREATE RULE ar_id_track_u AS ON update TO ar
  558. DO ALSO UPDATE transaction_ledger SET id = new.id WHERE id = old.id;
  559. INSERT INTO transaction_ledger (id, table_name) SELECT id, 'business' FROM business;
  560. CREATE RULE business_id_track_i AS ON insert TO business
  561. DO ALSO INSERT INTO transaction_ledger (id, table_name) VALUES (new.id, 'business');
  562. CREATE RULE business_id_track_u AS ON update TO business
  563. DO ALSO UPDATE transaction_ledger SET id = new.id WHERE id = old.id;
  564. INSERT INTO transaction_ledger (id, table_name) SELECT id, 'chart' FROM chart;
  565. CREATE RULE chart_id_track_i AS ON insert TO chart
  566. DO ALSO INSERT INTO transaction_ledger (id, table_name) VALUES (new.id, 'chart');
  567. CREATE RULE chart_id_track_u AS ON update TO chart
  568. DO ALSO UPDATE transaction_ledger SET id = new.id WHERE id = old.id;
  569. INSERT INTO transaction_ledger (id, table_name) SELECT id, 'customer' FROM customer;
  570. CREATE RULE customer_id_track_i AS ON insert TO customer
  571. DO ALSO INSERT INTO transaction_ledger (id, table_name) VALUES (new.id, 'customer');
  572. CREATE RULE customer_id_track_u AS ON update TO customer
  573. DO ALSO UPDATE transaction_ledger SET id = new.id WHERE id = old.id;
  574. INSERT INTO transaction_ledger (id, table_name) SELECT id, 'department' FROM department;
  575. CREATE RULE department_id_track_i AS ON insert TO department
  576. DO ALSO INSERT INTO transaction_ledger (id, table_name) VALUES (new.id, 'department');
  577. CREATE RULE department_id_track_u AS ON update TO department
  578. DO ALSO UPDATE transaction_ledger SET id = new.id WHERE id = old.id;
  579. INSERT INTO transaction_ledger (id, table_name) SELECT id, 'employee' FROM employee;
  580. CREATE RULE employee_id_track_i AS ON insert TO employee
  581. DO ALSO INSERT INTO transaction_ledger (id, table_name) VALUES (new.id, 'employee');
  582. CREATE RULE employee_id_track_u AS ON update TO employee
  583. DO ALSO UPDATE transaction_ledger SET id = new.id WHERE id = old.id;
  584. INSERT INTO transaction_ledger (id, table_name) SELECT id, 'gl' FROM gl;
  585. CREATE RULE gl_id_track_i AS ON insert TO gl
  586. DO ALSO INSERT INTO transaction_ledger (id, table_name) VALUES (new.id, 'gl');
  587. CREATE RULE gl_id_track_u AS ON update TO gl
  588. DO ALSO UPDATE transaction_ledger SET id = new.id WHERE id = old.id;
  589. INSERT INTO transaction_ledger (id, table_name) SELECT id, 'oe' FROM oe;
  590. CREATE RULE oe_id_track_i AS ON insert TO oe
  591. DO ALSO INSERT INTO transaction_ledger (id, table_name) VALUES (new.id, 'oe');
  592. CREATE RULE oe_id_track_u AS ON update TO oe
  593. DO ALSO UPDATE transaction_ledger SET id = new.id WHERE id = old.id;
  594. INSERT INTO transaction_ledger (id, table_name) SELECT id, 'parts' FROM parts;
  595. CREATE RULE parts_id_track_i AS ON insert TO parts
  596. DO ALSO INSERT INTO transaction_ledger (id, table_name) VALUES (new.id, 'parts');
  597. CREATE RULE parts_id_track_u AS ON update TO parts
  598. DO ALSO UPDATE transaction_ledger SET id = new.id WHERE id = old.id;
  599. INSERT INTO transaction_ledger (id, table_name) SELECT id, 'partsgroup' FROM partsgroup;
  600. CREATE RULE partsgroup_id_track_i AS ON insert TO partsgroup
  601. DO ALSO INSERT INTO transaction_ledger (id, table_name) VALUES (new.id, 'partsgroup');
  602. CREATE RULE partsgroup_id_track_u AS ON update TO partsgroup
  603. DO ALSO UPDATE transaction_ledger SET id = new.id WHERE id = old.id;
  604. INSERT INTO transaction_ledger (id, table_name) SELECT id, 'pricegroup' FROM pricegroup;
  605. CREATE RULE pricegroup_id_track_i AS ON insert TO pricegroup
  606. DO ALSO INSERT INTO transaction_ledger (id, table_name) VALUES (new.id, 'pricegroup');
  607. CREATE RULE pricegroup_id_track_u AS ON update TO pricegroup
  608. DO ALSO UPDATE transaction_ledger SET id = new.id WHERE id = old.id;
  609. INSERT INTO transaction_ledger (id, table_name) SELECT id, 'project' FROM project;
  610. CREATE RULE project_id_track_i AS ON insert TO project
  611. DO ALSO INSERT INTO transaction_ledger (id, table_name) VALUES (new.id, 'project');
  612. CREATE RULE project_id_track_u AS ON update TO project
  613. DO ALSO UPDATE transaction_ledger SET id = new.id WHERE id = old.id;
  614. INSERT INTO transaction_ledger (id, table_name) SELECT id, 'vendor' FROM vendor;
  615. CREATE RULE vendor_id_track_i AS ON insert TO vendor
  616. DO ALSO INSERT INTO transaction_ledger (id, table_name) VALUES (new.id, 'vendor');
  617. CREATE RULE employee_id_track_u AS ON update TO vendor
  618. DO ALSO UPDATE transaction_ledger SET id = new.id WHERE id = old.id;
  619. INSERT INTO transaction_ledger (id, table_name) SELECT id, 'warehouse' FROM warehouse;
  620. CREATE RULE warehouse_id_track_i AS ON insert TO warehouse
  621. DO ALSO INSERT INTO transaction_ledger (id, table_name) VALUES (new.id, 'employee');
  622. CREATE RULE warehouse_id_track_u AS ON update TO warehouse
  623. DO ALSO UPDATE transaction_ledger SET id = new.id WHERE id = old.id;