From d4585147ff509e608a6a7ff8bc6f4e5df84ec243 Mon Sep 17 00:00:00 2001 From: David Fetter Date: Thu, 9 Aug 2018 21:58:14 -0700 Subject: [PATCH] VARCHAR(n) is not useful as a data type Use TEXT instead. --- schema.sql | 110 +++++++++++++++++----------------- usda_sr28.sql | 160 +++++++++++++++++++++++++------------------------- 2 files changed, 135 insertions(+), 135 deletions(-) diff --git a/schema.sql b/schema.sql index 86945ee..21f747c 100644 --- a/schema.sql +++ b/schema.sql @@ -2,12 +2,12 @@ * Source Code File (SRC_CD.txt) */ CREATE TABLE src_cd ( - src_cd varchar(2) NOT NULL, - srccd_desc varchar(60) NOT NULL, + src_cd text NOT NULL, + srccd_desc text NOT NULL, PRIMARY KEY (src_cd) ); -COMMENT ON TABLE src_cd IS 'Contains codes indicating the type of data (analytical, calculated, assumed zero, and so on) in the Nutrient Data table. +COMMENT ON TABLE src_cd IS 'Contains codes indicating the type of data (analytical, calculated, assumed zero, and so on) in the Nutrient Data table. To improve the usability of the database and to provide values for the FNDDS, NDL staff imputed nutrient values for a number of proximate components, total dietary fiber, total sugar, and vitamin and mineral values.'; COMMENT ON COLUMN src_cd.src_cd IS 'A 2-digit code indicating type of data.'; @@ -18,8 +18,8 @@ COMMENT ON COLUMN src_cd.srccd_desc IS 'Description of source code that identifi * Data Derivation Code Description File (DERIV_CD.txt) */ CREATE TABLE deriv_cd ( - deriv_cd varchar(4) NOT NULL, - deriv_desc varchar(120) NOT NULL, + deriv_cd text NOT NULL, + deriv_desc text NOT NULL, PRIMARY KEY (deriv_cd) ); @@ -33,15 +33,15 @@ COMMENT ON COLUMN deriv_cd.deriv_desc IS 'Description of derivation code giving * Sources of Data File (DATA_SRC.txt) */ CREATE TABLE data_src ( - datasrc_id varchar(6) NOT NULL, - authors varchar(255), - title varchar(255) NOT NULL, - year varchar(4), - journal varchar(135), - vol_city varchar(16), - issue_state varchar(5), - start_page varchar(5), - end_page varchar(5), + datasrc_id text NOT NULL, + authors text, + title text NOT NULL, + year text, + journal text, + vol_city text, + issue_state text, + start_page text, + end_page text, PRIMARY KEY (datasrc_id) ); @@ -61,11 +61,11 @@ COMMENT ON COLUMN data_src.end_page IS 'Ending page number of article/document.' * Footnote File (FOOTNOTE.txt) */ CREATE TABLE footnote ( - ndb_no varchar(5) NOT NULL, - footnt_no varchar(4) NOT NULL, - footnt_typ varchar(1) NOT NULL, - nutr_no varchar(3), - footnt_txt varchar(200) NOT NULL + ndb_no text NOT NULL, + footnt_no text NOT NULL, + footnt_typ text NOT NULL, + nutr_no text, + footnt_txt text NOT NULL ); COMMENT ON TABLE footnote IS 'Contains additional information about the food item, household weight, and nutrient value.'; @@ -93,8 +93,8 @@ COMMENT ON COLUMN footnote.footnt_txt IS 'Footnote text.'; * LanguaL Factors Description File (LANGDESC.txt) */ CREATE TABLE langdesc ( - factor_code varchar(5) NOT NULL, - description varchar(140) NOT NULL, + factor_code text NOT NULL, + description text NOT NULL, PRIMARY KEY (factor_code) ); @@ -110,8 +110,8 @@ thesaurus.'; * Food Group Description File (FD_GROUP.txt) */ CREATE TABLE fd_group( - fdgrp_cd varchar(4) NOT NULL, - fdgrp_desc varchar(60) NOT NULL, + fdgrp_cd text NOT NULL, + fdgrp_desc text NOT NULL, PRIMARY KEY (fdgrp_cd) ); @@ -127,16 +127,16 @@ COMMENT ON COLUMN fd_group.fdgrp_desc IS 'Name of food group.'; * Food Description File (FOOD_DES.txt) */ CREATE TABLE food_des ( - ndb_no varchar(5) NOT NULL, - fdgrp_cd varchar(4) NOT NULL REFERENCES fd_group (fdgrp_cd), - long_desc varchar(200) NOT NULL, - shrt_desc varchar(60) NOT NULL, - comname varchar(100), - manufacname varchar(65), - survey varchar(1), - ref_desc varchar(135), + ndb_no text NOT NULL, + fdgrp_cd text NOT NULL REFERENCES fd_group (fdgrp_cd), + long_desc text NOT NULL, + shrt_desc text NOT NULL, + comname text, + manufacname text, + survey text, + ref_desc text, refuse numeric(2), - sciname varchar(65), + sciname text, n_factor numeric(4, 2), pro_factor numeric(4, 2), fat_factor numeric(4, 2), @@ -187,11 +187,11 @@ COMMENT ON COLUMN food_des.cho_factor IS 'Factor for calculating calories from c * Nutrient Definition File (NUTR_DEF.txt) */ CREATE TABLE nutr_def ( - nutr_no varchar(3) NOT NULL, - units varchar(7) NOT NULL, - tagname varchar(20), - nutrdesc varchar(60) NOT NULL, - num_dec varchar(1) NOT NULL, + nutr_no text NOT NULL, + units text NOT NULL, + tagname text, + nutrdesc text NOT NULL, + num_dec text NOT NULL, sr_order numeric(6) NOT NULL, PRIMARY KEY (nutr_no) ); @@ -213,24 +213,24 @@ various reports produced from SR.'; * Nutrient Data File (NUT_DATA.txt) */ CREATE TABLE nut_data( - ndb_no varchar(5) NOT NULL REFERENCES food_des (ndb_no), - nutr_no varchar(3) NOT NULL REFERENCES nutr_def (nutr_no), + ndb_no text NOT NULL REFERENCES food_des (ndb_no), + nutr_no text NOT NULL REFERENCES nutr_def (nutr_no), nutr_val numeric(10, 3) NOT NULL, num_data_pts numeric(5, 0) NOT NULL, std_error numeric(8, 3), - src_cd varchar(2) NOT NULL, - deriv_cd varchar(4), - ref_ndb_no varchar(5), - add_nutr_mark varchar(1), + src_cd text NOT NULL, + deriv_cd text, + ref_ndb_no text, + add_nutr_mark text, num_studies numeric(2), min numeric(10, 3), max numeric(10, 3), df numeric(4), low_eb numeric(10, 3), up_eb numeric(10, 3), - stat_cmt varchar(10), - addmod_date varchar(10), - cc varchar(1), + stat_cmt text, + addmod_date text, + cc text, PRIMARY KEY (ndb_no, nutr_no) ); @@ -281,10 +281,10 @@ release, but is planned for future releases.'; * Weight File (WEIGHT.txt) */ CREATE TABLE weight ( - ndb_no varchar(5) NOT NULL REFERENCES food_des (ndb_no), - seq varchar(2) NOT NULL, + ndb_no text NOT NULL REFERENCES food_des (ndb_no), + seq text NOT NULL, amount numeric(6, 3) NOT NULL, - msre_desc varchar(84) NOT NULL, + msre_desc text NOT NULL, gm_wgt numeric(7, 1) NOT NULL, num_data_pts numeric(4, 0), std_dev numeric(7, 3), @@ -308,8 +308,8 @@ COMMENT ON COLUMN weight.std_dev IS 'Standard deviation.'; * LanguaL Factor File (LANGUAL.txt) */ CREATE TABLE langual ( - ndb_no varchar(5) NOT NULL REFERENCES food_des (ndb_no), - factor_code varchar(5) NOT NULL REFERENCES langdesc (factor_code), + ndb_no text NOT NULL REFERENCES food_des (ndb_no), + factor_code text NOT NULL REFERENCES langdesc (factor_code), PRIMARY KEY (ndb_no, factor_code) ); @@ -326,9 +326,9 @@ COMMENT ON COLUMN langual.factor_code IS 'The LanguaL factor from the Thesaurus. * Sources of Data Link File (DATSRCLN.txt) */ CREATE TABLE datsrcln ( - ndb_no varchar(5) NOT NULL REFERENCES food_des (ndb_no), - nutr_no varchar(3) NOT NULL REFERENCES nutr_def (nutr_no), - datasrc_id varchar(6) NOT NULL REFERENCES data_src (datasrc_id), + ndb_no text NOT NULL REFERENCES food_des (ndb_no), + nutr_no text NOT NULL REFERENCES nutr_def (nutr_no), + datasrc_id text NOT NULL REFERENCES data_src (datasrc_id), PRIMARY KEY (ndb_no, nutr_no, datasrc_id) ); @@ -339,4 +339,4 @@ COMMENT ON COLUMN datsrcln.ndb_no IS '5-digit Nutrient Databank number that uniq identifies a food item. If this field is defined as numeric, the leading zero will be lost.'; COMMENT ON COLUMN datsrcln.nutr_no IS 'Unique 3-digit identifier code for a nutrient.'; -COMMENT ON COLUMN datsrcln.datasrc_id IS 'Unique ID identifying the reference/source.'; \ No newline at end of file +COMMENT ON COLUMN datsrcln.datasrc_id IS 'Unique ID identifying the reference/source.'; diff --git a/usda_sr28.sql b/usda_sr28.sql index ad41399..16550fc 100644 --- a/usda_sr28.sql +++ b/usda_sr28.sql @@ -10,14 +10,14 @@ SET check_function_bodies = false; SET client_min_messages = warning; -- --- Name: plpgsql; Type: EXTENSION; Schema: -; Owner: +-- Name: plpgsql; Type: EXTENSION; Schema: -; Owner: -- CREATE EXTENSION IF NOT EXISTS plpgsql WITH SCHEMA pg_catalog; -- --- Name: EXTENSION plpgsql; Type: COMMENT; Schema: -; Owner: +-- Name: EXTENSION plpgsql; Type: COMMENT; Schema: -; Owner: -- COMMENT ON EXTENSION plpgsql IS 'PL/pgSQL procedural language'; @@ -30,19 +30,19 @@ SET default_tablespace = ''; SET default_with_oids = false; -- --- Name: data_src; Type: TABLE; Schema: public; Owner: postgres; Tablespace: +-- Name: data_src; Type: TABLE; Schema: public; Owner: postgres; Tablespace: -- CREATE TABLE data_src ( - datasrc_id character varying(6) NOT NULL, - authors character varying(255), - title character varying(255) NOT NULL, - year character varying(4), - journal character varying(135), - vol_city character varying(16), - issue_state character varying(5), - start_page character varying(5), - end_page character varying(5) + datasrc_id text NOT NULL, + authors text, + title text NOT NULL, + year text, + journal text, + vol_city text, + issue_state text, + start_page text, + end_page text ); @@ -119,13 +119,13 @@ COMMENT ON COLUMN data_src.end_page IS 'Ending page number of article/document.' -- --- Name: datsrcln; Type: TABLE; Schema: public; Owner: postgres; Tablespace: +-- Name: datsrcln; Type: TABLE; Schema: public; Owner: postgres; Tablespace: -- CREATE TABLE datsrcln ( - ndb_no character varying(5) NOT NULL, - nutr_no character varying(3) NOT NULL, - datasrc_id character varying(6) NOT NULL + ndb_no text NOT NULL, + nutr_no text NOT NULL, + datasrc_id text NOT NULL ); @@ -164,12 +164,12 @@ COMMENT ON COLUMN datsrcln.datasrc_id IS 'Unique ID identifying the reference/so -- --- Name: deriv_cd; Type: TABLE; Schema: public; Owner: postgres; Tablespace: +-- Name: deriv_cd; Type: TABLE; Schema: public; Owner: postgres; Tablespace: -- CREATE TABLE deriv_cd ( - deriv_cd character varying(4) NOT NULL, - deriv_desc character varying(120) NOT NULL + deriv_cd text NOT NULL, + deriv_desc text NOT NULL ); @@ -198,12 +198,12 @@ COMMENT ON COLUMN deriv_cd.deriv_desc IS 'Description of derivation code giving -- --- Name: fd_group; Type: TABLE; Schema: public; Owner: postgres; Tablespace: +-- Name: fd_group; Type: TABLE; Schema: public; Owner: postgres; Tablespace: -- CREATE TABLE fd_group ( - fdgrp_cd character varying(4) NOT NULL, - fdgrp_desc character varying(60) NOT NULL + fdgrp_cd text NOT NULL, + fdgrp_desc text NOT NULL ); @@ -234,20 +234,20 @@ COMMENT ON COLUMN fd_group.fdgrp_desc IS 'Name of food group.'; -- --- Name: food_des; Type: TABLE; Schema: public; Owner: postgres; Tablespace: +-- Name: food_des; Type: TABLE; Schema: public; Owner: postgres; Tablespace: -- CREATE TABLE food_des ( - ndb_no character varying(5) NOT NULL, - fdgrp_cd character varying(4) NOT NULL, - long_desc character varying(200) NOT NULL, - shrt_desc character varying(60) NOT NULL, - comname character varying(100), - manufacname character varying(65), - survey character varying(1), - ref_desc character varying(135), + ndb_no text NOT NULL, + fdgrp_cd text NOT NULL, + long_desc text NOT NULL, + shrt_desc text NOT NULL, + comname text, + manufacname text, + survey text, + ref_desc text, refuse numeric(2,0), - sciname character varying(65), + sciname text, n_factor numeric(4,2), pro_factor numeric(4,2), fat_factor numeric(4,2), @@ -384,15 +384,15 @@ COMMENT ON COLUMN food_des.cho_factor IS 'Factor for calculating calories from c -- --- Name: footnote; Type: TABLE; Schema: public; Owner: postgres; Tablespace: +-- Name: footnote; Type: TABLE; Schema: public; Owner: postgres; Tablespace: -- CREATE TABLE footnote ( - ndb_no character varying(5) NOT NULL, - footnt_no character varying(4) NOT NULL, - footnt_typ character varying(1) NOT NULL, - nutr_no character varying(3), - footnt_txt character varying(200) NOT NULL + ndb_no text NOT NULL, + footnt_no text NOT NULL, + footnt_typ text NOT NULL, + nutr_no text, + footnt_txt text NOT NULL ); @@ -454,12 +454,12 @@ COMMENT ON COLUMN footnote.footnt_txt IS 'Footnote text.'; -- --- Name: langdesc; Type: TABLE; Schema: public; Owner: postgres; Tablespace: +-- Name: langdesc; Type: TABLE; Schema: public; Owner: postgres; Tablespace: -- CREATE TABLE langdesc ( - factor_code character varying(5) NOT NULL, - description character varying(140) NOT NULL + factor_code text NOT NULL, + description text NOT NULL ); @@ -491,12 +491,12 @@ thesaurus.'; -- --- Name: langual; Type: TABLE; Schema: public; Owner: postgres; Tablespace: +-- Name: langual; Type: TABLE; Schema: public; Owner: postgres; Tablespace: -- CREATE TABLE langual ( - ndb_no character varying(5) NOT NULL, - factor_code character varying(5) NOT NULL + ndb_no text NOT NULL, + factor_code text NOT NULL ); @@ -528,28 +528,28 @@ COMMENT ON COLUMN langual.factor_code IS 'The LanguaL factor from the Thesaurus. -- --- Name: nut_data; Type: TABLE; Schema: public; Owner: postgres; Tablespace: +-- Name: nut_data; Type: TABLE; Schema: public; Owner: postgres; Tablespace: -- CREATE TABLE nut_data ( - ndb_no character varying(5) NOT NULL, - nutr_no character varying(3) NOT NULL, + ndb_no text NOT NULL, + nutr_no text NOT NULL, nutr_val numeric(10,3) NOT NULL, num_data_pts numeric(5,0) NOT NULL, std_error numeric(8,3), - src_cd character varying(2) NOT NULL, - deriv_cd character varying(4), - ref_ndb_no character varying(5), - add_nutr_mark character varying(1), + src_cd text NOT NULL, + deriv_cd text, + ref_ndb_no text, + add_nutr_mark text, num_studies numeric(2,0), min numeric(10,3), max numeric(10,3), df numeric(4,0), low_eb numeric(10,3), up_eb numeric(10,3), - stat_cmt character varying(10), - addmod_date character varying(10), - cc character varying(1) + stat_cmt text, + addmod_date text, + cc text ); @@ -711,15 +711,15 @@ release, but is planned for future releases.'; -- --- Name: nutr_def; Type: TABLE; Schema: public; Owner: postgres; Tablespace: +-- Name: nutr_def; Type: TABLE; Schema: public; Owner: postgres; Tablespace: -- CREATE TABLE nutr_def ( - nutr_no character varying(3) NOT NULL, - units character varying(7) NOT NULL, - tagname character varying(20), - nutrdesc character varying(60) NOT NULL, - num_dec character varying(1) NOT NULL, + nutr_no text NOT NULL, + units text NOT NULL, + tagname text, + nutrdesc text NOT NULL, + num_dec text NOT NULL, sr_order numeric(6,0) NOT NULL ); @@ -781,12 +781,12 @@ various reports produced from SR.'; -- --- Name: src_cd; Type: TABLE; Schema: public; Owner: postgres; Tablespace: +-- Name: src_cd; Type: TABLE; Schema: public; Owner: postgres; Tablespace: -- CREATE TABLE src_cd ( - src_cd character varying(2) NOT NULL, - srccd_desc character varying(60) NOT NULL + src_cd text NOT NULL, + srccd_desc text NOT NULL ); @@ -796,7 +796,7 @@ ALTER TABLE public.src_cd OWNER TO postgres; -- Name: TABLE src_cd; Type: COMMENT; Schema: public; Owner: postgres -- -COMMENT ON TABLE src_cd IS 'Contains codes indicating the type of data (analytical, calculated, assumed zero, and so on) in the Nutrient Data table. +COMMENT ON TABLE src_cd IS 'Contains codes indicating the type of data (analytical, calculated, assumed zero, and so on) in the Nutrient Data table. To improve the usability of the database and to provide values for the FNDDS, NDL staff imputed nutrient values for a number of proximate components, total dietary fiber, total sugar, and vitamin and mineral values.'; @@ -816,14 +816,14 @@ COMMENT ON COLUMN src_cd.srccd_desc IS 'Description of source code that identifi -- --- Name: weight; Type: TABLE; Schema: public; Owner: postgres; Tablespace: +-- Name: weight; Type: TABLE; Schema: public; Owner: postgres; Tablespace: -- CREATE TABLE weight ( - ndb_no character varying(5) NOT NULL, - seq character varying(2) NOT NULL, + ndb_no text NOT NULL, + seq text NOT NULL, amount numeric(6,3) NOT NULL, - msre_desc character varying(84) NOT NULL, + msre_desc text NOT NULL, gm_wgt numeric(7,1) NOT NULL, num_data_pts numeric(4,0), std_dev numeric(7,3) @@ -989305,7 +989305,7 @@ COPY weight (ndb_no, seq, amount, msre_desc, gm_wgt, num_data_pts, std_dev) FROM -- --- Name: data_src_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: +-- Name: data_src_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: -- ALTER TABLE ONLY data_src @@ -989313,7 +989313,7 @@ ALTER TABLE ONLY data_src -- --- Name: datsrcln_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: +-- Name: datsrcln_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: -- ALTER TABLE ONLY datsrcln @@ -989321,7 +989321,7 @@ ALTER TABLE ONLY datsrcln -- --- Name: deriv_cd_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: +-- Name: deriv_cd_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: -- ALTER TABLE ONLY deriv_cd @@ -989329,7 +989329,7 @@ ALTER TABLE ONLY deriv_cd -- --- Name: fd_group_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: +-- Name: fd_group_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: -- ALTER TABLE ONLY fd_group @@ -989337,7 +989337,7 @@ ALTER TABLE ONLY fd_group -- --- Name: food_des_ndb_no_fdgrp_cd_key; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: +-- Name: food_des_ndb_no_fdgrp_cd_key; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: -- ALTER TABLE ONLY food_des @@ -989345,7 +989345,7 @@ ALTER TABLE ONLY food_des -- --- Name: food_des_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: +-- Name: food_des_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: -- ALTER TABLE ONLY food_des @@ -989353,7 +989353,7 @@ ALTER TABLE ONLY food_des -- --- Name: langdesc_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: +-- Name: langdesc_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: -- ALTER TABLE ONLY langdesc @@ -989361,7 +989361,7 @@ ALTER TABLE ONLY langdesc -- --- Name: langual_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: +-- Name: langual_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: -- ALTER TABLE ONLY langual @@ -989369,7 +989369,7 @@ ALTER TABLE ONLY langual -- --- Name: nut_data_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: +-- Name: nut_data_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: -- ALTER TABLE ONLY nut_data @@ -989377,7 +989377,7 @@ ALTER TABLE ONLY nut_data -- --- Name: nutr_def_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: +-- Name: nutr_def_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: -- ALTER TABLE ONLY nutr_def @@ -989385,7 +989385,7 @@ ALTER TABLE ONLY nutr_def -- --- Name: src_cd_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: +-- Name: src_cd_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: -- ALTER TABLE ONLY src_cd @@ -989393,7 +989393,7 @@ ALTER TABLE ONLY src_cd -- --- Name: weight_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: +-- Name: weight_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: -- ALTER TABLE ONLY weight