lsmb13-new Model
Schema public
Standard public schema
Table:
acc_trans
Structure of acc_trans
trans_id
integer
chart_id
integer
NOT NULL
REFERENCES
amount
numeric
transdate
date
DEFAULT ('now'::text)::date
source
text
cleared
boolean
DEFAULT false
fx_transaction
boolean
DEFAULT false
project_id
integer
memo
text
invoice_id
integer
entry_id
serial
PRIMARY KEY
Indexes on acc_trans
acc_trans_chart_id_key
chart_id
acc_trans_source_key
lower(source)
acc_trans_trans_id_key
trans_id
acc_trans_transdate_key
transdate
Table:
ap
Structure of ap
id
serial
PRIMARY KEY
invnumber
text
transdate
date
DEFAULT ('now'::text)::date
entity_id
integer
REFERENCES
Used to be customer_id, but customer is now metadata. You need to push to entity
taxincluded
boolean
DEFAULT false
amount
numeric
netamount
numeric
paid
numeric
datepaid
date
duedate
date
invoice
boolean
DEFAULT false
ordnumber
text
curr
character(3)
notes
text
person_id
integer
NOT NULL
REFERENCES
till
character varying(20)
quonumber
text
intnotes
text
department_id
integer
shipvia
text
language_code
character varying(6)
ponumber
text
shippingpoint
text
terms
smallint
Indexes on ap
ap_id_key
id
ap_invnumber_key
invnumber
ap_ordnumber_key
ordnumber
ap_quonumber_key
quonumber
ap_transdate_key
transdate
Table:
ar
Structure of ar
id
serial
PRIMARY KEY
invnumber
text
transdate
date
DEFAULT ('now'::text)::date
entity_id
integer
REFERENCES
Used to be customer_id, but customer is now metadata. You need to push to entity
taxincluded
boolean
amount
numeric
netamount
numeric
paid
numeric
datepaid
date
duedate
date
invoice
boolean
DEFAULT false
shippingpoint
text
terms
smallint
notes
text
curr
character(3)
ordnumber
text
person_id
integer
NOT NULL
REFERENCES
till
character varying(20)
quonumber
text
intnotes
text
department_id
integer
shipvia
text
language_code
character varying(6)
ponumber
text
Indexes on ar
ar_id_key
id
ar_invnumber_key
invnumber
ar_ordnumber_key
ordnumber
ar_quonumber_key
quonumber
ar_transdate_key
transdate
Table:
assembly
Structure of assembly
id
integer
PRIMARY KEY
parts_id
integer
PRIMARY KEY
qty
numeric
bom
boolean
adj
boolean
Indexes on assembly
assembly_id_key
id
Table:
audittrail
Structure of audittrail
trans_id
integer
tablename
text
reference
text
formname
text
action
text
transdate
timestamp without time zone
DEFAULT now()
person_id
integer
NOT NULL
REFERENCES
entry_id
bigserial
PRIMARY KEY
Indexes on audittrail
audittrail_trans_id_key
trans_id
Table:
business
Structure of business
id
serial
PRIMARY KEY
description
text
discount
numeric
Table:
chart
Structure of chart
id
serial
PRIMARY KEY
accno
text
NOT NULL
description
text
charttype
character(1)
DEFAULT 'A'::bpchar
category
character(1)
link
text
gifi_accno
text
contra
boolean
DEFAULT false
Indexes on chart
chart_category_key
category
chart_gifi_accno_key
gifi_accno
chart_id_key
id
chart_link_key
link
Tables referencing acc_trans via Foreign Key Constraints
Table:
company
Structure of company
id
serial
UNIQUE
NOT NULL
entity_id
integer
NOT NULL
REFERENCES
legal_name
text
PRIMARY KEY
entity_class_id
integer
NOT NULL
REFERENCES
primary_location_id
integer
PRIMARY KEY
REFERENCES
This is the location that should show up by default for any forms
tax_id
text
In the US this would be a EIN.
Constraints on company
company_legal_name_check
CHECK ((legal_name ~ '[[:alnum:]_]'::text))
Tables referencing company_to_contact via Foreign Key Constraints
Table:
company_to_entity
Structure of company_to_entity
company_id
integer
PRIMARY KEY
REFERENCES
entity_id
integer
PRIMARY KEY
REFERENCES
related_how
text
created
date
NOT NULL
DEFAULT ('now'::text)::date
Constraints on company_to_entity
company_to_entity_check
CHECK ((entity_id <> company_id))
Table:
company_to_location
Structure of company_to_location
location_id
integer
PRIMARY KEY
REFERENCES
company_id
integer
PRIMARY KEY
REFERENCES
Table:
country
Structure of country
id
serial
PRIMARY KEY
name
text
NOT NULL
short_name
text
NOT NULL
itu
text
The ITU Telecommunication Standardization Sector code for calling internationally. For example, the US is 1, Great Britain is 44
Constraints on country
country_name_check
CHECK ((name ~ '[[:alnum:]_]'::text))
country_short_name_check
CHECK ((short_name ~ '[[:alnum:]_]'::text))
Tables referencing location via Foreign Key Constraints
Table:
custom_field_catalog
Structure of custom_field_catalog
field_id
serial
PRIMARY KEY
table_id
integer
REFERENCES
field_name
text
Table:
custom_table_catalog
Structure of custom_table_catalog
table_id
serial
PRIMARY KEY
extends
text
table_name
text
Tables referencing custom_field_catalog via Foreign Key Constraints
Table:
customer
This is now a metadata table that holds information specific to customers. Source info is not part of the entity management
Structure of customer
id
serial
PRIMARY KEY
entity_id
integer
REFERENCES
This is the relationship between entities and customers
discount
numeric
taxincluded
boolean
DEFAULT false
creditlimit
numeric
terms
smallint
customernumber
character varying(32)
cc
text
bcc
text
business_id
integer
sic_code
character varying(6)
iban
character varying(34)
bic
character varying(11)
language_code
character varying(6)
pricegroup_id
integer
curr
character(3)
startdate
date
DEFAULT ('now'::text)::date
enddate
date
invoice_notes
text
Indexes on customer
customer_customernumber_key
customernumber
customer_id_key
id
Table:
customertax
Structure of customertax
customer_id
integer
PRIMARY KEY
chart_id
integer
PRIMARY KEY
Indexes on customertax
customer_customer_id_key
customer_id
Table:
defaults
Structure of defaults
setting_key
text
PRIMARY KEY
value
text
Table:
department
Structure of department
id
serial
PRIMARY KEY
description
text
role
character(1)
DEFAULT 'P'::bpchar
Indexes on department
department_id_key
id
Table:
dpt_trans
Structure of dpt_trans
trans_id
integer
PRIMARY KEY
department_id
integer
Table:
employee
Is a metadata table specific to employees
Structure of employee
id
serial
PRIMARY KEY
entity_id
integer
NOT NULL
REFERENCES
login
text
startdate
date
DEFAULT ('now'::text)::date
enddate
date
notes
text
role
character varying(20)
sales
boolean
DEFAULT false
ssn
character varying(20)
iban
character varying(34)
bic
character varying(11)
managerid
integer
employeenumber
character varying(32)
dob
date
Table:
entity
The primary entity table to map to all contacts
Structure of entity
id
serial
PRIMARY KEY
name
text
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
entity_class
integer
NOT NULL
REFERENCES
Constraints on entity
entity_name_check
CHECK ((name ~ '[[:alnum:]_]'::text))
Tables referencing ap via Foreign Key Constraints
Table:
entity_class
Defines the class type such as vendor, customer, contact, employee
Structure of entity_class
id
serial
PRIMARY KEY
The first 7 values are reserved and permanent
class
text
NOT NULL
active
boolean
NOT NULL
DEFAULT true
Constraints on entity_class
entity_class_class_check
CHECK (("class" ~ '[[:alnum:]_]'::text))
Tables referencing company via Foreign Key Constraints
Table:
entity_class_to_entity
Relation builder for classes to entity
Structure of entity_class_to_entity
entity_class_id
integer
PRIMARY KEY
REFERENCES
entity_id
integer
PRIMARY KEY
REFERENCES
Table:
entity_other_name
Similar to company_other_name, a person may be jd, Joshua Drake, linuxpoet... all are the same person.
Structure of entity_other_name
entity_id
integer
PRIMARY KEY
REFERENCES
other_name
text
PRIMARY KEY
Constraints on entity_other_name
entity_other_name_other_name_check
CHECK ((other_name ~ '[[:alnum:]_]'::text))
Table:
exchangerate
Structure of exchangerate
curr
character(3)
PRIMARY KEY
transdate
date
PRIMARY KEY
buy
numeric
sell
numeric
Indexes on exchangerate
exchangerate_ct_key
curr, transdate
Table:
gifi
Structure of gifi
accno
text
PRIMARY KEY
description
text
Table:
gl
Structure of gl
id
serial
PRIMARY KEY
reference
text
description
text
transdate
date
DEFAULT ('now'::text)::date
person_id
integer
REFERENCES
notes
text
department_id
integer
Indexes on gl
gl_description_key
lower(description)
gl_id_key
id
gl_reference_key
reference
gl_transdate_key
transdate
Table:
inventory
Structure of inventory
warehouse_id
integer
parts_id
integer
trans_id
integer
orderitems_id
integer
qty
numeric
shippingdate
date
person_id
integer
NOT NULL
REFERENCES
entry_id
serial
PRIMARY KEY
Table:
invoice
Structure of invoice
id
serial
PRIMARY KEY
trans_id
integer
parts_id
integer
description
text
qty
integer
allocated
integer
sellprice
numeric
fxsellprice
numeric
discount
real
assemblyitem
boolean
DEFAULT false
unit
character varying(5)
project_id
integer
deliverydate
date
serialnumber
text
notes
text
Indexes on invoice
invoice_id_key
id
invoice_trans_id_key
trans_id
Table:
jcitems
Structure of jcitems
id
serial
PRIMARY KEY
project_id
integer
parts_id
integer
description
text
qty
numeric
allocated
numeric
sellprice
numeric
fxsellprice
numeric
serialnumber
text
checkedin
timestamp with time zone
checkedout
timestamp with time zone
person_id
integer
NOT NULL
REFERENCES
notes
text
Indexes on jcitems
jcitems_id_key
id
Table:
language
Structure of language
code
character varying(6)
PRIMARY KEY
description
text
Table:
location
Structure of location
id
serial
PRIMARY KEY
line_one
text
NOT NULL
line_two
text
line_three
text
city_province
text
NOT NULL
country_id
integer
NOT NULL
REFERENCES
mail_code
text
NOT NULL
Constraints on location
location_city_province_check
CHECK ((city_province ~ '[[:alnum:]_]'::text))
location_line_one_check
CHECK ((line_one ~ '[[:alnum:]_]'::text))
location_mail_code_check
CHECK ((mail_code ~ '[[:alnum:]_]'::text))
Tables referencing company via Foreign Key Constraints
Table:
makemodel
Structure of makemodel
parts_id
integer
PRIMARY KEY
make
text
model
text
Indexes on makemodel
makemodel_make_key
lower(make)
makemodel_model_key
lower(model)
makemodel_parts_id_key
parts_id
Table:
oe
Structure of oe
id
serial
PRIMARY KEY
ordnumber
text
transdate
date
DEFAULT ('now'::text)::date
entity_id
integer
NOT NULL
REFERENCES
amount
numeric
netamount
numeric
reqdate
date
taxincluded
boolean
shippingpoint
text
notes
text
curr
character(3)
person_id
integer
NOT NULL
REFERENCES
closed
boolean
DEFAULT false
quotation
boolean
DEFAULT false
quonumber
text
intnotes
text
department_id
integer
shipvia
text
language_code
character varying(6)
ponumber
text
terms
smallint
oe_class_id
integer
NOT NULL
REFERENCES
Indexes on oe
oe_id_key
id
oe_ordnumber_key
ordnumber
oe_transdate_key
transdate
Table:
oe_class
This could probably be done better. But I need to remove the customer_id/vendor_id relationship and instead rely on a classification
Structure of oe_class
id
smallint
UNIQUE
oe_class
text
PRIMARY KEY
Constraints on oe_class
oe_class_id_check
CHECK (((id = 1) OR (id = 2)))
Tables referencing oe via Foreign Key Constraints
Table:
orderitems
Structure of orderitems
id
serial
PRIMARY KEY
trans_id
integer
parts_id
integer
description
text
qty
numeric
sellprice
numeric
discount
numeric
unit
character varying(5)
project_id
integer
reqdate
date
ship
numeric
serialnumber
text
notes
text
Indexes on orderitems
orderitems_id_key
id
orderitems_trans_id_key
trans_id
Table:
parts
Structure of parts
id
serial
PRIMARY KEY
partnumber
text
description
text
unit
character varying(5)
listprice
numeric
sellprice
numeric
lastcost
numeric
priceupdate
date
DEFAULT ('now'::text)::date
weight
numeric
onhand
numeric
notes
text
makemodel
boolean
DEFAULT false
assembly
boolean
DEFAULT false
alternate
boolean
DEFAULT false
rop
real
inventory_accno_id
integer
income_accno_id
integer
expense_accno_id
integer
bin
text
obsolete
boolean
DEFAULT false
bom
boolean
DEFAULT false
image
text
drawing
text
microfiche
text
partsgroup_id
integer
project_id
integer
avgcost
numeric
Indexes on parts
parts_description_key
lower(description)
parts_id_key
id
parts_partnumber_key
lower(partnumber)
Tables referencing partstax via Foreign Key Constraints
Table:
partscustomer
Structure of partscustomer
parts_id
integer
customer_id
integer
pricegroup_id
integer
pricebreak
numeric
sellprice
numeric
validfrom
date
validto
date
curr
character(3)
entry_id
serial
PRIMARY KEY
Table:
partsgroup
Structure of partsgroup
id
serial
PRIMARY KEY
partsgroup
text
Indexes on partsgroup
partsgroup_id_key
id
Table:
partstax
Structure of partstax
parts_id
integer
PRIMARY KEY
REFERENCES
chart_id
integer
PRIMARY KEY
REFERENCES
taxcategory_id
integer
REFERENCES
Indexes on partstax
partstax_parts_id_key
parts_id
Table:
partsvendor
Structure of partsvendor
entity_id
integer
NOT NULL
REFERENCES
parts_id
integer
partnumber
text
leadtime
smallint
lastcost
numeric
curr
character(3)
entry_id
serial
PRIMARY KEY
Indexes on partsvendor
partsvendor_parts_id_key
parts_id
Table:
person
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.
Structure of person
id
serial
PRIMARY KEY
entity_id
integer
NOT NULL
REFERENCES
salutation_id
integer
REFERENCES
first_name
text
NOT NULL
middle_name
text
last_name
text
NOT NULL
primary_location_id
integer
REFERENCES
Constraints on person
person_first_name_check
CHECK ((first_name ~ '[[:alnum:]_]'::text))
person_last_name_check
CHECK ((last_name ~ '[[:alnum:]_]'::text))
Tables referencing ap via Foreign Key Constraints
Table:
person_to_company
Structure of person_to_company
location_id
integer
PRIMARY KEY
REFERENCES
person_id
integer
PRIMARY KEY
REFERENCES
Table:
person_to_entity
Structure of person_to_entity
person_id
integer
PRIMARY KEY
REFERENCES
entity_id
integer
PRIMARY KEY
REFERENCES
related_how
text
created
date
NOT NULL
DEFAULT ('now'::text)::date
Constraints on person_to_entity
person_to_entity_check
CHECK ((entity_id <> person_id))
Table:
pricegroup
Structure of pricegroup
id
serial
PRIMARY KEY
pricegroup
text
Indexes on pricegroup
pricegroup_id_key
id
pricegroup_pricegroup_key
pricegroup
Table:
project
Structure of project
id
serial
PRIMARY KEY
projectnumber
text
description
text
startdate
date
enddate
date
parts_id
integer
production
numeric
completed
numeric
customer_id
integer
Indexes on project
project_id_key
id
Table:
recurring
Structure of recurring
id
integer
PRIMARY KEY
reference
text
startdate
date
nextdate
date
enddate
date
repeat
smallint
unit
character varying(6)
howmany
integer
payment
boolean
DEFAULT false
Table:
recurringemail
Structure of recurringemail
id
integer
PRIMARY KEY
formname
text
format
text
message
text
Table:
recurringprint
Structure of recurringprint
id
integer
PRIMARY KEY
formname
text
format
text
printer
text
Table:
salutation
Structure of salutation
id
serial
UNIQUE
NOT NULL
salutation
text
PRIMARY KEY
Tables referencing person via Foreign Key Constraints
Table:
shipto
Structure of shipto
trans_id
integer
shiptoname
character varying(64)
shiptoaddress1
character varying(32)
shiptoaddress2
character varying(32)
shiptocity
character varying(32)
shiptostate
character varying(32)
shiptozipcode
character varying(10)
shiptocountry
character varying(32)
shiptocontact
character varying(64)
shiptophone
character varying(20)
shiptofax
character varying(20)
shiptoemail
text
entry_id
serial
PRIMARY KEY
Indexes on shipto
shipto_trans_id_key
trans_id
Table:
sic
Structure of sic
code
character varying(6)
PRIMARY KEY
sictype
character(1)
description
text
Table:
status
Structure of status
trans_id
integer
PRIMARY KEY
formname
text
printed
boolean
DEFAULT false
emailed
boolean
DEFAULT false
spoolfile
text
Indexes on status
status_trans_id_key
trans_id
Table:
tax
Structure of tax
chart_id
integer
PRIMARY KEY
REFERENCES
rate
numeric
taxnumber
text
validto
date
pass
integer
NOT NULL
taxmodule_id
integer
NOT NULL
DEFAULT 1
REFERENCES
Table:
taxcategory
Structure of taxcategory
taxcategory_id
serial
PRIMARY KEY
taxcategoryname
text
NOT NULL
taxmodule_id
integer
NOT NULL
REFERENCES
Tables referencing partstax via Foreign Key Constraints
Table:
taxmodule
Structure of taxmodule
taxmodule_id
serial
PRIMARY KEY
taxmodulename
text
NOT NULL
Tables referencing tax via Foreign Key Constraints
Table:
transactions
Structure of transactions
id
integer
PRIMARY KEY
table_name
text
Table:
translation
Structure of translation
trans_id
integer
PRIMARY KEY
language_code
character varying(6)
PRIMARY KEY
description
text
Indexes on translation
translation_trans_id_key
trans_id
Table:
vendor
Now a meta data table
Structure of vendor
id
serial
PRIMARY KEY
entity_id
integer
NOT NULL
REFERENCES
terms
smallint
taxincluded
boolean
DEFAULT false
vendornumber
character varying(32)
cc
text
bcc
text
gifi_accno
character varying(30)
business_id
integer
taxnumber
character varying(32)
sic_code
character varying(6)
discount
numeric
creditlimit
numeric
iban
character varying(34)
bic
character varying(11)
language_code
character varying(6)
pricegroup_id
integer
curr
character(3)
startdate
date
enddate
date
Indexes on vendor
vendor_id_key
id
vendor_vendornumber_key
vendornumber
Table:
vendortax
Structure of vendortax
vendor_id
integer
PRIMARY KEY
chart_id
integer
PRIMARY KEY
Table:
warehouse
Structure of warehouse
id
serial
PRIMARY KEY
description
text
Table:
yearend
Structure of yearend
trans_id
integer
PRIMARY KEY
transdate
date
add_custom_field( character varying, character varying, character varying )
add_custom_field( character varying, character varying, character varying )
Function Properties
Language
Return Type
PLPGSQL
boolean
DECLARE
table_name ALIAS FOR $1;
new_field_name ALIAS FOR $2;
field_datatype ALIAS FOR $3;
BEGIN
EXECUTE 'SELECT TABLE_ID FROM custom_table_catalog
WHERE extends = ''' || table_name || ''' ';
IF NOT FOUND THEN
BEGIN
INSERT INTO custom_table_catalog (extends)
VALUES (table_name);
EXECUTE 'CREATE TABLE custom_'||table_name ||
' (row_id INT PRIMARY KEY)';
EXCEPTION WHEN duplicate_table THEN
-- do nothing
END;
END IF;
EXECUTE 'INSERT INTO custom_field_catalog (field_name, table_id)
VALUES ( ''' || new_field_name ||''', (SELECT table_id FROM custom_table_catalog
WHERE extends = '''|| table_name || '''))';
EXECUTE 'ALTER TABLE custom_'||table_name || ' ADD COLUMN '
|| new_field_name || ' ' || field_datatype;
RETURN TRUE;
END;
avgcost( integer )
avgcost( integer )
Function Properties
Language
Return Type
PLPGSQL
double precision
DECLARE
v_cost float;
v_qty float;
v_parts_id alias for $1;
BEGIN
SELECT INTO v_cost, v_qty SUM(i.sellprice * i.qty), SUM(i.qty)
FROM invoice i
JOIN ap a ON (a.id = i.trans_id)
WHERE i.parts_id = v_parts_id;
IF v_cost IS NULL THEN
v_cost := 0;
END IF;
IF NOT v_qty IS NULL THEN
IF v_qty = 0 THEN
v_cost := 0;
ELSE
v_cost := v_cost/v_qty;
END IF;
END IF;
RETURN v_cost;
END;
check_department( )
check_department( )
Function Properties
Language
Return Type
PLPGSQL
"trigger"
declare
dpt_id int;
begin
if new.department_id = 0 then
delete from dpt_trans where trans_id = new.id;
return NULL;
end if;
select into dpt_id trans_id from dpt_trans where trans_id = new.id;
if dpt_id > 0 then
update dpt_trans set department_id = new.department_id where trans_id = dpt_id;
else
insert into dpt_trans (trans_id, department_id) values (new.id, new.department_id);
end if;
return NULL;
end;
check_inventory( )
check_inventory( )
Function Properties
Language
Return Type
PLPGSQL
"trigger"
declare
itemid int;
row_data inventory%rowtype;
begin
if not old.quotation then
for row_data in select * from inventory where trans_id = old.id loop
select into itemid id from orderitems where trans_id = old.id and id = row_data.orderitems_id;
if itemid is null then
delete from inventory where trans_id = old.id and orderitems_id = row_data.orderitems_id;
end if;
end loop;
end if;
return old;
end;
del_customer( )
del_customer( )
Function Properties
Language
Return Type
PLPGSQL
"trigger"
begin
delete from shipto where trans_id = old.id;
delete from customertax where customer_id = old.id;
delete from partscustomer where customer_id = old.id;
return NULL;
end;
del_department( )
del_department( )
Function Properties
Language
Return Type
PLPGSQL
"trigger"
begin
delete from dpt_trans where trans_id = old.id;
return NULL;
end;
del_exchangerate( )
del_exchangerate( )
Function Properties
Language
Return Type
PLPGSQL
"trigger"
declare
t_transdate date;
t_curr char(3);
t_id int;
d_curr text;
begin
select into d_curr substr(value,1,3) from defaults where setting_key = 'curr';
if TG_RELNAME = 'ar' then
select into t_curr, t_transdate curr, transdate from ar where id = old.id;
end if;
if TG_RELNAME = 'ap' then
select into t_curr, t_transdate curr, transdate from ap where id = old.id;
end if;
if TG_RELNAME = 'oe' then
select into t_curr, t_transdate curr, transdate from oe where id = old.id;
end if;
if d_curr != t_curr then
select into t_id a.id from acc_trans ac
join ar a on (a.id = ac.trans_id)
where a.curr = t_curr
and ac.transdate = t_transdate
except select a.id from ar a where a.id = old.id
union
select a.id from acc_trans ac
join ap a on (a.id = ac.trans_id)
where a.curr = t_curr
and ac.transdate = t_transdate
except select a.id from ap a where a.id = old.id
union
select o.id from oe o
where o.curr = t_curr
and o.transdate = t_transdate
except select o.id from oe o where o.id = old.id;
if not found then
delete from exchangerate where curr = t_curr and transdate = t_transdate;
end if;
end if;
return old;
end;
del_recurring( )
del_recurring( )
Function Properties
Language
Return Type
PLPGSQL
"trigger"
BEGIN
DELETE FROM recurring WHERE id = old.id;
DELETE FROM recurringemail WHERE id = old.id;
DELETE FROM recurringprint WHERE id = old.id;
RETURN NULL;
END;
del_vendor( )
del_vendor( )
Function Properties
Language
Return Type
PLPGSQL
"trigger"
begin
delete from shipto where trans_id = old.id;
delete from vendortax where vendor_id = old.id;
delete from partsvendor where vendor_id = old.id;
return NULL;
end;
del_yearend( )
del_yearend( )
Function Properties
Language
Return Type
PLPGSQL
"trigger"
begin
delete from yearend where trans_id = old.id;
return NULL;
end;
drop_custom_field( character varying, character varying )
drop_custom_field( character varying, character varying )
Function Properties
Language
Return Type
PLPGSQL
boolean
DECLARE
table_name ALIAS FOR $1;
custom_field_name ALIAS FOR $2;
BEGIN
DELETE FROM custom_field_catalog
WHERE field_name = custom_field_name AND
table_id = (SELECT table_id FROM custom_table_catalog
WHERE extends = table_name);
EXECUTE 'ALTER TABLE custom_' || table_name ||
' DROP COLUMN ' || custom_field_name;
RETURN TRUE;
END;
lastcost( integer )
lastcost( integer )
Function Properties
Language
Return Type
PLPGSQL
double precision
DECLARE
v_cost float;
v_parts_id alias for $1;
BEGIN
SELECT INTO v_cost sellprice FROM invoice i
JOIN ap a ON (a.id = i.trans_id)
WHERE i.parts_id = v_parts_id
ORDER BY a.transdate desc, a.id desc
LIMIT 1;
IF v_cost IS NULL THEN
v_cost := 0;
END IF;
RETURN v_cost;
END;
trigger_parts_short( )
trigger_parts_short( )
Function Properties
Language
Return Type
PLPGSQL
"trigger"
BEGIN
IF NEW.onhand >= NEW.rop THEN
NOTIFY parts_short;
END IF;
RETURN NEW;
END;
update_user( integer, text )
update_user( integer, text )
Function Properties
Language
Return Type
SQL
integer
Takes int4 which is users.id and text which is username. Will update username based on id. Username is unique
UPDATE users SET username = '$2' WHERE id = $1;
SELECT 1;