2 -- tenantcode | integer | not null default nextval('tenant_tenantcode_seq'::regclass)
3 -- billingcontact | integer | default 0
4 -- name | text | default ''::text
5 -- propertycontact | integer | default 0
6 -- active | boolean | default false
7 -- debtclassification | text | default ''::text
8 -- varianceclassification | text | default ''::text
9 -- entitycode | integer | default 0
10 -- notecode | integer |
11 -- quality | integer | default 0
12 -- ah1contact | integer | default 0
13 -- entitytype | text | default 'L'::text
14 -- legalname | text | default ''::text
15 -- paymentstyle | text | default ''::text
16 -- lastmodifieddate | date | default '0001-01-01'::date
17 -- lastmodifiedtime | integer | default 0
18 -- lastmodifieduser | text | default ''::text
19 -- auditrecordid | integer | default 0
20 -- ah2contact | integer | default 0
21 -- businesstype | text | default ''::text
22 -- lastrenttotal | numeric | default (0)::numeric
23 -- cfbalance | numeric | default (0)::numeric
24 -- batchlaststatement | integer | default 0
26 ----------- Table "public.postaldetail"
27 -- Column | Type | Modifiers
28 -- ------------+---------+---------------------------
29 -- personcode | integer | not null default 0
30 -- postaltype | text | not null default ''::text
31 -- address | text | default ''::text
32 -- city | text | default ''::text
33 -- state | text | default ''::text
34 -- country | text | default ''::text
35 -- zip | text | default ''::text
37 ----------- Table "public.phonedetail"
38 -- Column | Type | Modifiers
39 -- --------------+---------+---------------------------
40 -- personcode | integer | not null default 0
41 -- phonetype | text | not null default ''::text
42 -- number | text | default ''::text
43 -- countrycode | integer | default 0
44 -- stdcode | integer | default 0
45 -- ccountrycode | text | default ''::text
46 -- cstdcode | text | default ''::text
48 ----------- Table "public.person"
49 -- Column | Type | Modifiers
50 -- ----------------+---------+------------------
51 -- personcode | integer | not null
52 -- persontitle | text | default ''::text
53 -- dateofbirth | date |
54 -- firstname | text | default ''::text
55 -- company | text | default ''::text
56 -- golfhandicap | integer |
57 -- lastname | text | default ''::text
58 -- preferred | text | default ''::text
60 -- jobtitle | text | default ''::text
61 -- office | text | default ''::text
62 -- creatorid | text | default ''::text
63 -- lastmodified | date |
64 -- department | text | default ''::text
65 -- spouse | text | default ''::text
66 -- lastvalidated | date |
68 -- systemcontact | boolean | default false
69 -- scheduleplusid | text | default ''::text
70 -- sorton | text | default ''::text
71 -- initials | text | default ''::text
72 -- middlenames | text | default ''::text
73 -- namesuffix | text | default ''::text
74 -- mailout | boolean | default true
75 -- tempgroup | boolean | default false
78 -- SELECT setval('batch_seq',(select max(b.batchcode) from (select batchcode from newaccttrans union select batchcode from accttran) b));
81 CREATE OR REPLACE VIEW debtor_maintenance AS
82 SELECT tenant.tenantcode AS debtorcode, tenant.active AS debtor_active, tenant.name AS debtor_name,
83 debtclassification, varianceclassification, tenant.entitytype AS debtor_et, tenant.entitycode AS debtor_ec,
85 billperson.persontitle AS billperson_title, billperson.firstname AS billperson_first, billperson.lastname AS billperson_last,
86 billperson.company AS bill_company_name, billperson.jobtitle AS billperson_job,
87 bill.address AS bill_address, bill.city AS bill_city, bill.state AS bill_state, bill.country AS bill_country, bill.zip AS bill_zip,
88 busphone.number AS busphone_no, busphone.ccountrycode AS busphone_isd, busphone.cstdcode AS busphone_std,
89 get_entity_name( tenant.entitytype, tenant.entitycode ) AS debtor_entity_name
91 LEFT JOIN person billperson ON tenant.billingcontact = billperson.personcode
92 LEFT JOIN postaldetail bill ON tenant.billingcontact = bill.personcode AND bill.postaltype = 'BILL'
93 LEFT JOIN phonedetail busphone ON tenant.billingcontact = busphone.personcode AND busphone.phonetype = 'BUS' ;
95 CREATE or REPLACE RULE debtor_maintenance_insert AS ON INSERT TO debtor_maintenance
98 INSERT INTO person ( personcode, persontitle, firstname, lastname, company, jobtitle )
100 COALESCE( NEW.billingcontact, nextval('person_personcode_seq')),
101 COALESCE( NEW.billperson_title, '' ),
102 COALESCE( NEW.billperson_first, ''),
103 COALESCE( NEW.billperson_last, '' ),
104 COALESCE( NEW.bill_company_name, NEW.debtor_name ),
105 COALESCE( NEW.billperson_job, '')
107 INSERT INTO postaldetail ( personcode, postaltype, address, city, state, country, zip )
109 COALESCE( NEW.billingcontact, currval('person_personcode_seq')), 'BILL',
110 COALESCE( NEW.bill_address, ''),
111 COALESCE( NEW.bill_city, ''),
112 COALESCE( NEW.bill_state, ''),
113 COALESCE( NEW.bill_country, ''),
114 COALESCE( NEW.bill_zip, '')
116 INSERT INTO phonedetail ( personcode, phonetype, number, ccountrycode, cstdcode )
118 COALESCE( NEW.billingcontact, currval('person_personcode_seq')), 'BUS',
119 COALESCE( NEW.busphone_no, ''),
120 COALESCE( NEW.busphone_isd, ''),
121 COALESCE( NEW.busphone_std, '' )
123 INSERT INTO contact ( personcode, contacttype, systemcode )
125 COALESCE( NEW.billingcontact, currval('person_personcode_seq')), 'TNNT', TRUE
127 INSERT INTO tenant ( tenantcode, active, name, debtclassification, varianceclassification, entitytype, entitycode, billingcontact )
129 COALESCE( NEW.debtorcode, nextval('tenant_tenantcode_seq') ),
130 COALESCE( NEW.debtor_active, TRUE ),
131 COALESCE( NEW.debtor_name, 'An unnamed debtor' ),
132 NEW.debtclassification, NEW.varianceclassification,
133 COALESCE( NEW.debtor_et, 'L'),
134 COALESCE( NEW.debtor_ec, 1 ),
135 COALESCE( NEW.billingcontact, currval('person_personcode_seq'))
139 CREATE or REPLACE RULE debtor_maintenance_update AS ON UPDATE TO debtor_maintenance
143 SET persontitle = NEW.billperson_title,
144 firstname = NEW.billperson_first,
145 lastname = NEW.billperson_last,
146 company = NEW.bill_company_name,
147 jobtitle = NEW.billperson_job
148 WHERE personcode = NEW.billingcontact;
151 SET address = NEW.bill_address,
152 city = NEW.bill_city,
153 state = NEW.bill_state,
154 country = NEW.bill_country,
156 WHERE personcode = NEW.billingcontact AND postaltype = 'BILL';
159 SET number = NEW.busphone_no,
160 ccountrycode = NEW.busphone_isd,
161 cstdcode = NEW.busphone_std
162 WHERE personcode = NEW.billingcontact AND phonetype = 'BUS';
165 SET active = NEW.debtor_active,
166 name = NEW.debtor_name,
167 debtclassification = NEW.debtclassification,
168 varianceclassification = NEW.varianceclassification,
169 entitytype = NEW.debtor_et,
170 entitycode = NEW.debtor_ec,
171 billingcontact = NEW.billingcontact
172 WHERE tenantcode = OLD.debtorcode;
178 ----------- Column | Type | Modifiers
179 -- ------------------------+---------+-----------------------------------------------------------------
180 -- creditorcode | integer | not null default nextval('creditor_creditorcode_seq'::regclass)
181 -- paymentcontact | integer | default 0
182 -- name | text | default ''::text
183 -- payeename | text | default ''::text
184 -- othercontact | integer | default 0
185 -- active | boolean | default false
186 -- paymentstyle | text | default 'CHEQ'::text
187 -- bankdetails | text | default ''::text
188 -- companycode | integer | default 0
189 -- lastmodifieddate | date | default '0001-01-01'::date
190 -- lastmodifiedtime | integer | default 0
191 -- lastmodifieduser | text | default ''::text
192 -- auditrecordid | integer | default 0
193 -- chequespermonth | integer | default 31
194 -- vchrentitytype | text | default ''::text
195 -- vchrentitycode | integer | default 0
196 -- vchraccountcode | numeric | default (0)::numeric
197 -- vchrapprover | text | default ''::text
198 -- bankdetailschangedby | text | default ''::text
199 -- enabledirectpayment | boolean | default false
200 -- directpaymentenabledby | text | default ''::text
201 -- nonaccounting | boolean | default false
202 -- acctcreditorcode | integer | default 0
203 -- dcstatementtext | text | default ''::text
204 -- dcremittanceemail | text | default ''::text
207 ----------- Table "public.postaldetail"
208 -- Column | Type | Modifiers
209 -- ------------+---------+---------------------------
210 -- personcode | integer | not null default 0
211 -- postaltype | text | not null default ''::text
212 -- address | text | default ''::text
213 -- city | text | default ''::text
214 -- state | text | default ''::text
215 -- country | text | default ''::text
216 -- zip | text | default ''::text
218 ----------- Table "public.phonedetail"
219 -- Column | Type | Modifiers
220 -- --------------+---------+---------------------------
221 -- personcode | integer | not null default 0
222 -- phonetype | text | not null default ''::text
223 -- number | text | default ''::text
224 -- countrycode | integer | default 0
225 -- stdcode | integer | default 0
226 -- ccountrycode | text | default ''::text
227 -- cstdcode | text | default ''::text
229 ----------- Table "public.person"
230 -- Column | Type | Modifiers
231 -- ----------------+---------+------------------
232 -- personcode | integer | not null
233 -- persontitle | text | default ''::text
234 -- dateofbirth | date |
235 -- firstname | text | default ''::text
236 -- company | text | default ''::text
237 -- golfhandicap | integer |
238 -- lastname | text | default ''::text
239 -- preferred | text | default ''::text
241 -- jobtitle | text | default ''::text
242 -- office | text | default ''::text
243 -- creatorid | text | default ''::text
244 -- lastmodified | date |
245 -- department | text | default ''::text
246 -- spouse | text | default ''::text
247 -- lastvalidated | date |
249 -- systemcontact | boolean | default false
250 -- scheduleplusid | text | default ''::text
251 -- sorton | text | default ''::text
252 -- initials | text | default ''::text
253 -- middlenames | text | default ''::text
254 -- namesuffix | text | default ''::text
255 -- mailout | boolean | default true
256 -- tempgroup | boolean | default false
258 CREATE OR REPLACE VIEW creditor_maintenance AS
259 SELECT creditor.creditorcode AS creditorcode, creditor.active AS creditor_active, creditor.name AS creditor_name,
260 payeename, dcstatementtext, dcremittanceemail, paymentstyle, enabledirectpayment, directpaymentenabledby,
261 bankdetails, bankdetailschangedby, chequespermonth, vchrentitytype, vchrentitycode, vchraccountcode,
262 vchrapprover, nonaccounting, acctcreditorcode, companycode,
264 pymtperson.persontitle AS pymtperson_title, pymtperson.firstname AS pymtperson_first, pymtperson.lastname AS pymtperson_last,
265 pymtperson.company AS pymt_company_name, pymtperson.jobtitle AS pymtperson_job,
266 pymt.address AS pymt_address, pymt.city AS pymt_city, pymt.state AS pymt_state, pymt.country AS pymt_country, pymt.zip AS pymt_zip,
267 busphone.number AS busphone_no, busphone.ccountrycode AS busphone_isd, busphone.cstdcode AS busphone_std,
268 get_entity_name( 'L', companycode ) AS creditor_entity_name
270 LEFT JOIN person pymtperson ON creditor.paymentcontact = pymtperson.personcode
271 LEFT JOIN postaldetail pymt ON creditor.paymentcontact = pymt.personcode AND pymt.postaltype = 'PYMT'
272 LEFT JOIN phonedetail busphone ON creditor.paymentcontact = busphone.personcode AND busphone.phonetype = 'BUS' ;
274 CREATE or REPLACE RULE creditor_maintenance_insert AS ON INSERT TO creditor_maintenance
277 INSERT INTO person ( personcode, persontitle, firstname, lastname, company, jobtitle )
279 COALESCE( NEW.paymentcontact, nextval('person_personcode_seq')),
280 COALESCE( NEW.pymtperson_title, '' ),
281 COALESCE( NEW.pymtperson_first, ''),
282 COALESCE( NEW.pymtperson_last, '' ),
283 COALESCE( NEW.pymt_company_name, NEW.creditor_name ),
284 COALESCE( NEW.pymtperson_job, '')
286 INSERT INTO postaldetail ( personcode, postaltype, address, city, state, country, zip )
288 COALESCE( NEW.paymentcontact, currval('person_personcode_seq')), 'PYMT',
289 COALESCE( NEW.pymt_address, ''),
290 COALESCE( NEW.pymt_city, ''),
291 COALESCE( NEW.pymt_state, ''),
292 COALESCE( NEW.pymt_country, ''),
293 COALESCE( NEW.pymt_zip, '')
295 INSERT INTO phonedetail ( personcode, phonetype, number, ccountrycode, cstdcode )
297 COALESCE( NEW.paymentcontact, currval('person_personcode_seq')), 'BUS',
298 COALESCE( NEW.busphone_no, ''),
299 COALESCE( NEW.busphone_isd, ''),
300 COALESCE( NEW.busphone_std, '' )
302 INSERT INTO contact ( personcode, contacttype, systemcode )
304 COALESCE( NEW.paymentcontact, currval('person_personcode_seq')), 'CRED', TRUE
306 INSERT INTO creditor ( creditorcode, active, name,
307 payeename, dcstatementtext, dcremittanceemail, paymentstyle, enabledirectpayment, directpaymentenabledby,
308 bankdetails, bankdetailschangedby, chequespermonth, vchrentitytype, vchrentitycode, vchraccountcode,
309 vchrapprover, nonaccounting, acctcreditorcode, companycode, paymentcontact )
311 COALESCE( NEW.creditorcode, nextval('creditor_creditorcode_seq') ),
312 COALESCE( NEW.creditor_active, TRUE ),
313 COALESCE( NEW.creditor_name, 'An unnamed creditor' ),
314 NEW.payeename, NEW.dcstatementtext, NEW.dcremittanceemail, NEW.paymentstyle, NEW.enabledirectpayment, NEW.directpaymentenabledby,
315 NEW.bankdetails, NEW.bankdetailschangedby, NEW.chequespermonth, NEW.vchrentitytype, NEW.vchrentitycode, NEW.vchraccountcode,
316 NEW.vchrapprover, NEW.nonaccounting, NEW.acctcreditorcode,
317 COALESCE( NEW.companycode, 1 ),
318 COALESCE( NEW.paymentcontact, currval('person_personcode_seq'))
322 CREATE or REPLACE RULE creditor_maintenance_update AS ON UPDATE TO creditor_maintenance
326 SET persontitle = NEW.pymtperson_title,
327 firstname = NEW.pymtperson_first,
328 lastname = NEW.pymtperson_last,
329 company = NEW.pymt_company_name,
330 jobtitle = NEW.pymtperson_job
331 WHERE personcode = NEW.paymentcontact;
334 SET address = NEW.pymt_address,
335 city = NEW.pymt_city,
336 state = NEW.pymt_state,
337 country = NEW.pymt_country,
339 WHERE personcode = NEW.paymentcontact AND postaltype = 'PYMT';
342 SET number = NEW.busphone_no,
343 ccountrycode = NEW.busphone_isd,
344 cstdcode = NEW.busphone_std
345 WHERE personcode = NEW.paymentcontact AND phonetype = 'BUS';
348 SET active = NEW.creditor_active,
349 name = NEW.creditor_name,
350 payeename = NEW.payeename,
351 dcstatementtext = NEW.dcstatementtext,
352 dcremittanceemail = NEW.dcremittanceemail,
353 paymentstyle = NEW.paymentstyle,
354 enabledirectpayment = NEW.enabledirectpayment,
355 directpaymentenabledby = NEW.directpaymentenabledby,
356 bankdetails = NEW.bankdetails,
357 bankdetailschangedby = NEW.bankdetailschangedby,
358 chequespermonth = NEW.chequespermonth,
359 vchrentitytype = NEW.vchrentitytype,
360 vchrentitycode = NEW.vchrentitycode,
361 vchraccountcode = NEW.vchraccountcode,
362 vchrapprover = NEW.vchrapprover,
363 nonaccounting = NEW.nonaccounting,
364 acctcreditorcode = NEW.acctcreditorcode,
365 companycode = NEW.companycode,
366 paymentcontact = NEW.paymentcontact
367 WHERE creditorcode = OLD.creditorcode;