summaryrefslogtreecommitdiff
path: root/sql/Pg-database.sql
blob: 384e39eb036a3c27e4ac27e8ca7c216955fcd639 (plain)
  1. begin;
  2. CREATE SEQUENCE id;
  3. -- Central DB structure
  4. -- This is the central database stuff which is used across all datasets
  5. -- in the ledger-smb.conf it is called 'ledgersmb' by default, but obviously
  6. -- can be named anything.
  7. -- BEGIN new entity management
  8. CREATE TABLE entity_class (
  9. id serial primary key,
  10. class text check (class ~ '[[:alnum:]_]') NOT NULL,
  11. active boolean not null default TRUE);
  12. COMMENT ON TABLE entity_class IS $$ Defines the class type such as vendor, customer, contact, employee $$;
  13. COMMENT ON COLUMN entity_class.id IS $$ The first 7 values are reserved and permanent $$;
  14. CREATE index entity_class_idx ON entity_class(lower(class));
  15. CREATE TABLE entity (
  16. id serial UNIQUE,
  17. name text check (name ~ '[[:alnum:]_]'),
  18. entity_class integer references entity_class(id) not null ,
  19. created date not null default current_date,
  20. PRIMARY KEY(name,entity_class));
  21. COMMENT ON TABLE entity IS $$ The primary entity table to map to all contacts $$;
  22. COMMENT ON COLUMN entity.name IS $$ This is the common name of an entity. If it was a person it may be Joshua Drake, a company Acme Corp. You may also choose to use a domain such as commandprompt.com $$;
  23. ALTER TABLE entity ADD FOREIGN KEY (entity_class) REFERENCES entity_class(id);
  24. INSERT INTO entity_class (id,class) VALUES (1,'Vendor');
  25. INSERT INTO entity_class (id,class) VALUES (2,'Customer');
  26. INSERT INTO entity_class (id,class) VALUES (3,'Employee');
  27. INSERT INTO entity_class (id,class) VALUES (4,'Contact');
  28. INSERT INTO entity_class (id,class) VALUES (5,'Lead');
  29. INSERT INTO entity_class (id,class) VALUES (6,'Referral');
  30. SELECT setval('entity_class_id_seq',7);
  31. CREATE TABLE entity_class_to_entity (
  32. entity_class_id integer not null references entity_class(id) ON DELETE CASCADE,
  33. entity_id integer not null references entity(id) ON DELETE CASCADE,
  34. PRIMARY KEY(entity_class_id,entity_id)
  35. );
  36. COMMENT ON TABLE entity_class_to_entity IS $$ Relation builder for classes to entity $$;
  37. -- USERS stuff --
  38. CREATE TABLE users (
  39. id serial UNIQUE,
  40. username varchar(30) primary key,
  41. entity_id int not null references entity(id) on delete cascade
  42. );
  43. COMMENT ON TABLE users IS $$username is the actual primary key here because we do not want duplicate users$$;
  44. -- Session tracking table
  45. CREATE TABLE session(
  46. session_id serial PRIMARY KEY,
  47. token VARCHAR(32) CHECK(length(token) = 32),
  48. last_used TIMESTAMP default now(),
  49. ttl int default 3600 not null,
  50. users_id INTEGER NOT NULL references users(id),
  51. transaction_id INTEGER NOT NULL
  52. );
  53. --
  54. CREATE TABLE transactions (
  55. id int PRIMARY KEY,
  56. table_name text,
  57. locked_by int references "session" (session_id) ON DELETE SET NULL
  58. );
  59. COMMENT on TABLE transactions IS
  60. $$ This table tracks basic transactions across AR, AP, and GL related tables.
  61. It provies a referential integrity enforcement mechanism for the financial data
  62. and also some common features such as discretionary (and pessimistic) locking
  63. for long batch workflows. $$;
  64. CREATE OR REPLACE FUNCTION lock_record (int, int) returns bool as
  65. $$
  66. declare
  67. locked int;
  68. begin
  69. SELECT locked_by into locked from transactions where id = $1;
  70. IF NOT FOUND THEN
  71. RETURN FALSE;
  72. ELSEIF locked is not null AND locked <> $2 THEN
  73. RETURN FALSE;
  74. END IF;
  75. UPDATE transactions set locked_by = $2 where id = $1;
  76. RETURN TRUE;
  77. end;
  78. $$ language plpgsql;
  79. COMMENT ON column transactions.locked_by IS
  80. $$ This should only be used in pessimistic locking measures as required by large
  81. batch work flows. $$;
  82. -- LOCATION AND COUNTRY
  83. CREATE TABLE country (
  84. id serial PRIMARY KEY,
  85. name text check (name ~ '[[:alnum:]_]') NOT NULL,
  86. short_name text check (short_name ~ '[[:alnum:]_]') NOT NULL,
  87. itu text);
  88. COMMENT ON COLUMN country.itu IS $$ The ITU Telecommunication Standardization Sector code for calling internationally. For example, the US is 1, Great Britain is 44 $$;
  89. CREATE UNIQUE INDEX country_name_idx on country(lower(name));
  90. CREATE TABLE location_class (
  91. id serial UNIQUE,
  92. class text check (class ~ '[[:alnum:]_]') not null,
  93. authoritative boolean not null,
  94. PRIMARY KEY (class,authoritative));
  95. CREATE UNIQUE INDEX lower_class_unique ON location_class(lower(class));
  96. INSERT INTO location_class(id,class,authoritative) VALUES ('1','Billing',TRUE);
  97. INSERT INTO location_class(id,class,authoritative) VALUES ('2','Sales',TRUE);
  98. INSERT INTO location_class(id,class,authoritative) VALUES ('3','Shipping',TRUE);
  99. SELECT SETVAL('location_class_id_seq',4);
  100. CREATE TABLE location (
  101. id serial PRIMARY KEY,
  102. line_one text check (line_one ~ '[[:alnum:]_]') NOT NULL,
  103. line_two text,
  104. line_three text,
  105. city text check (city ~ '[[:alnum:]_]') NOT NULL,
  106. state text check(state ~ '[[:alnum:]_]') NOT NULL,
  107. country_id integer not null REFERENCES country(id),
  108. mail_code text not null check (mail_code ~ '[[:alnum:]_]'),
  109. created date not null,
  110. inactive_date timestamp default null,
  111. active boolean not null default TRUE
  112. );
  113. CREATE TABLE company (
  114. id serial UNIQUE,
  115. entity_id integer not null references entity(id),
  116. legal_name text check (legal_name ~ '[[:alnum:]_]'),
  117. tax_id text,
  118. created date default current_date not null,
  119. PRIMARY KEY (entity_id,legal_name));
  120. COMMENT ON COLUMN company.tax_id IS $$ In the US this would be a EIN. $$;
  121. CREATE TABLE company_to_location (
  122. location_id integer references location(id) not null,
  123. location_class integer not null references location_class(id),
  124. company_id integer not null references company(id) ON DELETE CASCADE,
  125. PRIMARY KEY(location_id,company_id));
  126. CREATE TABLE salutation (
  127. id serial unique,
  128. salutation text primary key);
  129. INSERT INTO salutation (id,salutation) VALUES ('1','Dr.');
  130. INSERT INTO salutation (id,salutation) VALUES ('2','Miss.');
  131. INSERT INTO salutation (id,salutation) VALUES ('3','Mr.');
  132. INSERT INTO salutation (id,salutation) VALUES ('4','Mrs.');
  133. INSERT INTO salutation (id,salutation) VALUES ('5','Ms.');
  134. INSERT INTO salutation (id,salutation) VALUES ('6','Sir.');
  135. SELECT SETVAL('salutation_id_seq',7);
  136. CREATE TABLE person (
  137. id serial PRIMARY KEY,
  138. entity_id integer references entity(id) not null,
  139. salutation_id integer references salutation(id),
  140. first_name text check (first_name ~ '[[:alnum:]_]') NOT NULL,
  141. middle_name text,
  142. last_name text check (last_name ~ '[[:alnum:]_]') NOT NULL,
  143. created date not null default current_date
  144. );
  145. COMMENT ON TABLE person IS $$ Every person, must have an entity to derive a common or display name. The correct way to get class information on a person would be person.entity_id->entity_class_to_entity.entity_id. $$;
  146. create table entity_employee (
  147. person_id integer references person(id) not null,
  148. entity_id integer references entity(id) not null unique,
  149. startdate date not null default current_date,
  150. enddate date,
  151. role varchar(20),
  152. ssn text,
  153. sales bool default 'f',
  154. manager_id integer references entity(id),
  155. employeenumber varchar(32),
  156. dob date,
  157. PRIMARY KEY (person_id, entity_id)
  158. );
  159. CREATE TABLE person_to_location (
  160. location_id integer not null references location(id),
  161. location_class integer not null references location_class(id),
  162. person_id integer not null references person(id) ON DELETE CASCADE,
  163. PRIMARY KEY (location_id,person_id));
  164. CREATE TABLE person_to_company (
  165. location_id integer references location(id) not null,
  166. person_id integer not null references person(id) ON DELETE CASCADE,
  167. company_id integer not null references company(id) ON DELETE CASCADE,
  168. PRIMARY KEY (location_id,person_id));
  169. CREATE TABLE entity_other_name (
  170. entity_id integer not null references entity(id) ON DELETE CASCADE,
  171. other_name text check (other_name ~ '[[:alnum:]_]'),
  172. PRIMARY KEY (other_name, entity_id));
  173. COMMENT ON TABLE entity_other_name IS $$ Similar to company_other_name, a person may be jd, Joshua Drake, linuxpoet... all are the same person. $$;
  174. CREATE TABLE person_to_entity (
  175. person_id integer not null references person(id) ON DELETE CASCADE,
  176. entity_id integer not null check (entity_id != person_id) references entity(id) ON DELETE CASCADE,
  177. related_how text,
  178. created date not null default current_date,
  179. PRIMARY KEY (person_id,entity_id));
  180. CREATE TABLE company_to_entity (
  181. company_id integer not null references company(id) ON DELETE CASCADE,
  182. entity_id integer check (company_id != entity_id) not null references entity(id) ON DELETE CASCADE,
  183. related_how text,
  184. created date not null default current_date,
  185. PRIMARY KEY (company_id,entity_id));
  186. CREATE TABLE contact_class (
  187. id serial UNIQUE,
  188. class text check (class ~ '[[:alnum:]_]') NOT NULL,
  189. PRIMARY KEY (class));
  190. CREATE UNIQUE INDEX contact_class_class_idx ON contact_class(lower(class));
  191. INSERT INTO contact_class (id,class) values (1,'Primary Phone');
  192. INSERT INTO contact_class (id,class) values (2,'Secondary Phone');
  193. INSERT INTO contact_class (id,class) values (3,'Cell Phone');
  194. INSERT INTO contact_class (id,class) values (4,'AIM');
  195. INSERT INTO contact_class (id,class) values (5,'Yahoo');
  196. INSERT INTO contact_class (id,class) values (6,'Gtalk');
  197. INSERT INTO contact_class (id,class) values (7,'MSN');
  198. INSERT INTO contact_class (id,class) values (8,'IRC');
  199. INSERT INTO contact_class (id,class) values (9,'Fax');
  200. INSERT INTO contact_class (id,class) values (10,'Generic Jabber');
  201. INSERT INTO contact_class (id,class) values (11,'Home Phone');
  202. INSERT INTO contact_class (id,class) values (12,'Email');
  203. SELECT SETVAL('contact_class_id_seq',12);
  204. CREATE TABLE person_to_contact (
  205. person_id integer not null references person(id) ON DELETE CASCADE,
  206. contact_class_id integer references contact_class(id) not null,
  207. contact text check(contact ~ '[[:alnum:]_]') not null,
  208. PRIMARY KEY (person_id,contact_class_id,contact));
  209. COMMENT ON TABLE person_to_contact IS $$ To keep track of the relationship between multiple contact methods and a single individual $$;
  210. CREATE TABLE company_to_contact (
  211. company_id integer not null references company(id) ON DELETE CASCADE,
  212. contact_class_id integer references contact_class(id) not null,
  213. contact text check(contact ~ '[[:alnum:]_]') not null,
  214. description text not null,
  215. PRIMARY KEY (company_id,contact_class_id,contact));
  216. COMMENT ON TABLE company_to_contact IS $$ To keep track of the relationship between multiple contact methods and a single company $$;
  217. -- Begin rocking notes interface
  218. CREATE TABLE note_class(id serial primary key, class text not null check (class ~ '[[:alnum:]_]'));
  219. INSERT INTO note_class(id,class) VALUES (1,'Entity');
  220. INSERT INTO note_class(id,class) VALUES (2,'Invoice');
  221. CREATE UNIQUE INDEX note_class_idx ON note_class(lower(class));
  222. CREATE TABLE note (id serial primary key, note_class integer not null references note_class(id),
  223. note text not null, vector tsvector not null,
  224. created timestamp not null default now(),
  225. ref_key integer not null);
  226. CREATE TABLE entity_note(entity_id int references entity(id)) INHERITS (note);
  227. ALTER TABLE entity_note ADD CHECK (note_class = 1);
  228. ALTER TABLE entity_note ADD FOREIGN KEY (ref_key) REFERENCES entity(id) ON DELETE CASCADE;
  229. CREATE INDEX entity_note_id_idx ON entity_note(id);
  230. CREATE UNIQUE INDEX entity_note_class_idx ON note_class(lower(class));
  231. CREATE INDEX entity_note_vectors_idx ON entity_note USING gist(vector);
  232. CREATE TABLE invoice_note() INHERITS (note);
  233. CREATE INDEX invoice_note_id_idx ON invoice_note(id);
  234. CREATE UNIQUE INDEX invoice_note_class_idx ON note_class(lower(class));
  235. CREATE INDEX invoice_note_vectors_idx ON invoice_note USING gist(vector);
  236. -- END entity
  237. --
  238. CREATE TABLE makemodel (
  239. parts_id int PRIMARY KEY,
  240. make text,
  241. model text
  242. );
  243. --
  244. CREATE TABLE gl (
  245. id int DEFAULT nextval ( 'id' ) PRIMARY KEY REFERENCES transactions(id),
  246. reference text,
  247. description text,
  248. transdate date DEFAULT current_date,
  249. person_id integer references person(id),
  250. notes text,
  251. approved bool default true,
  252. department_id int default 0
  253. );
  254. --
  255. CREATE TABLE chart (
  256. id serial PRIMARY KEY,
  257. accno text NOT NULL,
  258. description text,
  259. charttype char(1) DEFAULT 'A',
  260. category char(1),
  261. link text,
  262. gifi_accno text,
  263. contra bool DEFAULT 'f'
  264. );
  265. --
  266. CREATE TABLE gifi (
  267. accno text PRIMARY KEY,
  268. description text
  269. );
  270. --
  271. CREATE TABLE defaults (
  272. setting_key text primary key,
  273. value text
  274. );
  275. \COPY defaults FROM stdin WITH DELIMITER |
  276. sinumber|1
  277. sonumber|1
  278. yearend|1
  279. businessnumber|1
  280. version|1.2.0
  281. closedto|\N
  282. revtrans|1
  283. ponumber|1
  284. sqnumber|1
  285. rfqnumber|1
  286. audittrail|0
  287. vinumber|1
  288. employeenumber|1
  289. partnumber|1
  290. customernumber|1
  291. vendornumber|1
  292. glnumber|1
  293. projectnumber|1
  294. queue_payments|0
  295. poll_frequency|1
  296. \.
  297. COMMENT ON TABLE defaults IS $$
  298. Note that poll_frequency is in seconds. poll_frequency and queue_payments
  299. are not exposed via the admin interface as they are advanced features best
  300. handled via DBAs. $$;
  301. -- */
  302. -- batch stuff
  303. CREATE TABLE batch_class (
  304. id serial unique,
  305. class varchar primary key
  306. );
  307. insert into batch_class (id,class) values (1,'ap');
  308. insert into batch_class (id,class) values (2,'ar');
  309. insert into batch_class (id,class) values (3,'payment');
  310. insert into batch_class (id,class) values (4,'payment_reversal');
  311. insert into batch_class (id,class) values (5,'gl');
  312. insert into batch_class (id,class) values (6,'receipt');
  313. SELECT SETVAL('batch_class_id_seq',6);
  314. CREATE TABLE batch (
  315. id serial primary key,
  316. batch_class_id integer references batch_class(id) not null,
  317. control_code text,
  318. description text,
  319. approved_on date default null,
  320. approved_by int references entity_employee(entity_id),
  321. created_by int references entity_employee(entity_id),
  322. locked_by int references session(session_id),
  323. created_on date default now()
  324. );
  325. COMMENT ON COLUMN batch.batch_class_id IS
  326. $$ Note that this field is largely used for sorting the vouchers. A given batch is NOT restricted to this type.$$;
  327. CREATE TABLE voucher (
  328. trans_id int REFERENCES transactions(id) NOT NULL,
  329. batch_id int references batch(id) not null,
  330. id serial NOT NULL unique,
  331. batch_class int references batch_class(id) not null,
  332. PRIMARY KEY (batch_class, batch_id, trans_id)
  333. );
  334. COMMENT ON COLUMN voucher.batch_class IS $$ This is the authoritative class of the
  335. voucher. $$;
  336. COMMENT ON COLUMN voucher.id IS $$ This is simply a surrogate key for easy reference.$$;
  337. CREATE TABLE acc_trans (
  338. trans_id int NOT NULL REFERENCES transactions(id),
  339. chart_id int NOT NULL REFERENCES chart (id),
  340. amount NUMERIC,
  341. transdate date DEFAULT current_date,
  342. source text,
  343. cleared bool DEFAULT 'f',
  344. fx_transaction bool DEFAULT 'f',
  345. project_id int,
  346. memo text,
  347. invoice_id int,
  348. approved bool default true,
  349. cleared_on date,
  350. reconciled_on date,
  351. voucher_id int references voucher(id),
  352. entry_id SERIAL PRIMARY KEY
  353. );
  354. CREATE INDEX acc_trans_voucher_id_idx ON acc_trans(voucher_id);
  355. --
  356. CREATE TABLE invoice (
  357. id serial PRIMARY KEY,
  358. trans_id int,
  359. parts_id int,
  360. description text,
  361. qty integer,
  362. allocated integer,
  363. sellprice NUMERIC,
  364. fxsellprice NUMERIC,
  365. discount numeric,
  366. assemblyitem bool DEFAULT 'f',
  367. unit varchar(5),
  368. project_id int,
  369. deliverydate date,
  370. serialnumber text,
  371. notes text
  372. );
  373. -- Added for Entity but can't be added due to order
  374. ALTER TABLE invoice_note ADD FOREIGN KEY (ref_key) REFERENCES invoice(id);
  375. --
  376. --
  377. -- pricegroup added here due to references
  378. CREATE TABLE pricegroup (
  379. id serial PRIMARY KEY,
  380. pricegroup text
  381. );
  382. CREATE TABLE entity_credit_account (
  383. id serial not null unique,
  384. entity_id int not null references entity(id) ON DELETE CASCADE,
  385. entity_class int not null references entity_class(id) check ( entity_class in (1,2) ),
  386. discount numeric,
  387. discount_terms int default 0,
  388. taxincluded bool default 'f',
  389. creditlimit NUMERIC default 0,
  390. terms int2 default 0,
  391. meta_number varchar(32),
  392. cc text,
  393. bcc text,
  394. business_id int,
  395. language_code varchar(6),
  396. pricegroup_id int references pricegroup(id),
  397. curr char(3),
  398. startdate date DEFAULT CURRENT_DATE,
  399. enddate date,
  400. threshold numeric default 0,
  401. employee_id int references entity_employee(entity_id),
  402. primary_contact int references person(id),
  403. ar_ap_account_id int references chart(id),
  404. cash_account_id int references chart(id),
  405. PRIMARY KEY(entity_id, meta_number, entity_class)
  406. );
  407. CREATE UNIQUE INDEX entity_credit_ar_accno_idx_u
  408. ON entity_credit_account(meta_number)
  409. WHERE entity_class = 2;
  410. COMMENT ON INDEX entity_credit_ar_accno_idx_u IS
  411. $$This index is used to ensure that AR accounts are not reused.$$;
  412. -- THe following credit accounts are used for inventory adjustments.
  413. INSERT INTO entity (name, entity_class) values ('Inventory Entity', 1);
  414. INSERT INTO company (legal_name, entity_id)
  415. values ('Inventory Entity', currval('entity_id_seq'));
  416. INSERT INTO entity_credit_account (entity_id, meta_number, entity_class)
  417. VALUES
  418. (currval('entity_id_seq'), '00000', 1),
  419. (currval('entity_id_seq'), '00000', 2);
  420. -- notes are from entity_note
  421. -- ssn, iban and bic are from entity_credit_account
  422. --
  423. -- The view below is broken. Disabling for now.
  424. CREATE VIEW employee AS
  425. SELECT s.salutation, p.first_name, p.last_name, ee.person_id, ee.entity_id, ee.startdate, ee.enddate, ee."role", ee.ssn, ee.sales, ee.manager_id, ee.employeenumber, ee.dob
  426. FROM person p
  427. JOIN entity_employee ee USING (entity_id)
  428. LEFT JOIN salutation s ON p.salutation_id = s.id;
  429. /*
  430. create view employee as
  431. SELECT
  432. ente.entity_id,
  433. 3,
  434. u.username,
  435. ente.startdate,
  436. ente.enddate,
  437. en.note,
  438. ente.ssn,
  439. eca.iban,
  440. eca.bic,
  441. ente.manager_id,
  442. ente.employeenumber,
  443. ente.dob
  444. FROM
  445. entity_employee ente
  446. JOIN
  447. entity_credit_account eca on (eca.entity_id = ente.entity_id)
  448. JOIN
  449. entity_note en on (en.entity_id = ente.entity_id)
  450. JOIN
  451. users u on (u.entity_id = ente.entity_id);
  452. */
  453. CREATE TABLE entity_bank_account (
  454. id serial not null,
  455. entity_id int not null references entity(id) ON DELETE CASCADE,
  456. bic varchar,
  457. iban varchar,
  458. UNIQUE (id),
  459. PRIMARY KEY (entity_id, bic, iban)
  460. );
  461. CREATE VIEW customer AS
  462. SELECT
  463. c.id,
  464. emd.entity_id,
  465. emd.entity_class,
  466. emd.discount,
  467. emd.taxincluded,
  468. emd.creditlimit,
  469. emd.terms,
  470. emd.meta_number as customernumber,
  471. emd.cc,
  472. emd.bcc,
  473. emd.business_id,
  474. emd.language_code,
  475. emd.pricegroup_id,
  476. emd.curr,
  477. emd.startdate,
  478. emd.enddate,
  479. eba.bic,
  480. eba.iban,
  481. ein.note as invoice_notes
  482. FROM entity_credit_account emd
  483. join entity_bank_account eba on emd.entity_id = eba.entity_id
  484. Left join entity_note ein on ein.ref_key = emd.entity_id
  485. join company c on c.entity_id = emd.entity_id
  486. where emd.entity_class = 2;
  487. CREATE VIEW vendor AS
  488. SELECT
  489. c.id,
  490. emd.entity_id,
  491. emd.entity_class,
  492. emd.discount,
  493. emd.taxincluded,
  494. emd.creditlimit,
  495. emd.terms,
  496. emd.meta_number as vendornumber,
  497. emd.cc,
  498. emd.bcc,
  499. emd.business_id,
  500. emd.language_code,
  501. emd.pricegroup_id,
  502. emd.curr,
  503. emd.startdate,
  504. emd.enddate,
  505. eba.bic,
  506. eba.iban,
  507. ein.note as
  508. invoice_notes
  509. FROM entity_credit_account emd
  510. LEFT join entity_bank_account eba on emd.entity_id = eba.entity_id
  511. left join entity_note ein on ein.ref_key = emd.entity_id
  512. join company c on c.entity_id = emd.entity_id
  513. where emd.entity_class = 1;
  514. COMMENT ON TABLE entity_credit_account IS $$ This is a metadata table for ALL entities in LSMB; it deprecates the use of customer and vendor specific tables (which were nearly identical and largely redundant), and replaces it with a single point of metadata. $$;
  515. COMMENT ON COLUMN entity_credit_account.entity_id IS $$ This is the relationship between entities and their metadata. $$;
  516. COMMENT ON COLUMN entity_credit_account.entity_class IS $$ A reference to entity_class, requiring that entity_credit_account only apply to vendors and customers, using the entity_class table as the Point Of Truth. $$;
  517. ALTER TABLE company ADD COLUMN sic_code varchar;
  518. --
  519. --
  520. -- COMMENT ON TABLE employee IS $$ Is a metadata table specific to employee $$;
  521. CREATE TABLE parts (
  522. id serial PRIMARY KEY,
  523. partnumber text,
  524. description text,
  525. unit varchar(5),
  526. listprice NUMERIC,
  527. sellprice NUMERIC,
  528. lastcost NUMERIC,
  529. priceupdate date DEFAULT current_date,
  530. weight numeric,
  531. onhand numeric DEFAULT 0,
  532. notes text,
  533. makemodel bool DEFAULT 'f',
  534. assembly bool DEFAULT 'f',
  535. alternate bool DEFAULT 'f',
  536. rop numeric, -- SC: ReOrder Point
  537. inventory_accno_id int,
  538. income_accno_id int,
  539. expense_accno_id int,
  540. bin text,
  541. obsolete bool DEFAULT 'f',
  542. bom bool DEFAULT 'f',
  543. image text,
  544. drawing text,
  545. microfiche text,
  546. partsgroup_id int,
  547. project_id int,
  548. avgcost NUMERIC
  549. );
  550. CREATE UNIQUE INDEX parts_partnumber_index_u ON parts (partnumber)
  551. WHERE obsolete is false;
  552. --
  553. CREATE TABLE assembly (
  554. id int,
  555. parts_id int,
  556. qty numeric,
  557. bom bool,
  558. adj bool,
  559. PRIMARY KEY (id, parts_id)
  560. );
  561. --
  562. CREATE TABLE ar (
  563. id int DEFAULT nextval ( 'id' ) PRIMARY KEY REFERENCES transactions(id),
  564. invnumber text,
  565. transdate date DEFAULT current_date,
  566. entity_id int REFERENCES entity(id),
  567. taxincluded bool,
  568. amount NUMERIC,
  569. netamount NUMERIC,
  570. paid NUMERIC,
  571. datepaid date,
  572. duedate date,
  573. invoice bool DEFAULT 'f',
  574. shippingpoint text,
  575. terms int2 DEFAULT 0,
  576. notes text,
  577. curr char(3),
  578. ordnumber text,
  579. person_id integer references entity_employee(entity_id),
  580. till varchar(20),
  581. quonumber text,
  582. intnotes text,
  583. department_id int default 0,
  584. shipvia text,
  585. language_code varchar(6),
  586. ponumber text,
  587. on_hold bool default false,
  588. reverse bool default false,
  589. approved bool default true,
  590. entity_credit_account int references entity_credit_account(id) not null,
  591. description text
  592. );
  593. COMMENT ON COLUMN ar.entity_id IS $$ Used to be customer_id, but customer is now metadata. You need to push to entity $$;
  594. --
  595. CREATE TABLE ap (
  596. id int DEFAULT nextval ( 'id' ) PRIMARY KEY REFERENCES transactions(id),
  597. invnumber text,
  598. transdate date DEFAULT current_date,
  599. entity_id int REFERENCES entity(id),
  600. taxincluded bool DEFAULT 'f',
  601. amount NUMERIC,
  602. netamount NUMERIC,
  603. paid NUMERIC,
  604. datepaid date,
  605. duedate date,
  606. invoice bool DEFAULT 'f',
  607. ordnumber text,
  608. curr char(3),
  609. notes text,
  610. person_id integer references entity_employee(entity_id),
  611. till varchar(20),
  612. quonumber text,
  613. intnotes text,
  614. department_id int DEFAULT 0,
  615. shipvia text,
  616. language_code varchar(6),
  617. ponumber text,
  618. shippingpoint text,
  619. on_hold bool default false,
  620. approved bool default true,
  621. reverse bool default false,
  622. terms int2 DEFAULT 0,
  623. description text,
  624. entity_credit_account int references entity_credit_account(id)
  625. );
  626. COMMENT ON COLUMN ap.entity_id IS $$ Used to be customer_id, but customer is now metadata. You need to push to entity $$;
  627. -- Payment stuff by David Mora
  628. CREATE TABLE payment (
  629. id serial primary key,
  630. reference text NOT NULL,
  631. payment_class integer NOT NULL,
  632. amount numeric NOT NULL,
  633. payment_date date default current_date,
  634. closed bool default FALSE,
  635. person_id integer references person(id),
  636. currency char(3),
  637. notes text,
  638. department_id integer default 0);
  639. COMMENT ON TABLE payment IS $$ This table will store the main data on a payment, prepayment, overpayment, etc... $$;
  640. COMMENT ON COLUMN payment.reference IS $$ This field will store the code for both receipts and payment orders, it will be differentiate by payment_class $$;
  641. COMMENT ON COLUMN payment.closed IS $$ This will store the current state of a payment/receipt order $$;
  642. CREATE INDEX payment_id_idx ON Payment(id);
  643. CREATE TABLE payment_links (
  644. payment_id integer references Payment(id),
  645. transaction_id integer NOT NULL,
  646. amount numeric);
  647. COMMENT ON TABLE payment_links IS $$ This table will link payment to ar/ap transactions $$;
  648. COMMENT ON COLUMN payment_links.transaction_id IS $$ This column lacks some data integrity controls that must be implemented in the future $$;
  649. --
  650. CREATE TABLE taxmodule (
  651. taxmodule_id serial PRIMARY KEY,
  652. taxmodulename text NOT NULL
  653. );
  654. --
  655. CREATE TABLE taxcategory (
  656. taxcategory_id serial PRIMARY KEY,
  657. taxcategoryname text NOT NULL,
  658. taxmodule_id int NOT NULL,
  659. FOREIGN KEY (taxmodule_id) REFERENCES taxmodule (taxmodule_id)
  660. );
  661. --
  662. CREATE TABLE partstax (
  663. parts_id int,
  664. chart_id int,
  665. taxcategory_id int,
  666. PRIMARY KEY (parts_id, chart_id),
  667. FOREIGN KEY (parts_id) REFERENCES parts (id) on delete cascade,
  668. FOREIGN KEY (chart_id) REFERENCES chart (id),
  669. FOREIGN KEY (taxcategory_id) REFERENCES taxcategory (taxcategory_id)
  670. );
  671. --
  672. CREATE TABLE tax (
  673. chart_id int,
  674. rate numeric,
  675. taxnumber text,
  676. validto timestamp default 'infinity',
  677. pass integer DEFAULT 0 NOT NULL,
  678. taxmodule_id int DEFAULT 1 NOT NULL,
  679. FOREIGN KEY (chart_id) REFERENCES chart (id),
  680. FOREIGN KEY (taxmodule_id) REFERENCES taxmodule (taxmodule_id),
  681. PRIMARY KEY (chart_id, validto)
  682. );
  683. --
  684. CREATE TABLE customertax (
  685. customer_id int references entity_credit_account(id) on delete cascade,
  686. chart_id int,
  687. PRIMARY KEY (customer_id, chart_id)
  688. );
  689. --
  690. CREATE TABLE vendortax (
  691. vendor_id int references entity_credit_account(id) on delete cascade,
  692. chart_id int,
  693. PRIMARY KEY (vendor_id, chart_id)
  694. );
  695. --
  696. CREATE TABLE oe_class (
  697. id smallint unique check(id IN (1,2,3,4)),
  698. oe_class text primary key);
  699. INSERT INTO oe_class(id,oe_class) values (1,'Sales Order');
  700. INSERT INTO oe_class(id,oe_class) values (2,'Purchase Order');
  701. INSERT INTO oe_class(id,oe_class) values (3,'Quotation');
  702. INSERT INTO oe_class(id,oe_class) values (4,'RFQ');
  703. COMMENT ON TABLE oe_class IS $$ This could probably be done better. But I need to remove the customer_id/vendor_id relationship and instead rely on a classification $$;
  704. CREATE TABLE oe (
  705. id serial PRIMARY KEY,
  706. ordnumber text,
  707. transdate date default current_date,
  708. entity_id integer references entity(id),
  709. amount NUMERIC,
  710. netamount NUMERIC,
  711. reqdate date,
  712. taxincluded bool,
  713. shippingpoint text,
  714. notes text,
  715. curr char(3),
  716. person_id integer references person(id),
  717. closed bool default 'f',
  718. quotation bool default 'f',
  719. quonumber text,
  720. intnotes text,
  721. department_id int default 0,
  722. shipvia text,
  723. language_code varchar(6),
  724. ponumber text,
  725. terms int2 DEFAULT 0,
  726. oe_class_id int references oe_class(id) NOT NULL
  727. );
  728. --
  729. CREATE TABLE orderitems (
  730. id serial PRIMARY KEY,
  731. trans_id int,
  732. parts_id int,
  733. description text,
  734. qty numeric,
  735. sellprice NUMERIC,
  736. discount numeric,
  737. unit varchar(5),
  738. project_id int,
  739. reqdate date,
  740. ship numeric,
  741. serialnumber text,
  742. notes text
  743. );
  744. --
  745. CREATE TABLE exchangerate (
  746. curr char(3),
  747. transdate date,
  748. buy numeric,
  749. sell numeric,
  750. PRIMARY KEY (curr, transdate)
  751. );
  752. --
  753. --
  754. create table shipto (
  755. trans_id int,
  756. shiptoname varchar(64),
  757. shiptoaddress1 varchar(32),
  758. shiptoaddress2 varchar(32),
  759. shiptocity varchar(32),
  760. shiptostate varchar(32),
  761. shiptozipcode varchar(10),
  762. shiptocountry varchar(32),
  763. shiptocontact varchar(64),
  764. shiptophone varchar(20),
  765. shiptofax varchar(20),
  766. shiptoemail text,
  767. entry_id SERIAL PRIMARY KEY
  768. );
  769. -- SHIPTO really needs to be pushed into entities too
  770. --
  771. --
  772. CREATE TABLE project (
  773. id serial PRIMARY KEY,
  774. projectnumber text,
  775. description text,
  776. startdate date,
  777. enddate date,
  778. parts_id int,
  779. production numeric default 0,
  780. completed numeric default 0,
  781. customer_id int
  782. );
  783. --
  784. CREATE TABLE partsgroup (
  785. id serial PRIMARY KEY,
  786. partsgroup text
  787. );
  788. --
  789. CREATE TABLE status (
  790. trans_id int,
  791. formname text,
  792. printed bool default 'f',
  793. emailed bool default 'f',
  794. spoolfile text,
  795. PRIMARY KEY (trans_id, formname)
  796. );
  797. --
  798. CREATE TABLE department (
  799. id serial PRIMARY KEY,
  800. description text,
  801. role char(1) default 'P'
  802. );
  803. --
  804. -- department transaction table
  805. CREATE TABLE dpt_trans (
  806. trans_id int PRIMARY KEY,
  807. department_id int
  808. );
  809. --
  810. -- business table
  811. CREATE TABLE business (
  812. id serial PRIMARY KEY,
  813. description text,
  814. discount numeric
  815. );
  816. --
  817. -- SIC
  818. CREATE TABLE sic (
  819. code varchar(6) PRIMARY KEY,
  820. sictype char(1),
  821. description text
  822. );
  823. --
  824. CREATE TABLE warehouse (
  825. id serial PRIMARY KEY,
  826. description text
  827. );
  828. --
  829. CREATE TABLE inventory (
  830. entity_id integer references entity_employee(entity_id),
  831. warehouse_id int,
  832. parts_id int,
  833. trans_id int,
  834. orderitems_id int,
  835. qty numeric,
  836. shippingdate date,
  837. entry_id SERIAL PRIMARY KEY
  838. );
  839. --
  840. CREATE TABLE yearend (
  841. trans_id int PRIMARY KEY,
  842. transdate date
  843. );
  844. --
  845. CREATE TABLE partsvendor (
  846. entity_id int not null references entity_credit_account(id) on delete cascade,
  847. parts_id int,
  848. partnumber text,
  849. leadtime int2,
  850. lastcost NUMERIC,
  851. curr char(3),
  852. entry_id SERIAL PRIMARY KEY
  853. );
  854. --
  855. CREATE TABLE partscustomer (
  856. parts_id int,
  857. customer_id int not null references entity_credit_account(id) on delete cascade,
  858. pricegroup_id int,
  859. pricebreak numeric,
  860. sellprice NUMERIC,
  861. validfrom date,
  862. validto date,
  863. curr char(3),
  864. entry_id SERIAL PRIMARY KEY
  865. );
  866. -- How does partscustomer.customer_id relate here?
  867. --
  868. CREATE TABLE language (
  869. code varchar(6) PRIMARY KEY,
  870. description text
  871. );
  872. --
  873. CREATE TABLE audittrail (
  874. trans_id int,
  875. tablename text,
  876. reference text,
  877. formname text,
  878. action text,
  879. transdate timestamp default current_timestamp,
  880. person_id integer references person(id) not null,
  881. entry_id BIGSERIAL PRIMARY KEY
  882. );
  883. --
  884. CREATE TABLE translation (
  885. trans_id int,
  886. language_code varchar(6),
  887. description text,
  888. PRIMARY KEY (trans_id, language_code)
  889. );
  890. --
  891. CREATE TABLE user_preference (
  892. id int PRIMARY KEY REFERENCES users(id),
  893. language varchar(6) REFERENCES language(code),
  894. stylesheet text default 'ledgersmb.css' not null,
  895. printer text,
  896. dateformat text default 'yyyy-mm-dd' not null,
  897. numberformat text default '1000.00' not null
  898. );
  899. -- user_preference is here due to a dependency on language.code
  900. COMMENT ON TABLE user_preference IS
  901. $$ This table sets the basic preferences for formats, languages, printers, and user-selected stylesheets.$$;
  902. CREATE TABLE recurring (
  903. id int DEFAULT nextval ( 'id' ) PRIMARY KEY,
  904. reference text,
  905. startdate date,
  906. nextdate date,
  907. enddate date,
  908. repeat int2,
  909. unit varchar(6),
  910. howmany int,
  911. payment bool default 'f'
  912. );
  913. --
  914. CREATE TABLE recurringemail (
  915. id int,
  916. formname text,
  917. format text,
  918. message text,
  919. PRIMARY KEY (id, formname)
  920. );
  921. --
  922. CREATE TABLE recurringprint (
  923. id int,
  924. formname text,
  925. format text,
  926. printer text,
  927. PRIMARY KEY (id, formname)
  928. );
  929. --
  930. CREATE TABLE jcitems (
  931. id serial PRIMARY KEY,
  932. project_id int,
  933. parts_id int,
  934. description text,
  935. qty numeric,
  936. allocated numeric,
  937. sellprice NUMERIC,
  938. fxsellprice NUMERIC,
  939. serialnumber text,
  940. checkedin timestamp with time zone,
  941. checkedout timestamp with time zone,
  942. person_id integer references person(id) not null,
  943. notes text
  944. );
  945. INSERT INTO transactions (id, table_name) SELECT id, 'ap' FROM ap;
  946. INSERT INTO transactions (id, table_name) SELECT id, 'ar' FROM ap;
  947. INSERT INTO transactions (id, table_name) SELECT id, 'gl' FROM gl;
  948. CREATE OR REPLACE FUNCTION track_global_sequence() RETURNS TRIGGER AS
  949. $$
  950. BEGIN
  951. IF tg_op = 'INSERT' THEN
  952. INSERT INTO transactions (id, table_name)
  953. VALUES (new.id, TG_RELNAME);
  954. ELSEIF tg_op = 'UPDATE' THEN
  955. IF new.id = old.id THEN
  956. return new;
  957. ELSE
  958. UPDATE transactions SET id = new.id WHERE id = old.id;
  959. END IF;
  960. ELSE
  961. DELETE FROM transactions WHERE id = old.id;
  962. END IF;
  963. RETURN new;
  964. END;
  965. $$ LANGUAGE PLPGSQL;
  966. CREATE TRIGGER ap_track_global_sequence BEFORE INSERT OR UPDATE ON ap
  967. FOR EACH ROW EXECUTE PROCEDURE track_global_sequence();
  968. CREATE TRIGGER ar_track_global_sequence BEFORE INSERT OR UPDATE ON ar
  969. FOR EACH ROW EXECUTE PROCEDURE track_global_sequence();
  970. CREATE TRIGGER gl_track_global_sequence BEFORE INSERT OR UPDATE ON gl
  971. FOR EACH ROW EXECUTE PROCEDURE track_global_sequence();
  972. CREATE TABLE custom_table_catalog (
  973. table_id SERIAL PRIMARY KEY,
  974. extends TEXT,
  975. table_name TEXT
  976. );
  977. CREATE TABLE custom_field_catalog (
  978. field_id SERIAL PRIMARY KEY,
  979. table_id INT REFERENCES custom_table_catalog,
  980. field_name TEXT
  981. );
  982. INSERT INTO taxmodule (
  983. taxmodule_id, taxmodulename
  984. ) VALUES (
  985. 1, 'Simple'
  986. );
  987. create index acc_trans_trans_id_key on acc_trans (trans_id);
  988. create index acc_trans_chart_id_key on acc_trans (chart_id);
  989. create index acc_trans_transdate_key on acc_trans (transdate);
  990. create index acc_trans_source_key on acc_trans (lower(source));
  991. --
  992. create index ap_id_key on ap (id);
  993. create index ap_transdate_key on ap (transdate);
  994. create index ap_invnumber_key on ap (invnumber);
  995. create index ap_ordnumber_key on ap (ordnumber);
  996. create index ap_quonumber_key on ap (quonumber);
  997. --
  998. create index ar_id_key on ar (id);
  999. create index ar_transdate_key on ar (transdate);
  1000. create index ar_invnumber_key on ar (invnumber);
  1001. create index ar_ordnumber_key on ar (ordnumber);
  1002. create index ar_quonumber_key on ar (quonumber);
  1003. --
  1004. create index assembly_id_key on assembly (id);
  1005. --
  1006. create index chart_id_key on chart (id);
  1007. create unique index chart_accno_key on chart (accno);
  1008. create index chart_category_key on chart (category);
  1009. create index chart_link_key on chart (link);
  1010. create index chart_gifi_accno_key on chart (gifi_accno);
  1011. --
  1012. create index customer_customer_id_key on customertax (customer_id);
  1013. --
  1014. create index exchangerate_ct_key on exchangerate (curr, transdate);
  1015. --
  1016. create unique index gifi_accno_key on gifi (accno);
  1017. --
  1018. create index gl_id_key on gl (id);
  1019. create index gl_transdate_key on gl (transdate);
  1020. create index gl_reference_key on gl (reference);
  1021. create index gl_description_key on gl (lower(description));
  1022. --
  1023. create index invoice_id_key on invoice (id);
  1024. create index invoice_trans_id_key on invoice (trans_id);
  1025. --
  1026. create index makemodel_parts_id_key on makemodel (parts_id);
  1027. create index makemodel_make_key on makemodel (lower(make));
  1028. create index makemodel_model_key on makemodel (lower(model));
  1029. --
  1030. create index oe_id_key on oe (id);
  1031. create index oe_transdate_key on oe (transdate);
  1032. create index oe_ordnumber_key on oe (ordnumber);
  1033. create index orderitems_trans_id_key on orderitems (trans_id);
  1034. create index orderitems_id_key on orderitems (id);
  1035. --
  1036. create index parts_id_key on parts (id);
  1037. create index parts_partnumber_key on parts (lower(partnumber));
  1038. create index parts_description_key on parts (lower(description));
  1039. create index partstax_parts_id_key on partstax (parts_id);
  1040. --
  1041. --
  1042. create index shipto_trans_id_key on shipto (trans_id);
  1043. --
  1044. create index project_id_key on project (id);
  1045. create unique index projectnumber_key on project (projectnumber);
  1046. --
  1047. create index partsgroup_id_key on partsgroup (id);
  1048. create unique index partsgroup_key on partsgroup (partsgroup);
  1049. --
  1050. create index status_trans_id_key on status (trans_id);
  1051. --
  1052. create index department_id_key on department (id);
  1053. --
  1054. create index partsvendor_parts_id_key on partsvendor (parts_id);
  1055. --
  1056. create index pricegroup_pricegroup_key on pricegroup (pricegroup);
  1057. create index pricegroup_id_key on pricegroup (id);
  1058. --
  1059. create index audittrail_trans_id_key on audittrail (trans_id);
  1060. --
  1061. create index translation_trans_id_key on translation (trans_id);
  1062. --
  1063. create unique index language_code_key on language (code);
  1064. --
  1065. create index jcitems_id_key on jcitems (id);
  1066. -- Popular some entity data
  1067. INSERT INTO country(short_name,name) VALUES ('AC','Ascension Island');
  1068. INSERT INTO country(short_name,name) VALUES ('AD','Andorra');
  1069. INSERT INTO country(short_name,name) VALUES ('AE','United Arab Emirates');
  1070. INSERT INTO country(short_name,name) VALUES ('AF','Afghanistan');
  1071. INSERT INTO country(short_name,name) VALUES ('AG','Antigua and Barbuda');
  1072. INSERT INTO country(short_name,name) VALUES ('AI','Anguilla');
  1073. INSERT INTO country(short_name,name) VALUES ('AL','Albania');
  1074. INSERT INTO country(short_name,name) VALUES ('AM','Armenia');
  1075. INSERT INTO country(short_name,name) VALUES ('AN','Netherlands Antilles');
  1076. INSERT INTO country(short_name,name) VALUES ('AO','Angola');
  1077. INSERT INTO country(short_name,name) VALUES ('AQ','Antarctica');
  1078. INSERT INTO country(short_name,name) VALUES ('AR','Argentina');
  1079. INSERT INTO country(short_name,name) VALUES ('AS','American Samoa');
  1080. INSERT INTO country(short_name,name) VALUES ('AT','Austria');
  1081. INSERT INTO country(short_name,name) VALUES ('AU','Australia');
  1082. INSERT INTO country(short_name,name) VALUES ('AW','Aruba');
  1083. INSERT INTO country(short_name,name) VALUES ('AX','Aland Islands');
  1084. INSERT INTO country(short_name,name) VALUES ('AZ','Azerbaijan');
  1085. INSERT INTO country(short_name,name) VALUES ('BA','Bosnia and Herzegovina');
  1086. INSERT INTO country(short_name,name) VALUES ('BB','Barbados');
  1087. INSERT INTO country(short_name,name) VALUES ('BD','Bangladesh');
  1088. INSERT INTO country(short_name,name) VALUES ('BE','Belgium');
  1089. INSERT INTO country(short_name,name) VALUES ('BF','Burkina Faso');
  1090. INSERT INTO country(short_name,name) VALUES ('BG','Bulgaria');
  1091. INSERT INTO country(short_name,name) VALUES ('BH','Bahrain');
  1092. INSERT INTO country(short_name,name) VALUES ('BI','Burundi');
  1093. INSERT INTO country(short_name,name) VALUES ('BJ','Benin');
  1094. INSERT INTO country(short_name,name) VALUES ('BM','Bermuda');
  1095. INSERT INTO country(short_name,name) VALUES ('BN','Brunei Darussalam');
  1096. INSERT INTO country(short_name,name) VALUES ('BO','Bolivia');
  1097. INSERT INTO country(short_name,name) VALUES ('BR','Brazil');
  1098. INSERT INTO country(short_name,name) VALUES ('BS','Bahamas');
  1099. INSERT INTO country(short_name,name) VALUES ('BT','Bhutan');
  1100. INSERT INTO country(short_name,name) VALUES ('BV','Bouvet Island');
  1101. INSERT INTO country(short_name,name) VALUES ('BW','Botswana');
  1102. INSERT INTO country(short_name,name) VALUES ('BY','Belarus');
  1103. INSERT INTO country(short_name,name) VALUES ('BZ','Belize');
  1104. INSERT INTO country(short_name,name) VALUES ('CA','Canada');
  1105. INSERT INTO country(short_name,name) VALUES ('CC','Cocos (Keeling) Islands');
  1106. INSERT INTO country(short_name,name) VALUES ('CD','Congo, Democratic Republic');
  1107. INSERT INTO country(short_name,name) VALUES ('CF','Central African Republic');
  1108. INSERT INTO country(short_name,name) VALUES ('CG','Congo');
  1109. INSERT INTO country(short_name,name) VALUES ('CH','Switzerland');
  1110. INSERT INTO country(short_name,name) VALUES ('CI','Cote D\'Ivoire (Ivory Coast)');
  1111. INSERT INTO country(short_name,name) VALUES ('CK','Cook Islands');
  1112. INSERT INTO country(short_name,name) VALUES ('CL','Chile');
  1113. INSERT INTO country(short_name,name) VALUES ('CM','Cameroon');
  1114. INSERT INTO country(short_name,name) VALUES ('CN','China');
  1115. INSERT INTO country(short_name,name) VALUES ('CO','Colombia');
  1116. INSERT INTO country(short_name,name) VALUES ('CR','Costa Rica');
  1117. INSERT INTO country(short_name,name) VALUES ('CS','Czechoslovakia (former)');
  1118. INSERT INTO country(short_name,name) VALUES ('CU','Cuba');
  1119. INSERT INTO country(short_name,name) VALUES ('CV','Cape Verde');
  1120. INSERT INTO country(short_name,name) VALUES ('CX','Christmas Island');
  1121. INSERT INTO country(short_name,name) VALUES ('CY','Cyprus');
  1122. INSERT INTO country(short_name,name) VALUES ('CZ','Czech Republic');
  1123. INSERT INTO country(short_name,name) VALUES ('DE','Germany');
  1124. INSERT INTO country(short_name,name) VALUES ('DJ','Djibouti');
  1125. INSERT INTO country(short_name,name) VALUES ('DK','Denmark');
  1126. INSERT INTO country(short_name,name) VALUES ('DM','Dominica');
  1127. INSERT INTO country(short_name,name) VALUES ('DO','Dominican Republic');
  1128. INSERT INTO country(short_name,name) VALUES ('DZ','Algeria');
  1129. INSERT INTO country(short_name,name) VALUES ('EC','Ecuador');
  1130. INSERT INTO country(short_name,name) VALUES ('EE','Estonia');
  1131. INSERT INTO country(short_name,name) VALUES ('EG','Egypt');
  1132. INSERT INTO country(short_name,name) VALUES ('EH','Western Sahara');
  1133. INSERT INTO country(short_name,name) VALUES ('ER','Eritrea');
  1134. INSERT INTO country(short_name,name) VALUES ('ES','Spain');
  1135. INSERT INTO country(short_name,name) VALUES ('ET','Ethiopia');
  1136. INSERT INTO country(short_name,name) VALUES ('FI','Finland');
  1137. INSERT INTO country(short_name,name) VALUES ('FJ','Fiji');
  1138. INSERT INTO country(short_name,name) VALUES ('FK','Falkland Islands (Malvinas)');
  1139. INSERT INTO country(short_name,name) VALUES ('FM','Micronesia');
  1140. INSERT INTO country(short_name,name) VALUES ('FO','Faroe Islands');
  1141. INSERT INTO country(short_name,name) VALUES ('FR','France');
  1142. INSERT INTO country(short_name,name) VALUES ('FX','France, Metropolitan');
  1143. INSERT INTO country(short_name,name) VALUES ('GA','Gabon');
  1144. INSERT INTO country(short_name,name) VALUES ('GB','Great Britain (UK)');
  1145. INSERT INTO country(short_name,name) VALUES ('GD','Grenada');
  1146. INSERT INTO country(short_name,name) VALUES ('GE','Georgia');
  1147. INSERT INTO country(short_name,name) VALUES ('GF','French Guiana');
  1148. INSERT INTO country(short_name,name) VALUES ('GH','Ghana');
  1149. INSERT INTO country(short_name,name) VALUES ('GI','Gibraltar');
  1150. INSERT INTO country(short_name,name) VALUES ('GL','Greenland');
  1151. INSERT INTO country(short_name,name) VALUES ('GM','Gambia');
  1152. INSERT INTO country(short_name,name) VALUES ('GN','Guinea');
  1153. INSERT INTO country(short_name,name) VALUES ('GP','Guadeloupe');
  1154. INSERT INTO country(short_name,name) VALUES ('GQ','Equatorial Guinea');
  1155. INSERT INTO country(short_name,name) VALUES ('GR','Greece');
  1156. INSERT INTO country(short_name,name) VALUES ('GS','S. Georgia and S. Sandwich Isls.');
  1157. INSERT INTO country(short_name,name) VALUES ('GT','Guatemala');
  1158. INSERT INTO country(short_name,name) VALUES ('GU','Guam');
  1159. INSERT INTO country(short_name,name) VALUES ('GW','Guinea-Bissau');
  1160. INSERT INTO country(short_name,name) VALUES ('GY','Guyana');
  1161. INSERT INTO country(short_name,name) VALUES ('HK','Hong Kong');
  1162. INSERT INTO country(short_name,name) VALUES ('HM','Heard and McDonald Islands');
  1163. INSERT INTO country(short_name,name) VALUES ('HN','Honduras');
  1164. INSERT INTO country(short_name,name) VALUES ('HR','Croatia (Hrvatska)');
  1165. INSERT INTO country(short_name,name) VALUES ('HT','Haiti');
  1166. INSERT INTO country(short_name,name) VALUES ('HU','Hungary');
  1167. INSERT INTO country(short_name,name) VALUES ('ID','Indonesia');
  1168. INSERT INTO country(short_name,name) VALUES ('IE','Ireland');
  1169. INSERT INTO country(short_name,name) VALUES ('IL','Israel');
  1170. INSERT INTO country(short_name,name) VALUES ('IM','Isle of Man');
  1171. INSERT INTO country(short_name,name) VALUES ('IN','India');
  1172. INSERT INTO country(short_name,name) VALUES ('IO','British Indian Ocean Territory');
  1173. INSERT INTO country(short_name,name) VALUES ('IQ','Iraq');
  1174. INSERT INTO country(short_name,name) VALUES ('IR','Iran');
  1175. INSERT INTO country(short_name,name) VALUES ('IS','Iceland');
  1176. INSERT INTO country(short_name,name) VALUES ('IT','Italy');
  1177. INSERT INTO country(short_name,name) VALUES ('JE','Jersey');
  1178. INSERT INTO country(short_name,name) VALUES ('JM','Jamaica');
  1179. INSERT INTO country(short_name,name) VALUES ('JO','Jordan');
  1180. INSERT INTO country(short_name,name) VALUES ('JP','Japan');
  1181. INSERT INTO country(short_name,name) VALUES ('KE','Kenya');
  1182. INSERT INTO country(short_name,name) VALUES ('KG','Kyrgyzstan');
  1183. INSERT INTO country(short_name,name) VALUES ('KH','Cambodia');
  1184. INSERT INTO country(short_name,name) VALUES ('KI','Kiribati');
  1185. INSERT INTO country(short_name,name) VALUES ('KM','Comoros');
  1186. INSERT INTO country(short_name,name) VALUES ('KN','Saint Kitts and Nevis');
  1187. INSERT INTO country(short_name,name) VALUES ('KP','Korea (North)');
  1188. INSERT INTO country(short_name,name) VALUES ('KR','Korea (South)');
  1189. INSERT INTO country(short_name,name) VALUES ('KW','Kuwait');
  1190. INSERT INTO country(short_name,name) VALUES ('KY','Cayman Islands');
  1191. INSERT INTO country(short_name,name) VALUES ('KZ','Kazakhstan');
  1192. INSERT INTO country(short_name,name) VALUES ('LA','Laos');
  1193. INSERT INTO country(short_name,name) VALUES ('LB','Lebanon');
  1194. INSERT INTO country(short_name,name) VALUES ('LC','Saint Lucia');
  1195. INSERT INTO country(short_name,name) VALUES ('LI','Liechtenstein');
  1196. INSERT INTO country(short_name,name) VALUES ('LK','Sri Lanka');
  1197. INSERT INTO country(short_name,name) VALUES ('LR','Liberia');
  1198. INSERT INTO country(short_name,name) VALUES ('LS','Lesotho');
  1199. INSERT INTO country(short_name,name) VALUES ('LT','Lithuania');
  1200. INSERT INTO country(short_name,name) VALUES ('LU','Luxembourg');
  1201. INSERT INTO country(short_name,name) VALUES ('LV','Latvia');
  1202. INSERT INTO country(short_name,name) VALUES ('LY','Libya');
  1203. INSERT INTO country(short_name,name) VALUES ('MA','Morocco');
  1204. INSERT INTO country(short_name,name) VALUES ('MC','Monaco');
  1205. INSERT INTO country(short_name,name) VALUES ('MD','Moldova');
  1206. INSERT INTO country(short_name,name) VALUES ('MG','Madagascar');
  1207. INSERT INTO country(short_name,name) VALUES ('MH','Marshall Islands');
  1208. INSERT INTO country(short_name,name) VALUES ('MK','F.Y.R.O.M. (Macedonia)');
  1209. INSERT INTO country(short_name,name) VALUES ('ML','Mali');
  1210. INSERT INTO country(short_name,name) VALUES ('MM','Myanmar');
  1211. INSERT INTO country(short_name,name) VALUES ('MN','Mongolia');
  1212. INSERT INTO country(short_name,name) VALUES ('MO','Macau');
  1213. INSERT INTO country(short_name,name) VALUES ('MP','Northern Mariana Islands');
  1214. INSERT INTO country(short_name,name) VALUES ('MQ','Martinique');
  1215. INSERT INTO country(short_name,name) VALUES ('MR','Mauritania');
  1216. INSERT INTO country(short_name,name) VALUES ('MS','Montserrat');
  1217. INSERT INTO country(short_name,name) VALUES ('MT','Malta');
  1218. INSERT INTO country(short_name,name) VALUES ('MU','Mauritius');
  1219. INSERT INTO country(short_name,name) VALUES ('MV','Maldives');
  1220. INSERT INTO country(short_name,name) VALUES ('MW','Malawi');
  1221. INSERT INTO country(short_name,name) VALUES ('MX','Mexico');
  1222. INSERT INTO country(short_name,name) VALUES ('MY','Malaysia');
  1223. INSERT INTO country(short_name,name) VALUES ('MZ','Mozambique');
  1224. INSERT INTO country(short_name,name) VALUES ('NA','Namibia');
  1225. INSERT INTO country(short_name,name) VALUES ('NC','New Caledonia');
  1226. INSERT INTO country(short_name,name) VALUES ('NE','Niger');
  1227. INSERT INTO country(short_name,name) VALUES ('NF','Norfolk Island');
  1228. INSERT INTO country(short_name,name) VALUES ('NG','Nigeria');
  1229. INSERT INTO country(short_name,name) VALUES ('NI','Nicaragua');
  1230. INSERT INTO country(short_name,name) VALUES ('NL','Netherlands');
  1231. INSERT INTO country(short_name,name) VALUES ('NO','Norway');
  1232. INSERT INTO country(short_name,name) VALUES ('NP','Nepal');
  1233. INSERT INTO country(short_name,name) VALUES ('NR','Nauru');
  1234. INSERT INTO country(short_name,name) VALUES ('NT','Neutral Zone');
  1235. INSERT INTO country(short_name,name) VALUES ('NU','Niue');
  1236. INSERT INTO country(short_name,name) VALUES ('NZ','New Zealand (Aotearoa)');
  1237. INSERT INTO country(short_name,name) VALUES ('OM','Oman');
  1238. INSERT INTO country(short_name,name) VALUES ('PA','Panama');
  1239. INSERT INTO country(short_name,name) VALUES ('PE','Peru');
  1240. INSERT INTO country(short_name,name) VALUES ('PF','French Polynesia');
  1241. INSERT INTO country(short_name,name) VALUES ('PG','Papua New Guinea');
  1242. INSERT INTO country(short_name,name) VALUES ('PH','Philippines');
  1243. INSERT INTO country(short_name,name) VALUES ('PK','Pakistan');
  1244. INSERT INTO country(short_name,name) VALUES ('PL','Poland');
  1245. INSERT INTO country(short_name,name) VALUES ('PM','St. Pierre and Miquelon');
  1246. INSERT INTO country(short_name,name) VALUES ('PN','Pitcairn');
  1247. INSERT INTO country(short_name,name) VALUES ('PR','Puerto Rico');
  1248. INSERT INTO country(short_name,name) VALUES ('PS','Palestinian Territory, Occupied');
  1249. INSERT INTO country(short_name,name) VALUES ('PT','Portugal');
  1250. INSERT INTO country(short_name,name) VALUES ('PW','Palau');
  1251. INSERT INTO country(short_name,name) VALUES ('PY','Paraguay');
  1252. INSERT INTO country(short_name,name) VALUES ('QA','Qatar');
  1253. INSERT INTO country(short_name,name) VALUES ('RE','Reunion');
  1254. INSERT INTO country(short_name,name) VALUES ('RO','Romania');
  1255. INSERT INTO country(short_name,name) VALUES ('RS','Serbia');
  1256. INSERT INTO country(short_name,name) VALUES ('RU','Russian Federation');
  1257. INSERT INTO country(short_name,name) VALUES ('RW','Rwanda');
  1258. INSERT INTO country(short_name,name) VALUES ('SA','Saudi Arabia');
  1259. INSERT INTO country(short_name,name) VALUES ('SB','Solomon Islands');
  1260. INSERT INTO country(short_name,name) VALUES ('SC','Seychelles');
  1261. INSERT INTO country(short_name,name) VALUES ('SD','Sudan');
  1262. INSERT INTO country(short_name,name) VALUES ('SE','Sweden');
  1263. INSERT INTO country(short_name,name) VALUES ('SG','Singapore');
  1264. INSERT INTO country(short_name,name) VALUES ('SH','St. Helena');
  1265. INSERT INTO country(short_name,name) VALUES ('SI','Slovenia');
  1266. INSERT INTO country(short_name,name) VALUES ('SJ','Svalbard & Jan Mayen Islands');
  1267. INSERT INTO country(short_name,name) VALUES ('SK','Slovak Republic');
  1268. INSERT INTO country(short_name,name) VALUES ('SL','Sierra Leone');
  1269. INSERT INTO country(short_name,name) VALUES ('SM','San Marino');
  1270. INSERT INTO country(short_name,name) VALUES ('SN','Senegal');
  1271. INSERT INTO country(short_name,name) VALUES ('SO','Somalia');
  1272. INSERT INTO country(short_name,name) VALUES ('SR','Suriname');
  1273. INSERT INTO country(short_name,name) VALUES ('ST','Sao Tome and Principe');
  1274. INSERT INTO country(short_name,name) VALUES ('SU','USSR (former)');
  1275. INSERT INTO country(short_name,name) VALUES ('SV','El Salvador');
  1276. INSERT INTO country(short_name,name) VALUES ('SY','Syria');
  1277. INSERT INTO country(short_name,name) VALUES ('SZ','Swaziland');
  1278. INSERT INTO country(short_name,name) VALUES ('TC','Turks and Caicos Islands');
  1279. INSERT INTO country(short_name,name) VALUES ('TD','Chad');
  1280. INSERT INTO country(short_name,name) VALUES ('TF','French Southern Territories');
  1281. INSERT INTO country(short_name,name) VALUES ('TG','Togo');
  1282. INSERT INTO country(short_name,name) VALUES ('TH','Thailand');
  1283. INSERT INTO country(short_name,name) VALUES ('TJ','Tajikistan');
  1284. INSERT INTO country(short_name,name) VALUES ('TK','Tokelau');
  1285. INSERT INTO country(short_name,name) VALUES ('TM','Turkmenistan');
  1286. INSERT INTO country(short_name,name) VALUES ('TN','Tunisia');
  1287. INSERT INTO country(short_name,name) VALUES ('TO','Tonga');
  1288. INSERT INTO country(short_name,name) VALUES ('TP','East Timor');
  1289. INSERT INTO country(short_name,name) VALUES ('TR','Turkey');
  1290. INSERT INTO country(short_name,name) VALUES ('TT','Trinidad and Tobago');
  1291. INSERT INTO country(short_name,name) VALUES ('TV','Tuvalu');
  1292. INSERT INTO country(short_name,name) VALUES ('TW','Taiwan');
  1293. INSERT INTO country(short_name,name) VALUES ('TZ','Tanzania');
  1294. INSERT INTO country(short_name,name) VALUES ('UA','Ukraine');
  1295. INSERT INTO country(short_name,name) VALUES ('UG','Uganda');
  1296. INSERT INTO country(short_name,name) VALUES ('UK','United Kingdom');
  1297. INSERT INTO country(short_name,name) VALUES ('UM','US Minor Outlying Islands');
  1298. INSERT INTO country(short_name,name) VALUES ('US','United States');
  1299. INSERT INTO country(short_name,name) VALUES ('UY','Uruguay');
  1300. INSERT INTO country(short_name,name) VALUES ('UZ','Uzbekistan');
  1301. INSERT INTO country(short_name,name) VALUES ('VA','Vatican City State (Holy See)');
  1302. INSERT INTO country(short_name,name) VALUES ('VC','Saint Vincent & the Grenadines');
  1303. INSERT INTO country(short_name,name) VALUES ('VE','Venezuela');
  1304. INSERT INTO country(short_name,name) VALUES ('VG','British Virgin Islands');
  1305. INSERT INTO country(short_name,name) VALUES ('VI','Virgin Islands (U.S.)');
  1306. INSERT INTO country(short_name,name) VALUES ('VN','Viet Nam');
  1307. INSERT INTO country(short_name,name) VALUES ('VU','Vanuatu');
  1308. INSERT INTO country(short_name,name) VALUES ('WF','Wallis and Futuna Islands');
  1309. INSERT INTO country(short_name,name) VALUES ('WS','Samoa');
  1310. INSERT INTO country(short_name,name) VALUES ('YE','Yemen');
  1311. INSERT INTO country(short_name,name) VALUES ('YT','Mayotte');
  1312. INSERT INTO country(short_name,name) VALUES ('YU','Yugoslavia (former)');
  1313. INSERT INTO country(short_name,name) VALUES ('ZA','South Africa');
  1314. INSERT INTO country(short_name,name) VALUES ('ZM','Zambia');
  1315. INSERT INTO country(short_name,name) VALUES ('ZR','Zaire');
  1316. INSERT INTO country(short_name,name) VALUES ('ZW','Zimbabwe');
  1317. --
  1318. CREATE FUNCTION del_yearend() RETURNS TRIGGER AS '
  1319. begin
  1320. delete from yearend where trans_id = old.id;
  1321. return NULL;
  1322. end;
  1323. ' language 'plpgsql';
  1324. -- end function
  1325. --
  1326. CREATE TRIGGER del_yearend AFTER DELETE ON gl FOR EACH ROW EXECUTE PROCEDURE del_yearend();
  1327. -- end trigger
  1328. --
  1329. CREATE FUNCTION del_department() RETURNS TRIGGER AS '
  1330. begin
  1331. delete from dpt_trans where trans_id = old.id;
  1332. return NULL;
  1333. end;
  1334. ' language 'plpgsql';
  1335. -- end function
  1336. --
  1337. CREATE TRIGGER del_department AFTER DELETE ON ar FOR EACH ROW EXECUTE PROCEDURE del_department();
  1338. -- end trigger
  1339. CREATE TRIGGER del_department AFTER DELETE ON ap FOR EACH ROW EXECUTE PROCEDURE del_department();
  1340. -- end trigger
  1341. CREATE TRIGGER del_department AFTER DELETE ON gl FOR EACH ROW EXECUTE PROCEDURE del_department();
  1342. -- end trigger
  1343. CREATE TRIGGER del_department AFTER DELETE ON oe FOR EACH ROW EXECUTE PROCEDURE del_department();
  1344. -- end trigger
  1345. --
  1346. CREATE FUNCTION del_exchangerate() RETURNS TRIGGER AS '
  1347. declare
  1348. t_transdate date;
  1349. t_curr char(3);
  1350. t_id int;
  1351. d_curr text;
  1352. begin
  1353. select into d_curr substr(value,1,3) from defaults where setting_key = ''curr'';
  1354. if TG_RELNAME = ''ar'' then
  1355. select into t_curr, t_transdate curr, transdate from ar where id = old.id;
  1356. end if;
  1357. if TG_RELNAME = ''ap'' then
  1358. select into t_curr, t_transdate curr, transdate from ap where id = old.id;
  1359. end if;
  1360. if TG_RELNAME = ''oe'' then
  1361. select into t_curr, t_transdate curr, transdate from oe where id = old.id;
  1362. end if;
  1363. if d_curr != t_curr then
  1364. select into t_id a.id from acc_trans ac
  1365. join ar a on (a.id = ac.trans_id)
  1366. where a.curr = t_curr
  1367. and ac.transdate = t_transdate
  1368. except select a.id from ar a where a.id = old.id
  1369. union
  1370. select a.id from acc_trans ac
  1371. join ap a on (a.id = ac.trans_id)
  1372. where a.curr = t_curr
  1373. and ac.transdate = t_transdate
  1374. except select a.id from ap a where a.id = old.id
  1375. union
  1376. select o.id from oe o
  1377. where o.curr = t_curr
  1378. and o.transdate = t_transdate
  1379. except select o.id from oe o where o.id = old.id;
  1380. if not found then
  1381. delete from exchangerate where curr = t_curr and transdate = t_transdate;
  1382. end if;
  1383. end if;
  1384. return old;
  1385. end;
  1386. ' language 'plpgsql';
  1387. -- end function
  1388. --
  1389. CREATE TRIGGER del_exchangerate BEFORE DELETE ON ar FOR EACH ROW EXECUTE PROCEDURE del_exchangerate();
  1390. -- end trigger
  1391. --
  1392. CREATE TRIGGER del_exchangerate BEFORE DELETE ON ap FOR EACH ROW EXECUTE PROCEDURE del_exchangerate();
  1393. -- end trigger
  1394. --
  1395. CREATE TRIGGER del_exchangerate BEFORE DELETE ON oe FOR EACH ROW EXECUTE PROCEDURE del_exchangerate();
  1396. -- end trigger
  1397. --
  1398. CREATE FUNCTION check_department() RETURNS TRIGGER AS '
  1399. declare
  1400. dpt_id int;
  1401. begin
  1402. if new.department_id = 0 then
  1403. delete from dpt_trans where trans_id = new.id;
  1404. return NULL;
  1405. end if;
  1406. select into dpt_id trans_id from dpt_trans where trans_id = new.id;
  1407. if dpt_id > 0 then
  1408. update dpt_trans set department_id = new.department_id where trans_id = dpt_id;
  1409. else
  1410. insert into dpt_trans (trans_id, department_id) values (new.id, new.department_id);
  1411. end if;
  1412. return NULL;
  1413. end;
  1414. ' language 'plpgsql';
  1415. -- end function
  1416. --
  1417. CREATE TRIGGER check_department AFTER INSERT OR UPDATE ON ar FOR EACH ROW EXECUTE PROCEDURE check_department();
  1418. -- end trigger
  1419. CREATE TRIGGER check_department AFTER INSERT OR UPDATE ON ap FOR EACH ROW EXECUTE PROCEDURE check_department();
  1420. -- end trigger
  1421. CREATE TRIGGER check_department AFTER INSERT OR UPDATE ON gl FOR EACH ROW EXECUTE PROCEDURE check_department();
  1422. -- end trigger
  1423. CREATE TRIGGER check_department AFTER INSERT OR UPDATE ON oe FOR EACH ROW EXECUTE PROCEDURE check_department();
  1424. -- end trigger
  1425. --
  1426. CREATE FUNCTION del_recurring() RETURNS TRIGGER AS '
  1427. BEGIN
  1428. DELETE FROM recurring WHERE id = old.id;
  1429. DELETE FROM recurringemail WHERE id = old.id;
  1430. DELETE FROM recurringprint WHERE id = old.id;
  1431. RETURN NULL;
  1432. END;
  1433. ' language 'plpgsql';
  1434. --end function
  1435. CREATE TRIGGER del_recurring AFTER DELETE ON ar FOR EACH ROW EXECUTE PROCEDURE del_recurring();
  1436. -- end trigger
  1437. CREATE TRIGGER del_recurring AFTER DELETE ON ap FOR EACH ROW EXECUTE PROCEDURE del_recurring();
  1438. -- end trigger
  1439. CREATE TRIGGER del_recurring AFTER DELETE ON gl FOR EACH ROW EXECUTE PROCEDURE del_recurring();
  1440. -- end trigger
  1441. --
  1442. CREATE FUNCTION avgcost(int) RETURNS FLOAT AS '
  1443. DECLARE
  1444. v_cost float;
  1445. v_qty float;
  1446. v_parts_id alias for $1;
  1447. BEGIN
  1448. SELECT INTO v_cost, v_qty SUM(i.sellprice * i.qty), SUM(i.qty)
  1449. FROM invoice i
  1450. JOIN ap a ON (a.id = i.trans_id)
  1451. WHERE i.parts_id = v_parts_id;
  1452. IF v_cost IS NULL THEN
  1453. v_cost := 0;
  1454. END IF;
  1455. IF NOT v_qty IS NULL THEN
  1456. IF v_qty = 0 THEN
  1457. v_cost := 0;
  1458. ELSE
  1459. v_cost := v_cost/v_qty;
  1460. END IF;
  1461. END IF;
  1462. RETURN v_cost;
  1463. END;
  1464. ' language 'plpgsql';
  1465. -- end function
  1466. --
  1467. CREATE FUNCTION lastcost(int) RETURNS FLOAT AS '
  1468. DECLARE
  1469. v_cost float;
  1470. v_parts_id alias for $1;
  1471. BEGIN
  1472. SELECT INTO v_cost sellprice FROM invoice i
  1473. JOIN ap a ON (a.id = i.trans_id)
  1474. WHERE i.parts_id = v_parts_id
  1475. ORDER BY a.transdate desc, a.id desc
  1476. LIMIT 1;
  1477. IF v_cost IS NULL THEN
  1478. v_cost := 0;
  1479. END IF;
  1480. RETURN v_cost;
  1481. END;
  1482. ' language plpgsql;
  1483. -- end function
  1484. --
  1485. CREATE OR REPLACE FUNCTION trigger_parts_short() RETURNS TRIGGER
  1486. AS
  1487. '
  1488. BEGIN
  1489. IF NEW.onhand >= NEW.rop THEN
  1490. NOTIFY parts_short;
  1491. END IF;
  1492. RETURN NEW;
  1493. END;
  1494. ' LANGUAGE PLPGSQL;
  1495. -- end function
  1496. CREATE TRIGGER parts_short AFTER UPDATE ON parts
  1497. FOR EACH ROW EXECUTE PROCEDURE trigger_parts_short();
  1498. -- end function
  1499. CREATE OR REPLACE FUNCTION add_custom_field (VARCHAR, VARCHAR, VARCHAR)
  1500. RETURNS BOOL AS
  1501. '
  1502. DECLARE
  1503. table_name ALIAS FOR $1;
  1504. new_field_name ALIAS FOR $2;
  1505. field_datatype ALIAS FOR $3;
  1506. BEGIN
  1507. EXECUTE ''SELECT TABLE_ID FROM custom_table_catalog
  1508. WHERE extends = '''''' || table_name || '''''' '';
  1509. IF NOT FOUND THEN
  1510. BEGIN
  1511. INSERT INTO custom_table_catalog (extends)
  1512. VALUES (table_name);
  1513. EXECUTE ''CREATE TABLE custom_''||table_name ||
  1514. '' (row_id INT PRIMARY KEY)'';
  1515. EXCEPTION WHEN duplicate_table THEN
  1516. -- do nothing
  1517. END;
  1518. END IF;
  1519. EXECUTE ''INSERT INTO custom_field_catalog (field_name, table_id)
  1520. VALUES ( '''''' || new_field_name ||'''''', (SELECT table_id FROM custom_table_catalog
  1521. WHERE extends = ''''''|| table_name || ''''''))'';
  1522. EXECUTE ''ALTER TABLE custom_''||table_name || '' ADD COLUMN ''
  1523. || new_field_name || '' '' || field_datatype;
  1524. RETURN TRUE;
  1525. END;
  1526. ' LANGUAGE PLPGSQL;
  1527. -- end function
  1528. CREATE OR REPLACE FUNCTION drop_custom_field (VARCHAR, VARCHAR)
  1529. RETURNS BOOL AS
  1530. '
  1531. DECLARE
  1532. table_name ALIAS FOR $1;
  1533. custom_field_name ALIAS FOR $2;
  1534. BEGIN
  1535. DELETE FROM custom_field_catalog
  1536. WHERE field_name = custom_field_name AND
  1537. table_id = (SELECT table_id FROM custom_table_catalog
  1538. WHERE extends = table_name);
  1539. EXECUTE ''ALTER TABLE custom_'' || table_name ||
  1540. '' DROP COLUMN '' || custom_field_name;
  1541. RETURN TRUE;
  1542. END;
  1543. ' LANGUAGE PLPGSQL;
  1544. -- end function
  1545. CREATE TABLE menu_node (
  1546. id serial NOT NULL,
  1547. label character varying NOT NULL,
  1548. parent integer,
  1549. "position" integer NOT NULL
  1550. );
  1551. --ALTER TABLE public.menu_node OWNER TO ledgersmb;
  1552. --
  1553. -- Name: menu_node_id_seq; Type: SEQUENCE SET; Schema: public; Owner: ledgersmb
  1554. --
  1555. SELECT pg_catalog.setval('menu_node_id_seq', 209, true);
  1556. --
  1557. -- Data for Name: menu_node; Type: TABLE DATA; Schema: public; Owner: ledgersmb
  1558. --
  1559. COPY menu_node (id, label, parent, "position") FROM stdin;
  1560. 205 Transaction Approval 0 5
  1561. 128 System 0 16
  1562. 190 Stylesheet 0 17
  1563. 191 Preferences 0 18
  1564. 192 New Window 0 19
  1565. 193 Logout 0 20
  1566. 206 Batches 205 1
  1567. 46 HR 0 6
  1568. 50 Order Entry 0 7
  1569. 63 Shipping 0 8
  1570. 67 Quotations 0 9
  1571. 73 General Journal 0 10
  1572. 77 Goods and Services 0 11
  1573. 0 Top-level \N 0
  1574. 1 AR 0 1
  1575. 2 Add Transaction 1 1
  1576. 144 Departments 128 8
  1577. 5 Transactions 4 1
  1578. 6 Outstanding 4 2
  1579. 7 AR Aging 4 3
  1580. 9 Taxable Sales 4 4
  1581. 10 Non-Taxable 4 5
  1582. 12 Add Customer 11 1
  1583. 13 Reports 11 2
  1584. 14 Search 13 1
  1585. 15 History 13 2
  1586. 16 Point of Sale 0 2
  1587. 17 Sale 16 1
  1588. 18 Open 16 2
  1589. 19 Receipts 16 3
  1590. 20 Close Till 16 4
  1591. 21 AP 0 3
  1592. 22 Add Transaction 21 1
  1593. 145 Add Department 144 1
  1594. 25 Transactions 24 1
  1595. 26 Outstanding 24 2
  1596. 27 AP Aging 24 3
  1597. 28 Taxable 24 4
  1598. 29 Non-taxable 24 5
  1599. 31 Add Vendor 30 1
  1600. 32 Reports 30 2
  1601. 33 Search 32 1
  1602. 34 History 32 2
  1603. 35 Cash 0 4
  1604. 36 Receipt 35 1
  1605. 38 Payment 35 3
  1606. 37 Receipts 35 2
  1607. 146 List Departments 144 2
  1608. 42 Receipts 41 1
  1609. 43 Payments 41 2
  1610. 44 Reconciliation 41 3
  1611. 147 Type of Business 128 9
  1612. 47 Employees 46 1
  1613. 48 Add Employee 47 1
  1614. 49 Search 47 2
  1615. 51 Sales Order 50 1
  1616. 52 Purchase Order 50 2
  1617. 53 Reports 50 3
  1618. 54 Sales Orders 53 1
  1619. 55 Purchase Orders 53 2
  1620. 57 Sales Orders 56 1
  1621. 58 Purchase Orders 56 2
  1622. 56 Generate 50 4
  1623. 60 Consolidate 50 5
  1624. 61 Sales Orders 60 1
  1625. 62 Purchase Orders 60 2
  1626. 64 Ship 63 1
  1627. 65 Receive 63 2
  1628. 66 Transfer 63 3
  1629. 68 Quotation 67 1
  1630. 69 RFQ 67 2
  1631. 70 Reports 67 3
  1632. 71 Quotations 70 1
  1633. 72 RFQs 70 2
  1634. 74 Journal Entry 73 1
  1635. 75 Adjust Till 73 2
  1636. 76 Reports 73 3
  1637. 78 Add Part 77 1
  1638. 79 Add Service 77 2
  1639. 80 Add Assembly 77 3
  1640. 81 Add Overhead 77 4
  1641. 82 Add Group 77 5
  1642. 83 Add Pricegroup 77 6
  1643. 84 Stock Assembly 77 7
  1644. 85 Reports 77 8
  1645. 86 All Items 85 1
  1646. 87 Parts 85 2
  1647. 88 Requirements 85 3
  1648. 89 Services 85 4
  1649. 90 Labor 85 5
  1650. 91 Groups 85 6
  1651. 92 Pricegroups 85 7
  1652. 93 Assembly 85 8
  1653. 94 Components 85 9
  1654. 95 Translations 77 9
  1655. 96 Description 95 1
  1656. 97 Partsgroup 95 2
  1657. 99 Add Project 98 1
  1658. 100 Add Timecard 98 2
  1659. 101 Generate 98 3
  1660. 102 Sales Orders 101 1
  1661. 103 Reports 98 4
  1662. 104 Search 103 1
  1663. 105 Transactions 103 2
  1664. 106 Time Cards 103 3
  1665. 107 Translations 98 5
  1666. 108 Description 107 1
  1667. 110 Chart of Accounts 109 1
  1668. 111 Trial Balance 109 2
  1669. 112 Income Statement 109 3
  1670. 113 Balance Sheet 109 4
  1671. 114 Inventory Activity 109 5
  1672. 117 Sales Invoices 116 1
  1673. 118 Sales Orders 116 2
  1674. 119 Checks 116 3
  1675. 120 Work Orders 116 4
  1676. 121 Quotations 116 5
  1677. 122 Packing Lists 116 6
  1678. 123 Pick Lists 116 7
  1679. 124 Purchase Orders 116 8
  1680. 125 Bin Lists 116 9
  1681. 126 RFQs 116 10
  1682. 127 Time Cards 116 11
  1683. 129 Audit Control 128 1
  1684. 130 Taxes 128 2
  1685. 131 Defaults 128 3
  1686. 132 Yearend 128 4
  1687. 133 Backup 128 5
  1688. 134 Send to File 133 1
  1689. 135 Send to Email 133 2
  1690. 136 Chart of Accounts 128 6
  1691. 137 Add Accounts 136 1
  1692. 138 List Accounts 136 2
  1693. 139 Add GIFI 136 3
  1694. 140 List GIFI 136 4
  1695. 141 Warehouses 128 7
  1696. 142 Add Warehouse 141 1
  1697. 143 List Warehouse 141 2
  1698. 148 Add Business 147 1
  1699. 149 List Businesses 147 2
  1700. 150 Language 128 10
  1701. 151 Add Language 150 1
  1702. 152 List Languages 150 2
  1703. 153 SIC 128 11
  1704. 154 Add SIC 153 1
  1705. 155 List SIC 153 2
  1706. 156 HTML Templates 128 12
  1707. 157 Income Statement 156 1
  1708. 158 Balance Sheet 156 2
  1709. 159 Invoice 156 3
  1710. 160 AR Transaction 156 4
  1711. 161 AP Transaction 156 5
  1712. 162 Packing List 156 6
  1713. 163 Pick List 156 7
  1714. 164 Sales Order 156 8
  1715. 165 Work Order 156 9
  1716. 166 Purchase Order 156 10
  1717. 167 Bin List 156 11
  1718. 168 Statement 156 12
  1719. 169 Quotation 156 13
  1720. 170 RFQ 156 14
  1721. 171 Timecard 156 15
  1722. 172 LaTeX Templates 128 13
  1723. 173 Invoice 172 1
  1724. 174 AR Transaction 172 2
  1725. 175 AP Transaction 172 3
  1726. 176 Packing List 172 4
  1727. 177 Pick List 172 5
  1728. 178 Sales Order 172 6
  1729. 179 Work Order 172 7
  1730. 180 Purchase Order 172 8
  1731. 181 Bin List 172 9
  1732. 182 Statement 172 10
  1733. 183 Check 172 11
  1734. 184 Receipt 172 12
  1735. 185 Quotation 172 13
  1736. 186 RFQ 172 14
  1737. 187 Timecard 172 15
  1738. 188 Text Templates 128 14
  1739. 189 POS Invoice 188 1
  1740. 198 AR Voucher 1 2
  1741. 3 Sales Invoice 1 3
  1742. 11 Customers 1 7
  1743. 4 Reports 1 6
  1744. 194 Credit Note 1 4
  1745. 195 Credit Invoice 1 5
  1746. 199 AP Voucher 21 2
  1747. 23 Vendor Invoice 21 3
  1748. 24 Reports 21 6
  1749. 30 Vendors 21 7
  1750. 196 Debit Note 21 4
  1751. 197 Debit Invoice 21 5
  1752. 200 Vouchers 35 5
  1753. 40 Transfer 35 6
  1754. 41 Reports 35 8
  1755. 45 Reconciliation 35 7
  1756. 203 Receipts 200 3
  1757. 204 Reverse Receipts 200 4
  1758. 201 Payments 200 1
  1759. 202 Reverse Payment 200 2
  1760. 98 Projects 0 12
  1761. 109 Reports 0 13
  1762. 115 Recurring Transactions 0 14
  1763. 116 Batch Printing 0 15
  1764. \.
  1765. --
  1766. -- Name: menu_node_parent_key; Type: CONSTRAINT; Schema: public; Owner: ledgersmb; Tablespace:
  1767. --
  1768. ALTER TABLE ONLY menu_node
  1769. ADD CONSTRAINT menu_node_parent_key UNIQUE (parent, "position");
  1770. --
  1771. -- Name: menu_node_pkey; Type: CONSTRAINT; Schema: public; Owner: ledgersmb; Tablespace:
  1772. --
  1773. ALTER TABLE ONLY menu_node
  1774. ADD CONSTRAINT menu_node_pkey PRIMARY KEY (id);
  1775. --
  1776. -- Name: menu_node_parent_fkey; Type: FK CONSTRAINT; Schema: public; Owner: ledgersmb
  1777. --
  1778. ALTER TABLE ONLY menu_node
  1779. ADD CONSTRAINT menu_node_parent_fkey FOREIGN KEY (parent) REFERENCES menu_node(id);
  1780. CREATE TABLE menu_attribute (
  1781. node_id integer NOT NULL,
  1782. attribute character varying NOT NULL,
  1783. value character varying NOT NULL,
  1784. id serial NOT NULL
  1785. );
  1786. --
  1787. -- Name: menu_attribute_id_seq; Type: SEQUENCE SET; Schema: public; Owner: ledgersmb
  1788. --
  1789. SELECT pg_catalog.setval('menu_attribute_id_seq', 584, true);
  1790. --
  1791. -- Data for Name: menu_attribute; Type: TABLE DATA; Schema: public; Owner: ledgersmb
  1792. --
  1793. COPY menu_attribute (node_id, attribute, value, id) FROM stdin;
  1794. 26 outstanding 1 584
  1795. 205 menu 1 574
  1796. 206 module vouchers.pl 575
  1797. 206 action search_batch 576
  1798. 1 menu 1 1
  1799. 2 module ar.pl 2
  1800. 2 action add 3
  1801. 3 action add 4
  1802. 3 module is.pl 5
  1803. 3 type invoice 6
  1804. 4 menu 1 7
  1805. 5 module ar.pl 8
  1806. 5 action search 9
  1807. 5 nextsub transactions 10
  1808. 6 module ar.pl 12
  1809. 6 action search 13
  1810. 6 nextsub transactions 14
  1811. 7 module rp.pl 15
  1812. 7 action report 16
  1813. 7 report ar_aging 17
  1814. 9 module rp.pl 21
  1815. 9 action report 22
  1816. 9 report tax_collected 23
  1817. 10 module rp.pl 24
  1818. 10 action report 25
  1819. 10 report nontaxable_sales 26
  1820. 11 menu 1 27
  1821. 12 module customer.pl 28
  1822. 12 action add 29
  1823. 13 menu 1 31
  1824. 14 module customer.pl 32
  1825. 14 action search 36
  1826. 15 module ct.pl 35
  1827. 15 db customer 37
  1828. 15 action history 33
  1829. 16 menu 1 38
  1830. 17 module ps.pl 39
  1831. 17 action add 40
  1832. 17 nextsub openinvoices 41
  1833. 18 action openinvoices 42
  1834. 18 module ps.pl 43
  1835. 19 module ps.pl 44
  1836. 19 action receipts 46
  1837. 20 module rc.pl 47
  1838. 20 action till_closing 48
  1839. 20 pos true 49
  1840. 21 menu 1 50
  1841. 22 action add 52
  1842. 22 module ap.pl 51
  1843. 23 action add 53
  1844. 23 type invoice 55
  1845. 23 module ir.pl 54
  1846. 24 menu 1 56
  1847. 25 action search 58
  1848. 25 nextsub transactions 59
  1849. 25 module ap.pl 57
  1850. 26 action search 61
  1851. 26 nextsub transactions 62
  1852. 26 module ap.pl 60
  1853. 27 module rp.pl 63
  1854. 27 action report 64
  1855. 28 module rp.pl 66
  1856. 28 action report 67
  1857. 28 report tax_collected 68
  1858. 27 report tax_paid 65
  1859. 29 module rp.pl 69
  1860. 29 action report 70
  1861. 29 report report 71
  1862. 30 menu 1 72
  1863. 31 module vendor.pl 73
  1864. 31 action add 74
  1865. 31 db vendor 75
  1866. 32 menu 1 76
  1867. 33 module vendor.pl 77
  1868. 33 action search 79
  1869. 33 db vendor 78
  1870. 34 module vendor.pl 80
  1871. 34 action history 81
  1872. 34 db vendor 82
  1873. 35 menu 1 83
  1874. 36 module payment.pl 84
  1875. 36 action payment 85
  1876. 36 type receipt 86
  1877. 37 module cp.pl 87
  1878. 38 module cp.pl 90
  1879. 38 action payment 91
  1880. 37 type receipt 89
  1881. 37 action payments 88
  1882. 38 type check 92
  1883. 194 module ar.pl 538
  1884. 194 action add 539
  1885. 40 module gl.pl 96
  1886. 40 action add 97
  1887. 40 transfer 1 98
  1888. 41 menu 1 99
  1889. 42 module rp.pl 100
  1890. 42 action report 101
  1891. 42 report receipts 102
  1892. 43 module rp.pl 103
  1893. 43 action report 104
  1894. 43 report payments 105
  1895. 45 module rc.pl 106
  1896. 45 action reconciliation 107
  1897. 44 module rc.pl 108
  1898. 44 action reconciliation 109
  1899. 44 report 1 110
  1900. 46 menu 1 111
  1901. 47 menu 1 112
  1902. 48 module employee.pl 113
  1903. 48 action add 114
  1904. 48 db employee 115
  1905. 49 module hr.pl 116
  1906. 49 db employee 118
  1907. 49 action search 117
  1908. 50 menu 1 119
  1909. 51 module oe.pl 120
  1910. 51 action add 121
  1911. 51 type sales_order 122
  1912. 52 module oe.pl 123
  1913. 52 action add 124
  1914. 52 type purchase_order 125
  1915. 53 menu 1 126
  1916. 54 module oe.pl 127
  1917. 54 type sales_order 129
  1918. 54 action search 128
  1919. 55 module oe.pl 130
  1920. 55 type purchase_order 132
  1921. 55 action search 131
  1922. 56 menu 1 133
  1923. 57 module oe.pl 134
  1924. 57 action search 136
  1925. 58 module oe.pl 137
  1926. 58 action search 139
  1927. 57 type generate_sales_order 135
  1928. 58 type generate_purchase_order 138
  1929. 60 menu 1 550
  1930. 61 module oe.pl 140
  1931. 61 action search 141
  1932. 62 module oe.pl 143
  1933. 62 action search 144
  1934. 62 type consolidate_purchase_order 145
  1935. 61 type consolidate_sales_order 142
  1936. 63 menu 1 146
  1937. 64 module oe.pl 147
  1938. 64 action search 148
  1939. 65 module oe.pl 150
  1940. 65 action search 151
  1941. 65 type consolidate_sales_order 152
  1942. 64 type receive_order 149
  1943. 66 module oe.pl 153
  1944. 66 action search_transfer 154
  1945. 67 menu 1 155
  1946. 68 module oe.pl 156
  1947. 68 action add 157
  1948. 69 module oe.pl 159
  1949. 69 action add 160
  1950. 68 type sales_quotation 158
  1951. 69 type request_quotation 161
  1952. 70 menu 1 162
  1953. 71 module oe.pl 163
  1954. 71 type sales_quotation 165
  1955. 71 action search 164
  1956. 72 module oe.pl 166
  1957. 72 action search 168
  1958. 72 type request_quotation 167
  1959. 73 menu 1 169
  1960. 74 module gl.pl 170
  1961. 74 action add 171
  1962. 75 module gl.pl 172
  1963. 75 action add_pos_adjust 174
  1964. 75 rowcount 3 175
  1965. 75 pos_adjust 1 176
  1966. 75 reference Adjusting Till: (Till) Source: (Source) 177
  1967. 75 descripton Adjusting till due to data entry error 178
  1968. 76 module gl.pl 180
  1969. 76 action search 181
  1970. 77 menu 1 182
  1971. 78 module ic.pl 183
  1972. 78 action add 184
  1973. 78 item part 185
  1974. 79 module ic.pl 186
  1975. 79 action add 187
  1976. 79 item service 188
  1977. 80 module ic.pl 189
  1978. 80 action add 190
  1979. 81 module ic.pl 192
  1980. 81 action add 193
  1981. 81 item part 194
  1982. 80 item labor 191
  1983. 82 action add 195
  1984. 82 module pe.pl 196
  1985. 83 action add 198
  1986. 83 module pe.pl 199
  1987. 83 type partsgroup 200
  1988. 82 type pricegroup 197
  1989. 84 module ic.pl 202
  1990. 84 action stock_assembly 203
  1991. 85 menu 1 204
  1992. 86 module ic.pl 205
  1993. 87 action search 206
  1994. 88 module ic.pl 211
  1995. 88 action requirements 212
  1996. 89 action search 213
  1997. 89 module ic.pl 214
  1998. 89 searchitems service 215
  1999. 87 searchitems part 210
  2000. 90 action search 216
  2001. 90 module ic.pl 217
  2002. 90 searchitems labor 218
  2003. 91 module pe.pl 221
  2004. 91 type pricegroup 222
  2005. 91 action search 220
  2006. 92 module pe.pl 224
  2007. 92 type partsgroup 225
  2008. 92 action search 223
  2009. 93 action search 226
  2010. 93 module ic.pl 227
  2011. 93 searchitems assembly 228
  2012. 94 action search 229
  2013. 94 module ic.pl 230
  2014. 94 searchitems component 231
  2015. 95 menu 1 232
  2016. 96 module pe.pl 233
  2017. 96 action translation 234
  2018. 96 translation description 235
  2019. 97 module pe.pl 236
  2020. 97 action translation 237
  2021. 97 translation partsgroup 238
  2022. 98 menu 1 239
  2023. 99 module pe.pl 240
  2024. 99 action add 241
  2025. 99 type project 242
  2026. 100 module jc.pl 243
  2027. 100 action add 244
  2028. 99 project project 245
  2029. 100 project project 246
  2030. 100 type timecard 247
  2031. 101 menu 1 248
  2032. 102 module pe.pl 249
  2033. 102 action project_sales_order 250
  2034. 103 menu 1 255
  2035. 104 module pe.pl 256
  2036. 104 type project 258
  2037. 104 action search 257
  2038. 105 action report 260
  2039. 105 report projects 261
  2040. 105 module rp.pl 262
  2041. 106 module jc.pl 263
  2042. 106 action search 264
  2043. 106 type timecard 265
  2044. 106 project project 266
  2045. 107 menu 1 268
  2046. 108 module pe.pl 269
  2047. 108 action translation 270
  2048. 108 translation project 271
  2049. 109 menu 1 272
  2050. 110 module ca.pl 273
  2051. 110 action chart_of_accounts 274
  2052. 111 action report 275
  2053. 111 module rp.pl 276
  2054. 111 report trial_balance 277
  2055. 112 action report 278
  2056. 112 module rp.pl 279
  2057. 112 report income_statement 280
  2058. 113 action report 281
  2059. 113 module rp.pl 282
  2060. 113 report balance_sheet 283
  2061. 114 action report 284
  2062. 114 module rp.pl 285
  2063. 114 report inv_activity 286
  2064. 115 action recurring_transactions 287
  2065. 115 module am.pl 288
  2066. 116 menu 1 289
  2067. 119 module bp.pl 290
  2068. 119 action search 291
  2069. 119 type check 292
  2070. 119 vc vendor 293
  2071. 117 module bp.pl 294
  2072. 117 action search 295
  2073. 117 vc customer 297
  2074. 118 module bp.pl 298
  2075. 118 action search 299
  2076. 118 vc customer 300
  2077. 118 type invoice 301
  2078. 117 type sales_order 296
  2079. 120 module bp.pl 302
  2080. 120 action search 303
  2081. 120 vc customer 304
  2082. 121 module bp.pl 306
  2083. 121 action search 307
  2084. 121 vc customer 308
  2085. 122 module bp.pl 310
  2086. 122 action search 311
  2087. 122 vc customer 312
  2088. 120 type work_order 305
  2089. 121 type sales_quotation 309
  2090. 122 type packing_list 313
  2091. 123 module bp.pl 314
  2092. 123 action search 315
  2093. 123 vc customer 316
  2094. 123 type pick_list 317
  2095. 124 module bp.pl 318
  2096. 124 action search 319
  2097. 124 vc vendor 321
  2098. 124 type purchase_order 320
  2099. 125 module bp.pl 322
  2100. 125 action search 323
  2101. 125 vc vendor 325
  2102. 126 module bp.pl 326
  2103. 126 action search 327
  2104. 126 vc vendor 329
  2105. 127 module bp.pl 330
  2106. 127 action search 331
  2107. 127 type timecard 332
  2108. 125 type bin_list 324
  2109. 126 type request_quotation 328
  2110. 127 vc employee 333
  2111. 128 menu 1 334
  2112. 129 module am.pl 337
  2113. 130 module am.pl 338
  2114. 131 module am.pl 339
  2115. 129 action audit_control 340
  2116. 130 taxes audit_control 341
  2117. 131 action defaults 342
  2118. 130 action taxes 343
  2119. 132 module am.pl 346
  2120. 132 action yearend 347
  2121. 133 menu 1 348
  2122. 134 module am.pl 349
  2123. 135 module am.pl 350
  2124. 134 action backup 351
  2125. 135 action backup 352
  2126. 134 media file 353
  2127. 135 media email 354
  2128. 137 module am.pl 355
  2129. 138 module am.pl 356
  2130. 139 module am.pl 357
  2131. 140 module am.pl 358
  2132. 137 action add_account 359
  2133. 138 action list_account 360
  2134. 139 action add_gifi 361
  2135. 140 action list_gifi 362
  2136. 141 menu 1 363
  2137. 142 module am.pl 364
  2138. 143 module am.pl 365
  2139. 142 action add_warehouse 366
  2140. 143 action list_warehouse 367
  2141. 145 module am.pl 368
  2142. 146 module am.pl 369
  2143. 145 action add_department 370
  2144. 146 action list_department 371
  2145. 147 menu 1 372
  2146. 148 module am.pl 373
  2147. 149 module am.pl 374
  2148. 148 action add_business 375
  2149. 149 action list_business 376
  2150. 150 menu 1 377
  2151. 151 module am.pl 378
  2152. 152 module am.pl 379
  2153. 151 action add_language 380
  2154. 152 action list_language 381
  2155. 153 menu 1 382
  2156. 154 module am.pl 383
  2157. 155 module am.pl 384
  2158. 154 action add_sic 385
  2159. 155 action list_sic 386
  2160. 156 menu 1 387
  2161. 157 module am.pl 388
  2162. 158 module am.pl 389
  2163. 159 module am.pl 390
  2164. 160 module am.pl 391
  2165. 161 module am.pl 392
  2166. 162 module am.pl 393
  2167. 163 module am.pl 394
  2168. 164 module am.pl 395
  2169. 165 module am.pl 396
  2170. 166 module am.pl 397
  2171. 167 module am.pl 398
  2172. 168 module am.pl 399
  2173. 169 module am.pl 400
  2174. 170 module am.pl 401
  2175. 171 module am.pl 402
  2176. 157 action list_templates 403
  2177. 158 action list_templates 404
  2178. 159 action list_templates 405
  2179. 160 action list_templates 406
  2180. 161 action list_templates 407
  2181. 162 action list_templates 408
  2182. 163 action list_templates 409
  2183. 164 action list_templates 410
  2184. 165 action list_templates 411
  2185. 166 action list_templates 412
  2186. 167 action list_templates 413
  2187. 168 action list_templates 414
  2188. 169 action list_templates 415
  2189. 170 action list_templates 416
  2190. 171 action list_templates 417
  2191. 157 template income_statement 418
  2192. 158 template balance_sheet 419
  2193. 159 template invoice 420
  2194. 160 template ar_transaction 421
  2195. 161 template ap_transaction 422
  2196. 162 template packing_list 423
  2197. 163 template pick_list 424
  2198. 164 template sales_order 425
  2199. 165 template work_order 426
  2200. 166 template purchase_order 427
  2201. 167 template bin_list 428
  2202. 168 template statement 429
  2203. 169 template quotation 430
  2204. 170 template rfq 431
  2205. 171 template timecard 432
  2206. 157 format HTML 433
  2207. 158 format HTML 434
  2208. 159 format HTML 435
  2209. 160 format HTML 436
  2210. 161 format HTML 437
  2211. 162 format HTML 438
  2212. 163 format HTML 439
  2213. 164 format HTML 440
  2214. 165 format HTML 441
  2215. 166 format HTML 442
  2216. 167 format HTML 443
  2217. 168 format HTML 444
  2218. 169 format HTML 445
  2219. 170 format HTML 446
  2220. 171 format HTML 447
  2221. 172 menu 1 448
  2222. 173 action list_templates 449
  2223. 174 action list_templates 450
  2224. 175 action list_templates 451
  2225. 176 action list_templates 452
  2226. 177 action list_templates 453
  2227. 178 action list_templates 454
  2228. 179 action list_templates 455
  2229. 180 action list_templates 456
  2230. 181 action list_templates 457
  2231. 182 action list_templates 458
  2232. 183 action list_templates 459
  2233. 184 action list_templates 460
  2234. 185 action list_templates 461
  2235. 186 action list_templates 462
  2236. 187 action list_templates 463
  2237. 173 module am.pl 464
  2238. 174 module am.pl 465
  2239. 175 module am.pl 466
  2240. 176 module am.pl 467
  2241. 177 module am.pl 468
  2242. 178 module am.pl 469
  2243. 179 module am.pl 470
  2244. 180 module am.pl 471
  2245. 181 module am.pl 472
  2246. 182 module am.pl 473
  2247. 183 module am.pl 474
  2248. 184 module am.pl 475
  2249. 185 module am.pl 476
  2250. 186 module am.pl 477
  2251. 187 module am.pl 478
  2252. 173 format LATEX 479
  2253. 174 format LATEX 480
  2254. 175 format LATEX 481
  2255. 176 format LATEX 482
  2256. 177 format LATEX 483
  2257. 178 format LATEX 484
  2258. 179 format LATEX 485
  2259. 180 format LATEX 486
  2260. 181 format LATEX 487
  2261. 182 format LATEX 488
  2262. 183 format LATEX 489
  2263. 184 format LATEX 490
  2264. 185 format LATEX 491
  2265. 186 format LATEX 492
  2266. 187 format LATEX 493
  2267. 173 template invoice 506
  2268. 174 template ar_transaction 507
  2269. 175 template ap_transaction 508
  2270. 176 template packing_list 509
  2271. 177 template pick_list 510
  2272. 178 template sales_order 511
  2273. 179 template work_order 512
  2274. 180 template purchase_order 513
  2275. 181 template bin_list 514
  2276. 182 template statement 515
  2277. 185 template quotation 518
  2278. 186 template rfq 519
  2279. 187 template timecard 520
  2280. 183 template check 516
  2281. 184 template receipt 517
  2282. 188 menu 1 521
  2283. 189 module am.pl 522
  2284. 189 action list_templates 523
  2285. 189 template pos_invoice 524
  2286. 189 format TEXT 525
  2287. 190 action display_stylesheet 526
  2288. 190 module am.pl 527
  2289. 191 module am.pl 528
  2290. 191 action config 529
  2291. 193 module login.pl 532
  2292. 193 action logout 533
  2293. 193 target _top 534
  2294. 192 menu 1 530
  2295. 192 new 1 531
  2296. 0 menu 1 535
  2297. 136 menu 1 536
  2298. 144 menu 1 537
  2299. 195 action add 540
  2300. 195 module is.pl 541
  2301. 196 action add 543
  2302. 196 module ap.pl 544
  2303. 197 action add 545
  2304. 197 module ir.pl 547
  2305. 196 type debit_note 549
  2306. 194 type credit_note 548
  2307. 195 type credit_invoice 542
  2308. 197 type debit_invoice 546
  2309. 36 account_class 1 551
  2310. 202 batch_type payment_reversal 570
  2311. 204 batch_type receipt_reversal 573
  2312. 200 menu 1 552
  2313. 198 action create_batch 554
  2314. 198 batch_type receivable 555
  2315. 198 module vouchers.pl 553
  2316. 199 module vouchers.pl 559
  2317. 199 action create_batch 560
  2318. 199 batch_type payable 561
  2319. 201 module vouchers.pl 562
  2320. 201 action create_batch 563
  2321. 203 module vouchers.pl 565
  2322. 203 action create_batch 566
  2323. 203 batch_type receipts 567
  2324. 202 module vouchers.pl 568
  2325. 202 action create_batch 569
  2326. 204 module vouchers.pl 571
  2327. 204 action create_batch 572
  2328. 201 batch_type payment 564
  2329. \.
  2330. --
  2331. -- Name: menu_attribute_id_key; Type: CONSTRAINT; Schema: public; Owner: ledgersmb; Tablespace:
  2332. --
  2333. ALTER TABLE ONLY menu_attribute
  2334. ADD CONSTRAINT menu_attribute_id_key UNIQUE (id);
  2335. --
  2336. -- Name: menu_attribute_pkey; Type: CONSTRAINT; Schema: public; Owner: ledgersmb; Tablespace:
  2337. --
  2338. ALTER TABLE ONLY menu_attribute
  2339. ADD CONSTRAINT menu_attribute_pkey PRIMARY KEY (node_id, attribute);
  2340. --
  2341. -- Name: menu_attribute_node_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: ledgersmb
  2342. --
  2343. ALTER TABLE ONLY menu_attribute
  2344. ADD CONSTRAINT menu_attribute_node_id_fkey FOREIGN KEY (node_id) REFERENCES menu_node(id);
  2345. --
  2346. -- PostgreSQL database dump complete
  2347. --
  2348. --
  2349. CREATE TABLE menu_acl (
  2350. id serial NOT NULL,
  2351. role_name character varying,
  2352. acl_type character varying,
  2353. node_id integer,
  2354. CONSTRAINT menu_acl_acl_type_check CHECK ((((acl_type)::text = 'allow'::text) OR ((acl_type)::text = 'deny'::text)))
  2355. );
  2356. ALTER TABLE ONLY menu_acl
  2357. ADD CONSTRAINT menu_acl_pkey PRIMARY KEY (id);
  2358. ALTER TABLE ONLY menu_acl
  2359. ADD CONSTRAINT menu_acl_node_id_fkey FOREIGN KEY (node_id) REFERENCES menu_node(id);
  2360. --
  2361. -- PostgreSQL database dump complete
  2362. --
  2363. CREATE TYPE menu_item AS (
  2364. position int,
  2365. id int,
  2366. level int,
  2367. label varchar,
  2368. path varchar,
  2369. args varchar[]
  2370. );
  2371. CREATE OR REPLACE FUNCTION menu_generate() RETURNS SETOF menu_item AS
  2372. $$
  2373. DECLARE
  2374. item menu_item;
  2375. arg menu_attribute%ROWTYPE;
  2376. BEGIN
  2377. FOR item IN
  2378. SELECT n.position, n.id, c.level, n.label, c.path, '{}'
  2379. FROM connectby('menu_node', 'id', 'parent', 'position', '0',
  2380. 0, ',')
  2381. c(id integer, parent integer, "level" integer,
  2382. path text, list_order integer)
  2383. JOIN menu_node n USING(id)
  2384. LOOP
  2385. FOR arg IN
  2386. SELECT *
  2387. FROM menu_attribute
  2388. WHERE node_id = item.id
  2389. LOOP
  2390. item.args := item.args ||
  2391. (arg.attribute || '=' || arg.value)::varchar;
  2392. END LOOP;
  2393. RETURN NEXT item;
  2394. END LOOP;
  2395. END;
  2396. $$ language plpgsql;
  2397. CREATE OR REPLACE FUNCTION menu_children(in_parent_id int) RETURNS SETOF menu_item
  2398. AS $$
  2399. declare
  2400. item menu_item;
  2401. arg menu_attribute%ROWTYPE;
  2402. begin
  2403. FOR item IN
  2404. SELECT n.position, n.id, c.level, n.label, c.path, '{}'
  2405. FROM connectby('menu_node', 'id', 'parent', 'position',
  2406. in_parent_id, 1, ',')
  2407. c(id integer, parent integer, "level" integer,
  2408. path text, list_order integer)
  2409. JOIN menu_node n USING(id)
  2410. LOOP
  2411. FOR arg IN
  2412. SELECT *
  2413. FROM menu_attribute
  2414. WHERE node_id = item.id
  2415. LOOP
  2416. item.args := item.args ||
  2417. (arg.attribute || '=' || arg.value)::varchar;
  2418. END LOOP;
  2419. return next item;
  2420. end loop;
  2421. end;
  2422. $$ language plpgsql;
  2423. COMMENT ON FUNCTION menu_children(int) IS $$ This function returns all menu items which are children of in_parent_id (the only input parameter. $$;
  2424. CREATE OR REPLACE FUNCTION
  2425. menu_insert(in_parent_id int, in_position int, in_label text)
  2426. returns int
  2427. AS $$
  2428. DECLARE
  2429. new_id int;
  2430. BEGIN
  2431. UPDATE menu_node
  2432. SET position = position * -1
  2433. WHERE parent = in_parent_id
  2434. AND position >= in_position;
  2435. INSERT INTO menu_node (parent, position, label)
  2436. VALUES (in_parent_id, in_position, in_label);
  2437. SELECT INTO new_id currval('menu_node_id_seq');
  2438. UPDATE menu_node
  2439. SET position = (position * -1) + 1
  2440. WHERE parent = in_parent_id
  2441. AND position < 0;
  2442. RETURN new_id;
  2443. END;
  2444. $$ language plpgsql;
  2445. comment on function menu_insert(int, int, text) is $$
  2446. This function inserts menu items at arbitrary positions. The arguments are, in
  2447. order: parent, position, label. The return value is the id number of the menu
  2448. item created. $$;
  2449. CREATE VIEW menu_friendly AS
  2450. SELECT t."level", t.path, t.list_order, (repeat(' '::text, (2 * t."level")) || (n.label)::text) AS label, n.id, n."position" FROM (connectby('menu_node'::text, 'id'::text, 'parent'::text, 'position'::text, '0'::text, 0, ','::text) t(id integer, parent integer, "level" integer, path text, list_order integer) JOIN menu_node n USING (id));
  2451. --ALTER TABLE public.menu_friendly OWNER TO ledgersmb;
  2452. --
  2453. -- PostgreSQL database dump complete
  2454. --
  2455. CREATE AGGREGATE as_array (
  2456. BASETYPE = ANYELEMENT,
  2457. STYPE = ANYARRAY,
  2458. SFUNC = ARRAY_APPEND,
  2459. INITCOND = '{}'
  2460. );
  2461. CREATE AGGREGATE compound_array (
  2462. BASETYPE = ANYARRAY,
  2463. STYPE = ANYARRAY,
  2464. SFUNC = ARRAY_CAT,
  2465. INITCOND = '{}'
  2466. );
  2467. CREATE TABLE pending_reports (
  2468. id bigserial primary key not null,
  2469. report_id int,
  2470. scn int,
  2471. their_balance INT,
  2472. our_balance INT,
  2473. errorcode INT,
  2474. entered_by int references entity(id) not null,
  2475. corrections INT NOT NULL DEFAULT 0,
  2476. clear_time TIMESTAMP NOT NULL,
  2477. insert_time TIMESTAMPTZ NOT NULL DEFAULT now(),
  2478. ledger_id int REFERENCES acc_trans(entry_id),
  2479. overlook boolean not null default 'f'
  2480. );
  2481. CREATE TABLE report_corrections (
  2482. id serial primary key not null,
  2483. correction_id int not null default 1,
  2484. entry_in int references pending_reports(id) not null,
  2485. entered_by int not null,
  2486. reason text not null,
  2487. insert_time timestamptz not null default now()
  2488. );
  2489. CREATE INDEX company_name_gist__idx ON company USING gist(legal_name gist_trgm_ops);
  2490. CREATE INDEX location_address_one_gist__idx ON location USING gist(line_one gist_trgm_ops);
  2491. CREATE INDEX location_address_two_gist__idx ON location USING gist(line_two gist_trgm_ops);
  2492. CREATE INDEX location_address_three_gist__idx ON location USING gist(line_three gist_trgm_ops);
  2493. CREATE INDEX location_city_prov_gist_idx ON location USING gist(city gist_trgm_ops);
  2494. CREATE INDEX entity_name_gist_idx ON entity USING gist(name gist_trgm_ops);
  2495. CREATE TABLE pending_job (
  2496. id serial not null unique,
  2497. batch_class int references batch_class(id),
  2498. entered_by text REFERENCES users(username)
  2499. not null default SESSION_USER,
  2500. entered_at timestamp default now(),
  2501. batch_id int references batch(id),
  2502. completed_at timestamp,
  2503. success bool,
  2504. error_condition text,
  2505. CHECK (completed_at IS NULL OR success IS NOT NULL),
  2506. CHECK (success IS NOT FALSE OR error_condition IS NOT NULL)
  2507. );
  2508. COMMENT ON table pending_job IS
  2509. $$ Purpose: This table stores pending/queued jobs to be processed async.
  2510. Additionally, this functions as a log of all such processing for purposes of
  2511. internal audits, performance tuning, and the like. $$;
  2512. CREATE INDEX pending_job_batch_id_pending ON pending_job(batch_id) where success IS NULL;
  2513. CREATE INDEX pending_job_entered_by ON pending_job(entered_by);
  2514. CREATE OR REPLACE FUNCTION trigger_pending_job() RETURNS TRIGGER
  2515. AS
  2516. $$
  2517. BEGIN
  2518. IF NEW.success IS NULL THEN
  2519. NOTIFY job_entered;
  2520. END IF;
  2521. RETURN NEW;
  2522. END;
  2523. $$ LANGUAGE PLPGSQL;
  2524. CREATE TRIGGER notify_pending_jobs BEFORE INSERT OR UPDATE ON pending_job
  2525. FOR EACH ROW EXECUTE PROCEDURE trigger_pending_job();
  2526. CREATE TABLE payments_queue (
  2527. transactions numeric[],
  2528. batch_id int,
  2529. source text,
  2530. total numeric,
  2531. ar_ap_accno text,
  2532. cash_accno text,
  2533. payment_date date,
  2534. account_class int,
  2535. job_id int references pending_job(id)
  2536. DEFAULT currval('pending_job_id_seq')
  2537. );
  2538. CREATE INDEX payments_queue_job_id ON payments_queue(job_id);
  2539. COMMENT ON table payments_queue IS
  2540. $$ This is a holding table and hence not a candidate for normalization.
  2541. Jobs should be deleted from this table when they complete successfully.$$;
  2542. commit;