From e60532b326687be7857f74692d58877d015f6cb7 Mon Sep 17 00:00:00 2001 From: Laura Beaufort <31420082+lbeaufort@users.noreply.github.com> Date: Fri, 6 Sep 2019 13:53:21 -0400 Subject: [PATCH 1/8] Fallback to False when env var is unset --- webservices/rest.py | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/webservices/rest.py b/webservices/rest.py index 479dc54e5..5fbbb4cbd 100644 --- a/webservices/rest.py +++ b/webservices/rest.py @@ -133,7 +133,7 @@ def handle_error(error): FEC_API_WHITELIST_IPS = env.get_credential('FEC_API_WHITELIST_IPS', False) # Search this key_id in the API umbrella admin interface to look up the API KEY DOWNLOAD_WHITELIST_API_KEY_ID = env.get_credential('DOWNLOAD_WHITELIST_API_KEY_ID') -RESTRICT_DOWNLOADS = env.get_credential('RESTRICT_DOWNLOADS') +RESTRICT_DOWNLOADS = env.get_credential('RESTRICT_DOWNLOADS', False) @app.before_request def limit_remote_addr(): From e4c43db5c601bdfe4af750a4183608bfde3bad50 Mon Sep 17 00:00:00 2001 From: Laura Beaufort <31420082+lbeaufort@users.noreply.github.com> Date: Fri, 6 Sep 2019 14:02:07 -0400 Subject: [PATCH 2/8] Remove double-negative by replacing 'falses' with 'true_values' --- webservices/rest.py | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/webservices/rest.py b/webservices/rest.py index 5fbbb4cbd..23ea46df5 100644 --- a/webservices/rest.py +++ b/webservices/rest.py @@ -143,8 +143,8 @@ def limit_remote_addr(): - Block any flagged IPs - If we're restricting downloads, only allow requests from whitelisted key """ - falses = (False, 'False', 'false', 'f') - if FEC_API_WHITELIST_IPS not in falses: + true_values = (True, 'True', 'true', 't') + if FEC_API_WHITELIST_IPS in true_values: try: *_, source_ip, api_data_route, cf_route = request.access_route except ValueError: # Not enough routes @@ -154,7 +154,7 @@ def limit_remote_addr(): abort(403) if source_ip in BLOCKED_IPS: abort(403) - if RESTRICT_DOWNLOADS not in falses and '/download/' in request.url: + if RESTRICT_DOWNLOADS in true_values and '/download/' in request.url: # 'X-Api-User-Id' header is passed through by the API umbrella request_api_key_id = request.headers.get('X-Api-User-Id') if request_api_key_id != DOWNLOAD_WHITELIST_API_KEY_ID: From 5f2612ac4b2c029d910891039e88614320063ec2 Mon Sep 17 00:00:00 2001 From: Jean Date: Thu, 12 Sep 2019 00:47:32 -0400 Subject: [PATCH 3/8] use disclosure.fec_fitem sched tables instead of fec_fitem_sched views, drop unused fec_vsum_sched views --- ...c_communication_cost_mv_replace_source.sql | 317 ++++++++++++++++++ .../V0162__drop_fec_vsum_sched_vws.sql | 33 ++ 2 files changed, 350 insertions(+) create mode 100644 data/migrations/V0161__ofec_communication_cost_mv_replace_source.sql create mode 100644 data/migrations/V0162__drop_fec_vsum_sched_vws.sql diff --git a/data/migrations/V0161__ofec_communication_cost_mv_replace_source.sql b/data/migrations/V0161__ofec_communication_cost_mv_replace_source.sql new file mode 100644 index 000000000..fb5a2974e --- /dev/null +++ b/data/migrations/V0161__ofec_communication_cost_mv_replace_source.sql @@ -0,0 +1,317 @@ +/* +This migration file is to solve issue #3908 + +There is a set of fec_vsum_sched_xxx, which was created in very early days of this project. +We have tables (disclosure.fec_fitem_sched_xxx) that better suits the needs. +This set of views need to be dropped for +1) better maintenance +2) to prevent people use it by mistake. + +public.fec_fitem_f76_vw is currently been used by the following two MVs: +ofec_communication_cost_aggregate_candidate_mv +ofec_communication_cost_mv + +Those two depending MVs will to be +redefined to use the more accurate table disclosure.fec_fitem_f76 +Then public.fec_fitem_f76_vw will be dropped. + +*/ + +-- ------------------------------------------------ +-- ofec_communication_cost_aggregate_candidate_mv +-- ------------------------------------------------ +DROP MATERIALIZED VIEW IF EXISTS public.ofec_communication_cost_aggregate_candidate_mv_tmp; + +CREATE MATERIALIZED VIEW public.ofec_communication_cost_aggregate_candidate_mv_tmp AS + SELECT row_number() OVER () AS idx, + f76.s_o_ind AS support_oppose_indicator, + f76.org_id AS cmte_id, + f76.s_o_cand_id AS cand_id, + sum(f76.communication_cost) AS total, + count(f76.communication_cost) AS count, + date_part('year'::text, f76.communication_dt)::integer + date_part('year'::text, f76.communication_dt)::integer % 2 AS cycle + FROM disclosure.fec_fitem_f76 as f76 + WHERE date_part('year'::text, f76.communication_dt) >= 1979::double precision AND f76.s_o_cand_id IS NOT NULL + GROUP BY f76.org_id, f76.s_o_cand_id, f76.s_o_ind, (date_part('year'::text, f76.communication_dt)::integer + date_part('year'::text, f76.communication_dt)::integer % 2) +WITH DATA; + +ALTER TABLE public.ofec_communication_cost_aggregate_candidate_mv_tmp + OWNER TO fec; +GRANT ALL ON TABLE public.ofec_communication_cost_aggregate_candidate_mv_tmp TO fec; +GRANT SELECT ON TABLE public.ofec_communication_cost_aggregate_candidate_mv_tmp TO fec_read; + +-- indexes +CREATE UNIQUE INDEX idx_ofec_communication_cost_aggregate_candidate_mv_tmp_idx + ON public.ofec_communication_cost_aggregate_candidate_mv_tmp + USING btree + (idx); + +CREATE INDEX idx_ofec_communication_cost_aggregate_candidate_mv_tmp_s_o_ind + ON public.ofec_communication_cost_aggregate_candidate_mv_tmp + USING btree + (support_oppose_indicator COLLATE pg_catalog."default"); + +CREATE INDEX idx_ofec_communication_cost_aggregate_candidate_mv_tmp_cand_id + ON public.ofec_communication_cost_aggregate_candidate_mv_tmp + USING btree + (cand_id COLLATE pg_catalog."default"); + +CREATE INDEX idx_ofec_communication_cost_aggregate_candidate_mv_tmp_cmte_id + ON public.ofec_communication_cost_aggregate_candidate_mv_tmp + USING btree + (cmte_id COLLATE pg_catalog."default"); + +CREATE INDEX idx_ofec_communication_cost_aggregate_candidate_mv_tmp_count + ON public.ofec_communication_cost_aggregate_candidate_mv_tmp + USING btree + (count); + +CREATE INDEX idx_ofec_communication_cost_aggregate_candidate_mv_tmp_cycle + ON public.ofec_communication_cost_aggregate_candidate_mv_tmp + USING btree + (cycle); + +CREATE INDEX idx_ofec_communication_cost_aggregate_candidate_mv_tmp_total + ON public.ofec_communication_cost_aggregate_candidate_mv_tmp + USING btree + (total); + +-- point view to the tmp mv +CREATE OR REPLACE VIEW public.ofec_communication_cost_aggregate_candidate_vw AS + SELECT * FROM ofec_communication_cost_aggregate_candidate_mv_tmp; + +ALTER TABLE public.ofec_communication_cost_aggregate_candidate_vw + OWNER TO fec; +GRANT ALL ON TABLE public.ofec_communication_cost_aggregate_candidate_vw TO fec; +GRANT SELECT ON TABLE public.ofec_communication_cost_aggregate_candidate_vw TO fec_read; + +-- drop old MV +DROP MATERIALIZED VIEW IF EXISTS public.ofec_communication_cost_aggregate_candidate_mv; + +-- rename _tmp mv to mv +ALTER MATERIALIZED VIEW public.ofec_communication_cost_aggregate_candidate_mv_tmp RENAME TO ofec_communication_cost_aggregate_candidate_mv; + +-- rename indexes +ALTER INDEX IF EXISTS idx_ofec_communication_cost_aggregate_candidate_mv_tmp_idx RENAME TO idx_ofec_communication_cost_aggregate_candidate_mv_idx; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_aggregate_candidate_mv_tmp_s_o_ind RENAME TO idx_ofec_communication_cost_aggregate_candidate_mv_s_o_ind; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_aggregate_candidate_mv_tmp_cand_id RENAME TO idx_ofec_communication_cost_aggregate_candidate_mv_cand_id; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_aggregate_candidate_mv_tmp_cmte_id RENAME TO idx_ofec_communication_cost_aggregate_candidate_mv_cmte_id; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_aggregate_candidate_mv_tmp_count RENAME TO idx_ofec_communication_cost_aggregate_candidate_mv_count; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_aggregate_candidate_mv_tmp_cycle RENAME TO idx_ofec_communication_cost_aggregate_candidate_mv_cycle; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_aggregate_candidate_mv_tmp_total RENAME TO idx_ofec_communication_cost_aggregate_candidate_mv_total; + +/* +SELECT f76.s_o_ind AS support_oppose_indicator, +f76.org_id AS cmte_id, +f76.s_o_cand_id AS cand_id, +sum(f76.communication_cost) AS total, +count(f76.communication_cost) AS count, +date_part('year'::text, f76.communication_dt)::integer + date_part('year'::text, f76.communication_dt)::integer % 2 AS cycle +FROM disclosure.fec_fitem_f76 as f76 +WHERE date_part('year'::text, f76.communication_dt) >= 1979::double precision AND f76.s_o_cand_id IS NOT NULL +GROUP BY f76.org_id, f76.s_o_cand_id, f76.s_o_ind, (date_part('year'::text, f76.communication_dt)::integer + date_part('year'::text, f76.communication_dt)::integer % 2) +except +select support_oppose_indicator, +cmte_id, +cand_id, +total, +count, +cycle +FROM public.ofec_communication_cost_aggregate_candidate_mv +*/ + +-- ------------------------------------------------ +-- ofec_communication_cost_mv +-- +-- data type for column schedule_type in public.fec_fitem_f76_vw is undefined. +-- data type for column schedule_type in disclosure.fec_fitem_f76 is varchar(8) +-- In openFEC/webservices/common/models/costs.py, schedule_type is defined as String, therefore will not cause problem +-- ------------------------------------------------ +DROP MATERIALIZED VIEW IF EXISTS public.ofec_communication_cost_mv_tmp; +CREATE MATERIALIZED VIEW public.ofec_communication_cost_mv_tmp AS + WITH com_names AS ( + SELECT DISTINCT ON (ofec_committee_history_vw.committee_id) ofec_committee_history_vw.committee_id, + ofec_committee_history_vw.name AS committee_name + FROM ofec_committee_history_vw + ORDER BY ofec_committee_history_vw.committee_id, ofec_committee_history_vw.cycle DESC + ) + SELECT f76.org_id, + f76.communication_tp, + f76.communication_tp_desc, + f76.communication_class, + f76.communication_class_desc, + f76.communication_dt, + f76.s_o_ind, + f76.s_o_ind_desc, + f76.s_o_cand_id, + f76.s_o_cand_nm, + f76.s_o_cand_l_nm, + f76.s_o_cand_f_nm, + f76.s_o_cand_m_nm, + f76.s_o_cand_prefix, + f76.s_o_cand_suffix, + f76.s_o_cand_office, + f76.s_o_cand_office_desc, + f76.s_o_cand_office_st, + f76.s_o_cand_office_st_desc, + f76.s_o_cand_office_district, + f76.s_o_rpt_pgi, + f76.s_o_rpt_pgi_desc, + f76.communication_cost, + f76.election_other_desc, + f76.transaction_tp, + f76.action_cd, + f76.action_cd_desc, + f76.tran_id, + f76.schedule_type, + f76.schedule_type_desc, + f76.image_num, + f76.file_num, + f76.link_id, + f76.orig_sub_id, + f76.sub_id, + f76.filing_form, + f76.rpt_tp, + f76.rpt_yr, + f76.election_cycle, + f76.s_o_cand_id AS cand_id, + f76.org_id AS cmte_id, + com_names.committee_name, + report_pdf_url(f76.image_num::text) AS pdf_url + FROM disclosure.fec_fitem_f76 f76 + LEFT JOIN com_names ON f76.org_id::text = com_names.committee_id::text + WHERE date_part('year'::text, f76.communication_dt)::integer >= 1979 +WITH DATA; + +ALTER TABLE public.ofec_communication_cost_mv_tmp + OWNER TO fec; +GRANT ALL ON TABLE public.ofec_communication_cost_mv_tmp TO fec; +GRANT SELECT ON TABLE public.ofec_communication_cost_mv_tmp TO fec_read; + +-- -------------- +-- recreate the view +-- data type for column schedule_type in public.fec_fitem_f76_vw is undefined. +-- data type for column schedule_type in disclosure.fec_fitem_f76 is varchar(8) +-- can not repoint the view to the tmp MV with "CREATE OR REPLACE" +-- Need to DROP and CREATE +-- Since public.ofec_communication_cost_vw had no depending objects, it can be dropped and created without chain reaction +DROP VIEW public.ofec_communication_cost_vw; + +CREATE OR REPLACE VIEW public.ofec_communication_cost_vw AS + SELECT * FROM ofec_communication_cost_mv_tmp; + +ALTER TABLE public.ofec_communication_cost_vw + OWNER TO fec; +GRANT ALL ON TABLE public.ofec_communication_cost_vw TO fec; +GRANT SELECT ON TABLE public.ofec_communication_cost_vw TO fec_read; +-- -------------- + +-- indexes +CREATE UNIQUE INDEX idx_ofec_communication_cost_mv_tmp_sub_id + ON public.ofec_communication_cost_mv_tmp + USING btree + (sub_id); + +CREATE INDEX idx_ofec_communication_cost_mv_tmp_cand_id + ON public.ofec_communication_cost_mv_tmp + USING btree + (cand_id COLLATE pg_catalog."default"); + +CREATE INDEX idx_ofec_communication_cost_mv_tmp_cmte_id + ON public.ofec_communication_cost_mv_tmp + USING btree + (cmte_id COLLATE pg_catalog."default"); + +CREATE INDEX idx_ofec_communication_cost_mv_tmp_comm_class + ON public.ofec_communication_cost_mv_tmp + USING btree + (communication_class COLLATE pg_catalog."default"); + +CREATE INDEX idx_ofec_communication_cost_mv_tmp_comm_cost + ON public.ofec_communication_cost_mv_tmp + USING btree + (communication_cost); + +CREATE INDEX idx_ofec_communication_cost_mv_tmp_comm_dt + ON public.ofec_communication_cost_mv_tmp + USING btree + (communication_dt); + +CREATE INDEX idx_ofec_communication_cost_mv_tmp_comm_tp + ON public.ofec_communication_cost_mv_tmp + USING btree + (communication_tp COLLATE pg_catalog."default"); + +CREATE INDEX idx_ofec_communication_cost_mv_tmp_filing_form + ON public.ofec_communication_cost_mv_tmp + USING btree + (filing_form COLLATE pg_catalog."default"); + +CREATE INDEX idx_ofec_communication_cost_mv_tmp_image_num + ON public.ofec_communication_cost_mv_tmp + USING btree + (image_num COLLATE pg_catalog."default"); + +CREATE INDEX idx_ofec_communication_cost_mv_tmp_s_o_cand_office_dist + ON public.ofec_communication_cost_mv_tmp + USING btree + (s_o_cand_office_district COLLATE pg_catalog."default"); + +CREATE INDEX idx_ofec_communication_cost_mv_tmp_s_o_cand_office + ON public.ofec_communication_cost_mv_tmp + USING btree + (s_o_cand_office COLLATE pg_catalog."default"); + +CREATE INDEX idx_ofec_communication_cost_mv_tmp_s_o_cand_office_st + ON public.ofec_communication_cost_mv_tmp + USING btree + (s_o_cand_office_st COLLATE pg_catalog."default"); + +CREATE INDEX idx_ofec_communication_cost_mv_tmp_s_o_ind + ON public.ofec_communication_cost_mv_tmp + USING btree + (s_o_ind COLLATE pg_catalog."default"); + + +-- drop old MV +DROP MATERIALIZED VIEW IF EXISTS public.ofec_communication_cost_mv; + +-- rename _tmp mv to mv +ALTER MATERIALIZED VIEW public.ofec_communication_cost_mv_tmp RENAME TO ofec_communication_cost_mv; + +-- rename indexes +ALTER INDEX IF EXISTS idx_ofec_communication_cost_mv_tmp_sub_id RENAME TO idx_ofec_communication_cost_mv_sub_id; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_mv_tmp_cand_id RENAME TO idx_ofec_communication_cost_mv_cand_id; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_mv_tmp_cmte_id RENAME TO idx_ofec_communication_cost_mv_cmte_id; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_mv_tmp_comm_class RENAME TO idx_ofec_communication_cost_mv_comm_class; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_mv_tmp_comm_cost RENAME TO idx_ofec_communication_cost_mv_comm_cost; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_mv_tmp_comm_dt RENAME TO idx_ofec_communication_cost_mv_comm_dt; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_mv_tmp_comm_tp RENAME TO idx_ofec_communication_cost_mv_comm_tp; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_mv_tmp_filing_form RENAME TO idx_ofec_communication_cost_mv_filing_form; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_mv_tmp_image_num RENAME TO idx_ofec_communication_cost_mv_image_num; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_mv_tmp_s_o_cand_office_dist RENAME TO idx_ofec_communication_cost_mv_s_o_cand_office_dist; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_mv_tmp_s_o_cand_office RENAME TO idx_ofec_communication_cost_mv_s_o_cand_office; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_mv_tmp_s_o_cand_office_st RENAME TO idx_ofec_communication_cost_mv_s_o_cand_office_st; + +ALTER INDEX IF EXISTS idx_ofec_communication_cost_mv_tmp_s_o_ind RENAME TO idx_ofec_communication_cost_mv_s_o_ind; + +-- -------------- +DROP VIEW IF EXISTS public.fec_fitem_f76_vw; +-- -------------- diff --git a/data/migrations/V0162__drop_fec_vsum_sched_vws.sql b/data/migrations/V0162__drop_fec_vsum_sched_vws.sql new file mode 100644 index 000000000..c831664bd --- /dev/null +++ b/data/migrations/V0162__drop_fec_vsum_sched_vws.sql @@ -0,0 +1,33 @@ +/* +This migration file is to solve issue #3908 + +There is a set of fec_vsum_sched_xxx, which was created in very early days of this project. +We have tables (disclosure.fec_fitem_sched_xxx) that better suits the needs. +This set of views need to be dropped for +1) better maintenance +2) to prevent people use it by mistake. +*/ + +DROP VIEW IF EXISTS public.fec_vsum_sched_a_vw; +DROP VIEW IF EXISTS public.fec_vsum_sched_b_vw; +DROP VIEW IF EXISTS public.fec_vsum_sched_c1_vw; +DROP VIEW IF EXISTS public.fec_vsum_sched_c2_vw; +DROP VIEW IF EXISTS public.fec_vsum_sched_c_vw; +DROP VIEW IF EXISTS public.fec_vsum_sched_d_vw; +DROP VIEW IF EXISTS public.fec_vsum_sched_e_vw; +DROP VIEW IF EXISTS public.fec_vsum_sched_f_vw; +DROP VIEW IF EXISTS public.fec_vsum_sched_h1_vw; +DROP VIEW IF EXISTS public.fec_vsum_sched_h2_vw; +DROP VIEW IF EXISTS public.fec_vsum_sched_h3_vw; +DROP VIEW IF EXISTS public.fec_vsum_sched_h4_vw; +DROP VIEW IF EXISTS public.fec_vsum_sched_h5_vw; +DROP VIEW IF EXISTS public.fec_vsum_sched_h6_vw; +DROP VIEW IF EXISTS public.fec_vsum_sched_i_vw; +DROP VIEW IF EXISTS public.fec_vsum_sched_l_vw; + +DROP VIEW IF EXISTS public.fec_vsum_f105_vw; +DROP VIEW IF EXISTS public.fec_vsum_f56_vw; +DROP VIEW IF EXISTS public.fec_vsum_f57_vw; +DROP VIEW IF EXISTS public.fec_vsum_f76_vw; +DROP VIEW IF EXISTS public.fec_vsum_f91_vw; +DROP VIEW IF EXISTS public.fec_vsum_f94_vw; \ No newline at end of file From 1c6cf77fd3d22de315af3f3f25d59ad8e94c2a80 Mon Sep 17 00:00:00 2001 From: Jean Date: Fri, 13 Sep 2019 07:57:08 -0400 Subject: [PATCH 4/8] correct views with column data type unknown --- .../V0163__ofec_reports_ie_only_mv.sql | 155 ++ ...ct_views_with_column_data_type_unknown.sql | 1499 +++++++++++++++++ webservices/flow.py | 4 +- 3 files changed, 1655 insertions(+), 3 deletions(-) create mode 100644 data/migrations/V0163__ofec_reports_ie_only_mv.sql create mode 100644 data/migrations/V0164__correct_views_with_column_data_type_unknown.sql diff --git a/data/migrations/V0163__ofec_reports_ie_only_mv.sql b/data/migrations/V0163__ofec_reports_ie_only_mv.sql new file mode 100644 index 000000000..529ac2d72 --- /dev/null +++ b/data/migrations/V0163__ofec_reports_ie_only_mv.sql @@ -0,0 +1,155 @@ +/* +This migration file is to solve issue #3908 + +There is a set of fec_vsum_sched_xxx, which was created in very early days of this project. +We have tables (disclosure.fec_fitem_sched_xxx) that better suits the needs. +This set of views need to be dropped for +1) better maintenance +2) to prevent people use it by mistake. + +In addition, there are several views with columns of data type "unknown". +In this ticket, this will be corrected. + +public.fec_vsum_f5_vw is currently been used by the following MV: +public.ofec_reports_ie_only_mv + +public.ofec_reports_ie_only_mv is redefined to use +the base tables of public.fec_vsum_f5_vw so it will +1) reduce the dependency layer +2) public.fec_vsum_f5_vw can be recreated to correct the "unknown" data type issue + +*/ +-- ------------------------------------------------ +-- ofec_reports_ie_only_mv +-- ------------------------------------------------ +DROP MATERIALIZED VIEW IF EXISTS public.ofec_reports_ie_only_mv_tmp; +CREATE MATERIALIZED VIEW public.ofec_reports_ie_only_mv_tmp AS +-- WITH fec_vsum_f5 AS +SELECT row_number() OVER () AS idx, +f5.indv_org_id AS committee_id, +(f5.rpt_yr + f5.rpt_yr%2) AS cycle, + f5.cvg_start_dt AS coverage_start_date, + f5.cvg_end_dt AS coverage_end_date, + f5.rpt_yr AS report_year, + f5.ttl_indt_contb AS independent_contributions_period, + f5.ttl_indt_exp AS independent_expenditures_period, + f5.filer_sign_dt AS filer_sign_date, + f5.notary_sign_dt AS notary_sign_date, + f5.notary_commission_exprtn_dt AS notary_commission_experation_date, + f5.begin_image_num AS beginning_image_number, + f5.end_image_num AS end_image_number, + f5.rpt_tp AS report_type, + f5.rpt_tp_desc AS report_type_full, + (CASE WHEN (vs.orig_sub_id IS NOT NULL) THEN 'Y'::text ELSE 'N'::text END) ~~ 'N'::text AS is_amended, + f5.receipt_dt AS receipt_date, + f5.file_num AS file_number, + f5.amndt_ind AS amendment_indicator, + f5.amndt_ind_desc AS amendment_indicator_full, + means_filed(f5.begin_image_num::text) AS means_filed, + report_html_url(means_filed(f5.begin_image_num::text), f5.indv_org_id::text, f5.file_num::text) AS html_url, + report_fec_url(f5.begin_image_num::text, f5.file_num::integer) AS fec_url +FROM (disclosure.nml_form_5 f5 + LEFT JOIN disclosure.v_sum_and_det_sum_report vs ON ((f5.sub_id = vs.orig_sub_id))) +WHERE ((f5.delete_ind IS NULL) AND ((f5.rpt_tp)::text <> ALL (ARRAY[('24'::character varying)::text, ('48'::character varying)::text]))) +AND (f5.rpt_yr + f5.rpt_yr%2) >= 1979::numeric +WITH DATA; + +ALTER TABLE public.ofec_reports_ie_only_mv_tmp + OWNER TO fec; +GRANT ALL ON TABLE public.ofec_reports_ie_only_mv_tmp TO fec; +GRANT SELECT ON TABLE public.ofec_reports_ie_only_mv_tmp TO fec_read; + + +CREATE UNIQUE INDEX idx_ofec_reports_ie_only_mv_tmp_idx + ON public.ofec_reports_ie_only_mv_tmp + USING btree + (idx); + +CREATE INDEX idx_ofec_reports_ie_only_mv_tmp_begin_image_num_idx + ON public.ofec_reports_ie_only_mv_tmp + USING btree + (beginning_image_number COLLATE pg_catalog."default", idx); + +CREATE INDEX idx_ofec_reports_ie_only_mv_tmp_cmte_id_idx + ON public.ofec_reports_ie_only_mv_tmp + USING btree + (committee_id COLLATE pg_catalog."default", idx); + +CREATE INDEX idx_ofec_reports_ie_only_mv_tmp_cvg_end_dt_idx + ON public.ofec_reports_ie_only_mv_tmp + USING btree + (coverage_end_date, idx); + +CREATE INDEX idx_ofec_reports_ie_only_mv_tmp_cvg_start_dt_idx + ON public.ofec_reports_ie_only_mv_tmp + USING btree + (coverage_start_date, idx); + +CREATE INDEX idx_ofec_reports_ie_only_mv_tmp_cycle_idx + ON public.ofec_reports_ie_only_mv_tmp + USING btree + (cycle, idx); + +CREATE INDEX idx_ofec_reports_ie_only_mv_tmp_indt_exp_period_idx + ON public.ofec_reports_ie_only_mv_tmp + USING btree + (independent_expenditures_period, idx); + +CREATE INDEX idx_ofec_reports_ie_only_mv_tmp_is_amended_idx + ON public.ofec_reports_ie_only_mv_tmp + USING btree + (is_amended, idx); + +CREATE INDEX idx_ofec_reports_ie_only_mv_tmp_receipt_dt_idx + ON public.ofec_reports_ie_only_mv_tmp + USING btree + (receipt_date, idx); + +CREATE INDEX idx_ofec_reports_ie_only_mv_tmp_rpt_tp_idx + ON public.ofec_reports_ie_only_mv_tmp + USING btree + (report_type COLLATE pg_catalog."default", idx); + +CREATE INDEX idx_ofec_reports_ie_only_mv_tmp_rpt_yr_idx + ON public.ofec_reports_ie_only_mv_tmp + USING btree + (report_year, idx); + + +-- point view to the tmp mv +CREATE OR REPLACE VIEW public.ofec_reports_ie_only_vw AS + SELECT * FROM ofec_reports_ie_only_mv_tmp; + +ALTER TABLE public.ofec_reports_ie_only_vw + OWNER TO fec; +GRANT ALL ON TABLE public.ofec_reports_ie_only_vw TO fec; +GRANT SELECT ON TABLE public.ofec_reports_ie_only_vw TO fec_read; + +-- drop old MV +DROP MATERIALIZED VIEW IF EXISTS public.ofec_reports_ie_only_mv; + +-- rename _tmp mv to mv +ALTER MATERIALIZED VIEW public.ofec_reports_ie_only_mv_tmp RENAME TO ofec_reports_ie_only_mv; + +-- rename indexes +ALTER INDEX IF EXISTS idx_ofec_reports_ie_only_mv_tmp_idx RENAME TO idx_ofec_reports_ie_only_mv_idx; + +ALTER INDEX IF EXISTS idx_ofec_reports_ie_only_mv_tmp_begin_image_num_idx RENAME TO idx_ofec_reports_ie_only_mv_begin_image_num_idx; + +ALTER INDEX IF EXISTS idx_ofec_reports_ie_only_mv_tmp_cmte_id_idx RENAME TO idx_ofec_reports_ie_only_mv_cmte_id_idx; + +ALTER INDEX IF EXISTS idx_ofec_reports_ie_only_mv_tmp_cvg_end_dt_idx RENAME TO idx_ofec_reports_ie_only_mv_cvg_end_dt_idx; + +ALTER INDEX IF EXISTS idx_ofec_reports_ie_only_mv_tmp_cvg_start_dt_idx RENAME TO idx_ofec_reports_ie_only_mv_cvg_start_dt_idx; + +ALTER INDEX IF EXISTS idx_ofec_reports_ie_only_mv_tmp_cycle_idx RENAME TO idx_ofec_reports_ie_only_mv_cycle_idx; + +ALTER INDEX IF EXISTS idx_ofec_reports_ie_only_mv_tmp_indt_exp_period_idx RENAME TO idx_ofec_reports_ie_only_mv_indt_exp_period_idx; + +ALTER INDEX IF EXISTS idx_ofec_reports_ie_only_mv_tmp_is_amended_idx RENAME TO idx_ofec_reports_ie_only_mv_is_amended_idx; + +ALTER INDEX IF EXISTS idx_ofec_reports_ie_only_mv_tmp_receipt_dt_idx RENAME TO idx_ofec_reports_ie_only_mv_receipt_dt_idx; + +ALTER INDEX IF EXISTS idx_ofec_reports_ie_only_mv_tmp_rpt_tp_idx RENAME TO idx_ofec_reports_ie_only_mv_rpt_tp_idx; + +ALTER INDEX IF EXISTS idx_ofec_reports_ie_only_mv_tmp_rpt_yr_idx RENAME TO idx_ofec_reports_ie_only_mv_rpt_yr_idx; \ No newline at end of file diff --git a/data/migrations/V0164__correct_views_with_column_data_type_unknown.sql b/data/migrations/V0164__correct_views_with_column_data_type_unknown.sql new file mode 100644 index 000000000..20cd21f3e --- /dev/null +++ b/data/migrations/V0164__correct_views_with_column_data_type_unknown.sql @@ -0,0 +1,1499 @@ +/* +This migration file is to solve issue #3908 + +There is a set of fec_vsum_sched_xxx, which was created in very early days of this project. +We have tables (disclosure.fec_fitem_sched_xxx) that better suits the needs. +This set of views need to be dropped for +1) better maintenance +2) to prevent people use it by mistake. + +In addition, there are several views with columns of data type "unknown". +In this ticket, this will be corrected. + +*/ + +-- ------------------ +-- fec_f56_notice_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_f56_notice_vw; +CREATE VIEW public.fec_f56_notice_vw AS + SELECT f56.filer_cmte_id, + f56.entity_tp, + f56.entity_tp_desc, + f56.contbr_nm, + f56.contbr_l_nm, + f56.contbr_f_nm, + f56.contbr_m_nm, + f56.contbr_prefix, + f56.contbr_suffix, + f56.contbr_st1, + f56.contbr_st2, + f56.conbtr_city, + f56.contbr_st, + f56.contbr_zip, + f56.contbr_employer, + f56.contbr_occupation, + f56.contb_dt, + f56.contb_amt, + f56.cand_id, + f56.cand_nm, + f56.cand_office, + f56.cand_office_desc, + f56.cand_office_st, + f56.cand_office_st_desc, + f56.cand_office_district, + f56.conduit_cmte_id, + f56.conduit_nm, + f56.conduit_st1, + f56.conduit_st2, + f56.conduit_city, + f56.conduit_st, + f56.conduit_zip, + f56.amndt_ind, + f56.amndt_ind_desc, + CASE + WHEN ("substring"(((f56.sub_id)::character varying)::text, 1, 1) = '4'::text) THEN f56.tran_id + ELSE NULL::character varying + END AS tran_id, + 'F5'::character varying(8) AS filing_form, + 'SA-F56'::character varying(8) AS schedule_type, + f56.form_tp_desc AS schedule_type_desc, + f56.image_num, + f56.file_num, + f56.sub_id, + f56.link_id, + f56.orig_sub_id, + f5.rpt_yr, + f5.rpt_tp, + (f5.rpt_yr + mod(f5.rpt_yr, (2)::numeric)) AS cycle + FROM disclosure.nml_form_56 f56, + disclosure.nml_form_5 f5 + WHERE ((f56.link_id = f5.sub_id) AND ((f5.rpt_tp)::text = ANY (ARRAY[('24'::character varying)::text, ('48'::character varying)::text])) AND ((f56.amndt_ind)::text <> 'D'::text) AND (f56.delete_ind IS NULL) AND (f5.delete_ind IS NULL)); + + +ALTER TABLE public.fec_f56_notice_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_f56_notice_vw TO fec_read; + + +-- ------------------ +-- fec_f57_notice_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_f57_notice_vw; +CREATE VIEW public.fec_f57_notice_vw AS + SELECT f57.filer_cmte_id, + f57.pye_nm, + f57.pye_l_nm, + f57.pye_f_nm, + f57.pye_m_nm, + f57.pye_prefix, + f57.pye_suffix, + f57.pye_st1, + f57.pye_st2, + f57.pye_city, + f57.pye_st, + f57.pye_zip, + f57.exp_purpose, + f57.entity_tp, + f57.entity_tp_desc, + f57.catg_cd, + f57.catg_cd_desc, + f57.s_o_cand_id, + f57.s_o_cand_l_nm, + f57.s_o_cand_f_nm, + f57.s_o_cand_m_nm, + f57.s_o_cand_prefix, + f57.s_o_cand_suffix, + f57.s_o_cand_nm, + f57.s_o_cand_office, + f57.s_o_cand_office_desc, + f57.s_o_cand_office_st, + f57.s_o_cand_office_state_desc, + f57.s_o_cand_office_district, + f57.s_o_ind, + f57.s_o_ind_desc, + f57.election_tp, + f57.fec_election_tp_desc, + f57.fec_election_yr, + f57.election_tp_desc, + f57.cal_ytd_ofc_sought, + f57.exp_dt, + f57.exp_amt, + f57.exp_tp, + f57.exp_tp_desc, + f57.conduit_cmte_id, + f57.conduit_cmte_nm, + f57.conduit_cmte_st1, + f57.conduit_cmte_st2, + f57.conduit_cmte_city, + f57.conduit_cmte_st, + f57.conduit_cmte_zip, + f57.amndt_ind AS action_cd, + f57.amndt_ind_desc AS action_cd_desc, + CASE + WHEN ("substring"(((f57.sub_id)::character varying)::text, 1, 1) = '4'::text) THEN f57.tran_id + ELSE NULL::character varying + END AS tran_id, + 'F5'::character varying(8) AS filing_form, + 'SE-F57'::character varying(8) AS schedule_type, + f57.form_tp_desc AS schedule_type_desc, + f57.image_num, + f57.file_num, + f57.sub_id, + f57.link_id, + f57.orig_sub_id, + f5.rpt_yr, + f5.rpt_tp, + (f5.rpt_yr + mod(f5.rpt_yr, (2)::numeric)) AS cycle + FROM disclosure.nml_form_57 f57, + disclosure.nml_form_5 f5 + WHERE ((f57.link_id = f5.sub_id) AND ((f5.rpt_tp)::text = ANY (ARRAY[('24'::character varying)::text, ('48'::character varying)::text])) AND ((f57.amndt_ind)::text <> 'D'::text) AND (f57.delete_ind IS NULL) AND (f5.delete_ind IS NULL)); + + +ALTER TABLE public.fec_f57_notice_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_f57_notice_vw TO fec_read; + +-- ------------------ +-- fec_f5_notice_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_f5_notice_vw; +CREATE VIEW public.fec_f5_notice_vw AS + SELECT f5.indv_org_id, + f5.indv_org_nm, + f5.indv_l_nm, + f5.indv_f_nm, + f5.indv_m_nm, + f5.indv_prefix, + f5.indv_suffix, + f5.indv_org_st1, + f5.indv_org_st2, + f5.indv_org_city, + f5.indv_org_st, + f5.indv_org_zip, + f5.entity_tp, + f5.addr_chg_flg, + f5.qual_nonprofit_corp_ind, + f5.indv_org_employer, + f5.indv_org_occupation, + f5.amndt_ind, + f5.amndt_ind_desc, + f5.orig_amndt_dt, + f5.rpt_tp, + f5.rpt_tp_desc, + f5.rpt_pgi, + f5.rpt_pgi_desc, + f5.cvg_start_dt, + f5.cvg_end_dt, + f5.rpt_yr, + f5.receipt_dt, + (f5.rpt_yr + mod(f5.rpt_yr, (2)::numeric)) AS cycle, + f5.ttl_indt_contb, + f5.ttl_indt_exp, + f5.filer_nm, + f5.filer_sign_nm, + f5.filer_sign_dt, + f5.filer_l_nm, + f5.filer_f_nm, + f5.filer_m_nm, + f5.filer_prefix, + f5.filer_suffix, + f5.notary_sign_dt, + f5.notary_commission_exprtn_dt, + f5.notary_nm, + f5.sub_id, + f5.begin_image_num, + f5.end_image_num, + 'F5'::character varying(8) AS form_tp, + f5.form_tp_desc, + f5.file_num, + f5.prev_file_num, + f5.mst_rct_file_num + FROM disclosure.nml_form_5 f5 + WHERE ((f5.delete_ind IS NULL) AND ((f5.rpt_tp)::text = ANY (ARRAY[('24'::character varying)::text, ('48'::character varying)::text]))); + + +ALTER TABLE public.fec_f5_notice_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_f5_notice_vw TO fec_read; +-- ------------------ +-- fec_f65_notice_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_f65_notice_vw; +CREATE VIEW public.fec_f65_notice_vw AS + SELECT f65.filer_cmte_id, + f65.contbr_lender_nm, + f65.contbr_l_nm, + f65.contbr_f_nm, + f65.contbr_m_nm, + f65.contbr_prefix, + f65.contbr_suffix, + f65.contbr_lender_st1, + f65.contbr_lender_st2, + f65.contbr_lender_city, + f65.contbr_lender_st, + f65.contbr_lender_zip, + f65.contbr_lender_employer, + f65.contbr_lender_occupation, + f65.entity_tp, + f65.entity_tp_desc, + f65.contb_dt, + f65.contb_amt, + f65.cand_id, + f65.cand_nm, + f65.cand_office, + f65.cand_office_desc, + f65.cand_office_st, + f65.cand_office_st_desc, + f65.cand_office_district, + f65.conduit_cmte_id, + f65.conduit_cmte_nm, + f65.conduit_cmte_st1, + f65.conduit_cmte_st2, + f65.conduit_cmte_city, + f65.conduit_cmte_st, + f65.conduit_cmte_zip, + f65.amndt_ind AS action_cd, + f65.amndt_ind_desc AS action_cd_desc, + CASE + WHEN ("substring"(((f65.sub_id)::character varying)::text, 1, 1) = '4'::text) THEN f65.tran_id + ELSE NULL::character varying + END AS tran_id, + f65.receipt_dt, + 'F6'::character varying(8) AS filing_form, + 'SA-F65'::character varying(8) AS schedule_type, + f65.form_tp_desc AS schedule_type_desc, + f65.image_num, + f65.file_num, + f65.sub_id, + f65.link_id, + f65.orig_sub_id, + f6.rpt_yr, + (f6.rpt_yr + mod(f6.rpt_yr, (2)::numeric)) AS cycle + FROM disclosure.nml_form_65 f65, + disclosure.nml_form_6 f6 + WHERE ((f65.link_id = f6.sub_id) AND ((f65.amndt_ind)::text <> 'D'::text) AND (f65.delete_ind IS NULL) AND (f6.delete_ind IS NULL)); + + +ALTER TABLE public.fec_f65_notice_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_f65_notice_vw TO fec_read; + +-- ------------------ +-- fec_sched_e_notice_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_sched_e_notice_vw; +CREATE VIEW public.fec_sched_e_notice_vw AS + SELECT se.cmte_id, + se.cmte_nm, + se.pye_nm, + se.payee_l_nm, + se.payee_f_nm, + se.payee_m_nm, + se.payee_prefix, + se.payee_suffix, + se.pye_st1, + se.pye_st2, + se.pye_city, + se.pye_st, + se.pye_zip, + se.entity_tp, + se.entity_tp_desc, + se.exp_desc, + se.catg_cd, + se.catg_cd_desc, + se.s_o_cand_id, + se.s_o_cand_nm, + se.s_o_cand_nm_first, + se.s_o_cand_nm_last, + se.s_0_cand_m_nm AS s_o_cand_m_nm, + se.s_0_cand_prefix AS s_o_cand_prefix, + se.s_0_cand_suffix AS s_o_cand_suffix, + se.s_o_cand_office, + se.s_o_cand_office_desc, + se.s_o_cand_office_st, + se.s_o_cand_office_st_desc, + se.s_o_cand_office_district, + se.s_o_ind, + se.s_o_ind_desc, + se.election_tp, + se.fec_election_tp_desc, + se.cal_ytd_ofc_sought, + se.dissem_dt, + se.exp_amt, + se.exp_dt, + se.exp_tp, + se.exp_tp_desc, + se.memo_cd, + se.memo_cd_desc, + se.memo_text, + se.conduit_cmte_id, + se.conduit_cmte_nm, + se.conduit_cmte_st1, + se.conduit_cmte_st2, + se.conduit_cmte_city, + se.conduit_cmte_st, + se.conduit_cmte_zip, + se.indt_sign_nm, + se.indt_sign_dt, + se.notary_sign_nm, + se.notary_sign_dt, + se.notary_commission_exprtn_dt, + se.filer_l_nm, + se.filer_f_nm, + se.filer_m_nm, + se.filer_prefix, + se.filer_suffix, + se.amndt_ind AS action_cd, + se.amndt_ind_desc AS action_cd_desc, + CASE + WHEN ("substring"(((se.sub_id)::character varying)::text, 1, 1) = '4'::text) THEN se.tran_id + ELSE NULL::character varying + END AS tran_id, + CASE + WHEN ("substring"(((se.sub_id)::character varying)::text, 1, 1) = '4'::text) THEN se.back_ref_tran_id + ELSE NULL::character varying + END AS back_ref_tran_id, + CASE + WHEN ("substring"(((se.sub_id)::character varying)::text, 1, 1) = '4'::text) THEN se.back_ref_sched_nm + ELSE NULL::character varying + END AS back_ref_sched_nm, + 'SE'::character varying(8) AS schedule_type, + se.form_tp_desc AS schedule_type_desc, + se.line_num, + se.image_num, + se.file_num, + se.link_id, + se.orig_sub_id, + se.sub_id, + 'F24'::character varying(8) AS filing_form, + f24.rpt_tp, + f24.rpt_yr, + (f24.rpt_yr + mod(f24.rpt_yr, (2)::numeric)) AS cycle + FROM disclosure.nml_sched_e se, + disclosure.nml_form_24 f24 + WHERE ((se.link_id = f24.sub_id) AND (f24.delete_ind IS NULL) AND (se.delete_ind IS NULL) AND ((se.amndt_ind)::text <> 'D'::text)); + + +ALTER TABLE public.fec_sched_e_notice_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_sched_e_notice_vw TO fec_read; + +-- ------------------ +-- fec_vsum_f5_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_vsum_f5_vw; +CREATE VIEW public.fec_vsum_f5_vw AS + SELECT f5.indv_org_id, + f5.indv_org_nm, + f5.indv_l_nm, + f5.indv_f_nm, + f5.indv_m_nm, + f5.indv_prefix, + f5.indv_suffix, + f5.indv_org_st1, + f5.indv_org_st2, + f5.indv_org_city, + f5.indv_org_st, + f5.indv_org_zip, + f5.entity_tp, + f5.addr_chg_flg, + f5.qual_nonprofit_corp_ind, + f5.indv_org_employer, + f5.indv_org_occupation, + f5.amndt_ind, + f5.amndt_ind_desc, + f5.orig_amndt_dt, + f5.rpt_tp, + f5.rpt_tp_desc, + f5.rpt_pgi, + f5.rpt_pgi_desc, + f5.cvg_start_dt, + f5.cvg_end_dt, + f5.rpt_yr, + f5.receipt_dt, + (f5.rpt_yr + mod(f5.rpt_yr, (2)::numeric)) AS election_cycle, + f5.ttl_indt_contb, + f5.ttl_indt_exp, + f5.filer_nm, + f5.filer_sign_nm, + f5.filer_sign_dt, + f5.filer_l_nm, + f5.filer_f_nm, + f5.filer_m_nm, + f5.filer_prefix, + f5.filer_suffix, + f5.notary_sign_dt, + f5.notary_commission_exprtn_dt, + f5.notary_nm, + f5.begin_image_num, + f5.end_image_num, + 'F5'::character varying(8) AS form_tp, + f5.form_tp_desc, + f5.file_num, + f5.prev_file_num, + f5.mst_rct_file_num, + f5.sub_id, + CASE + WHEN (vs.orig_sub_id IS NOT NULL) THEN 'Y'::text + ELSE 'N'::text + END AS most_recent_filing_flag + FROM (disclosure.nml_form_5 f5 + LEFT JOIN disclosure.v_sum_and_det_sum_report vs ON ((f5.sub_id = vs.orig_sub_id))) + WHERE ((f5.delete_ind IS NULL) AND ((f5.rpt_tp)::text <> ALL (ARRAY[('24'::character varying)::text, ('48'::character varying)::text]))); + +ALTER TABLE public.fec_vsum_f5_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_vsum_f5_vw TO fec_read; + +-- ------------------ +-- fec_form_1m_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_form_1m_vw; +CREATE VIEW public.fec_form_1m_vw AS + SELECT f1m.cmte_id, + f1m.cmte_nm, + f1m.cmte_st1, + f1m.cmte_st2, + f1m.cmte_city, + f1m.cmte_st, + f1m.cmte_zip, + f1m.cmte_tp, + f1m.cmte_tp_desc, + f1m.affiliation_dt, + f1m.affiliated_cmte_id, + f1m.affiliated_cmte_nm, + f1m.fst_cand_id, + f1m.fst_cand_nm, + f1m.fst_cand_office, + f1m.fst_cand_office_desc, + f1m.fst_cand_office_st, + f1m.fst_cand_office_st_desc, + f1m.fst_cand_office_district, + f1m.fst_cand_contb_dt, + f1m.sec_cand_id, + f1m.sec_cand_nm, + f1m.sec_cand_office, + f1m.sec_cand_office_desc, + f1m.sec_cand_office_st, + f1m.sec_cand_office_st_desc, + f1m.sec_cand_office_district, + f1m.sec_cand_contb_dt, + f1m.trd_cand_id, + f1m.trd_cand_nm, + f1m.trd_cand_office, + f1m.trd_cand_office_desc, + f1m.trd_cand_office_st, + f1m.trd_cand_office_st_desc, + f1m.trd_cand_office_district, + f1m.trd_cand_contb_dt, + f1m.frth_cand_id, + f1m.frth_cand_nm, + f1m.frth_cand_office, + f1m.frth_cand_office_desc, + f1m.frth_cand_office_st, + f1m.frth_cand_office_st_desc, + f1m.frth_cand_office_district, + f1m.frth_cand_contb_dt, + f1m.fith_cand_id, + f1m.fith_cand_nm, + f1m.fith_cand_office, + f1m.fith_cand_office_desc, + f1m.fith_cand_office_st, + f1m.fith_cand_office_st_desc, + f1m.fith_cand_office_district, + f1m.fith_cand_contb_dt, + f1m.fiftyfirst_cand_contbr_dt, + f1m.fst_cand_l_nm, + f1m.fst_cand_f_nm, + f1m.fst_cand_m_nm, + f1m.fst_cand_prefix, + f1m.fst_cand_suffix, + f1m.sec_cand_l_nm, + f1m.sec_cand_f_nm, + f1m.sec_cand_m_nm, + f1m.sec_cand_prefix, + f1m.sec_cand_suffix, + f1m.trd_cand_l_nm, + f1m.trd_cand_f_nm, + f1m.trd_cand_m_nm, + f1m.trd_cand_prefix, + f1m.trd_cand_suffix, + f1m.frth_cand_l_nm, + f1m.frth_cand_f_nm, + f1m.frth_cand_m_nm, + f1m.frth_cand_prefix, + f1m.frth_cand_suffix, + f1m.fith_cand_l_nm, + f1m.fith_cand_f_nm, + f1m.fith_cand_m_nm, + f1m.fith_cand_prefix, + f1m.fith_cand_suffix, + f1m.tres_sign_nm, + f1m.tres_sign_l_nm, + f1m.tres_sign_f_nm, + f1m.tres_sign_m_nm, + f1m.tres_sign_prefix, + f1m.tres_sign_suffix, + f1m.tres_sign_dt, + f1m.orig_registration_dt, + f1m.qual_dt, + f1m.receipt_dt, + f1m.rpt_yr, + (f1m.rpt_yr + mod(f1m.rpt_yr, (2)::numeric)) AS cycle, + f1m.file_num, + f1m.prev_file_num, + f1m.mst_rct_file_num, + f1m.sub_id, + f1m.begin_image_num, + f1m.end_image_num, + 'F1M'::character varying(8) AS form_tp, + f1m.form_tp_desc + FROM disclosure.nml_form_1m f1m + WHERE ((f1m.delete_ind IS NULL) AND (f1m.rpt_yr >= (1977)::numeric)); + +ALTER TABLE public.fec_form_1m_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_form_1m_vw TO fec_read; + +-- ------------------ +-- fec_vsum_f2_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_vsum_f2_vw; +CREATE VIEW public.fec_vsum_f2_vw AS + WITH f AS ( + SELECT nml_form_2.cand_id, + nml_form_2.election_yr, + min((nml_form_2.begin_image_num)::text) AS f_begin_image_num, + 'Y' AS first_form_2 + FROM disclosure.nml_form_2 + WHERE ((nml_form_2.delete_ind IS NULL) AND (((nml_form_2.cand_id)::text, nml_form_2.election_yr, nml_form_2.receipt_dt) IN ( SELECT nml_form_2_1.cand_id, + nml_form_2_1.election_yr, + min(nml_form_2_1.receipt_dt) AS min + FROM disclosure.nml_form_2 nml_form_2_1 + WHERE (nml_form_2_1.delete_ind IS NULL) + GROUP BY nml_form_2_1.cand_id, nml_form_2_1.election_yr))) + GROUP BY nml_form_2.cand_id, nml_form_2.election_yr + ) + SELECT f2.cand_id, + f2.cand_nm, + f2.cand_nm_first, + f2.cand_nm_last, + f2.cand_m_nm, + f2.cand_prefix, + f2.cand_suffix, + f2.cand_st1, + f2.cand_st2, + f2.cand_city, + f2.cand_st, + f2.cand_zip, + f2.addr_chg_flg, + f2.cand_pty_affiliation, + f2.cand_pty_affiliation_desc, + f2.cand_office, + f2.cand_office_desc, + f2.cand_office_st, + f2.cand_office_st_desc, + f2.cand_office_district, + f2.election_yr, + f2.pcc_cmte_id, + f2.pcc_cmte_nm, + f2.pcc_cmte_st1, + f2.pcc_cmte_st2, + f2.pcc_cmte_city, + f2.pcc_cmte_st, + f2.pcc_cmte_zip, + f2.addl_auth_cmte_id, + f2.addl_auth_cmte_nm, + f2.addl_auth_cmte_st1, + f2.addl_auth_cmte_st2, + f2.addl_auth_cmte_city, + f2.addl_auth_cmte_st, + f2.addl_auth_cmte_zip, + f2.cand_sign_nm, + f2.cand_sign_l_nm, + f2.cand_sign_f_nm, + f2.cand_sign_m_nm, + f2.cand_sign_prefix, + f2.cand_sign_suffix, + f2.cand_sign_dt, + f2.party_cd, + f2.party_cd_desc, + f2.amndt_ind, + f2.amndt_ind_desc, + f2.cand_ici, + f2.cand_ici_desc, + f2.cand_status, + f2.cand_status_desc, + f2.prim_pers_funds_decl, + f2.gen_pers_funds_decl, + f2.receipt_dt, + f2.rpt_yr, + (f2.rpt_yr + (f2.rpt_yr % (2)::numeric)) AS election_cycle, + f2.file_num, + f2.prev_file_num, + f2.mst_rct_file_num, + f2.begin_image_num, + f2.end_image_num, + 'F2'::character varying(8) AS form_tp, + f2.form_tp_desc, + f2.sub_id, + CASE + WHEN (f.first_form_2 IS NOT NULL) THEN (f.first_form_2)::character varying + ELSE 'N'::character varying + END AS first_form_2 + FROM (disclosure.nml_form_2 f2 + LEFT JOIN f ON ((((f2.begin_image_num)::text = f.f_begin_image_num) AND ((f2.cand_id)::text = (f.cand_id)::text)))) + WHERE (f2.delete_ind IS NULL); + +ALTER TABLE public.fec_vsum_f2_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_vsum_f2_vw TO fec_read; + +-- ------------------ +-- fec_vsum_f3_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_vsum_f3_vw; +CREATE VIEW public.fec_vsum_f3_vw AS + SELECT f3.cmte_id, + f3.cmte_nm, + f3.cmte_st1, + f3.cmte_st2, + f3.cmte_city, + f3.cmte_st, + f3.cmte_zip, + f3.cmte_addr_chg_flg, + f3.cmte_election_st, + f3.cmte_election_st_desc, + f3.cmte_election_district, + f3.amndt_ind, + f3.amndt_ind_desc, + f3.rpt_tp, + f3.rpt_tp_desc, + f3.rpt_pgi, + f3.rpt_pgi_desc, + f3.election_dt, + f3.election_st, + f3.election_st_desc, + f3.cvg_start_dt, + f3.cvg_end_dt, + f3.rpt_yr, + f3.receipt_dt, + (f3.rpt_yr + (f3.rpt_yr % (2)::numeric)) AS election_cycle, + f3.tres_sign_nm, + f3.tres_l_nm, + f3.tres_f_nm, + f3.tres_m_nm, + f3.tres_prefix, + f3.tres_suffix, + f3.tres_sign_dt, + f3.ttl_contb_per, + f3.ttl_contb_ref_per, + f3.net_contb_per, + f3.ttl_op_exp_per, + f3.ttl_offsets_to_op_exp_per, + f3.net_op_exp_per, + f3.coh_cop_i AS coh_cop_line_8, + GREATEST(f3.coh_cop_i, f3.coh_cop_ii) AS coh_cop, + f3.debts_owed_to_cmte, + f3.debts_owed_by_cmte, + f3.indv_item_contb_per, + f3.indv_unitem_contb_per, + f3.ttl_indv_contb_per, + f3.pol_pty_cmte_contb_per, + f3.other_pol_cmte_contb_per, + f3.cand_contb_per, + f3.ttl_contb_column_ttl_per, + f3.tranf_from_other_auth_cmte_per, + f3.loans_made_by_cand_per, + f3.all_other_loans_per, + f3.ttl_loans_per, + f3.offsets_to_op_exp_per, + f3.other_receipts_per, + f3.ttl_receipts_per_i AS ttl_receipts_line_16, + GREATEST(f3.ttl_receipts_per_i, f3.ttl_receipts_ii) AS ttl_receipts_per, + f3.op_exp_per, + f3.tranf_to_other_auth_cmte_per, + f3.loan_repymts_cand_loans_per, + f3.loan_repymts_other_loans_per, + f3.ttl_loan_repymts_per, + f3.ref_indv_contb_per, + f3.ref_pol_pty_cmte_contb_per, + f3.ref_other_pol_cmte_contb_per, + f3.ttl_contb_ref_col_ttl_per, + f3.other_disb_per, + f3.ttl_disb_per_i AS ttl_disb_line_22, + GREATEST(f3.ttl_disb_per_i, f3.ttl_disb_per_ii) AS ttl_disb_per, + f3.coh_bop, + f3.ttl_receipts_ii AS ttl_receipts_line_24, + f3.subttl_per, + f3.ttl_disb_per_ii AS ttl_disb_line_26, + f3.coh_cop_ii AS coh_cop_line_27, + f3.ttl_contb_ytd, + f3.ttl_contb_ref_ytd, + f3.net_contb_ytd, + f3.ttl_op_exp_ytd, + f3.ttl_offsets_to_op_exp_ytd, + f3.net_op_exp_ytd, + f3.ttl_indv_item_contb_ytd, + f3.ttl_indv_unitem_contb_ytd, + f3.ttl_indv_contb_ytd, + f3.pol_pty_cmte_contb_ytd, + f3.other_pol_cmte_contb_ytd, + f3.cand_contb_ytd, + f3.ttl_contb_col_ttl_ytd, + f3.tranf_from_other_auth_cmte_ytd, + f3.loans_made_by_cand_ytd, + f3.all_other_loans_ytd, + f3.ttl_loans_ytd, + f3.offsets_to_op_exp_ytd, + f3.other_receipts_ytd, + f3.ttl_receipts_ytd, + f3.op_exp_ytd, + f3.tranf_to_other_auth_cmte_ytd, + f3.loan_repymts_cand_loans_ytd, + f3.loan_repymts_other_loans_ytd, + f3.ttl_loan_repymts_ytd, + f3.ref_indv_contb_ytd, + f3.ref_pol_pty_cmte_contb_ytd, + f3.ref_other_pol_cmte_contb_ytd, + f3.ref_ttl_contb_col_ttl_ytd, + f3.other_disb_ytd, + f3.ttl_disb_ytd, + f3.grs_rcpt_auth_cmte_prim, + f3.agr_amt_contrib_pers_fund_prim, + f3.grs_rcpt_min_pers_contrib_prim, + f3.grs_rcpt_auth_cmte_gen, + f3.agr_amt_pers_contrib_gen, + f3.grs_rcpt_min_pers_contrib_gen, + f3.cand_id, + f3.cand_nm, + f3.f3z1_rpt_tp, + f3.f3z1_rpt_tp_desc, + f3.begin_image_num, + f3.end_image_num, + 'F3'::character varying(8) AS form_tp, + f3.form_tp_desc, + f3.file_num, + f3.prev_file_num, + f3.mst_rct_file_num, + f3.sub_id, + CASE + WHEN (vs.orig_sub_id IS NOT NULL) THEN 'Y'::text + ELSE 'N'::text + END AS most_recent_filing_flag + FROM (disclosure.nml_form_3 f3 + LEFT JOIN disclosure.v_sum_and_det_sum_report vs ON ((f3.sub_id = vs.orig_sub_id))) + WHERE (f3.delete_ind IS NULL); + +ALTER TABLE public.fec_vsum_f3_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_vsum_f3_vw TO fec_read; + +-- ------------------ +-- fec_vsum_f3p_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_vsum_f3p_vw; +CREATE VIEW fec_vsum_f3p_vw AS + SELECT f3p.cmte_id, + f3p.cmte_nm, + f3p.cmte_st1, + f3p.cmte_st2, + f3p.cmte_city, + f3p.cmte_st, + f3p.cmte_zip, + f3p.addr_chg_flg, + f3p.activity_primary, + f3p.activity_general, + f3p.term_rpt_flag, + f3p.amndt_ind, + f3p.amndt_ind_desc, + f3p.rpt_tp, + f3p.rpt_tp_desc, + f3p.rpt_pgi, + f3p.rpt_pgi_desc, + f3p.election_dt, + f3p.election_st, + f3p.election_st_desc, + f3p.cvg_start_dt, + f3p.cvg_end_dt, + f3p.rpt_yr, + f3p.receipt_dt, + (f3p.rpt_yr + (f3p.rpt_yr % (2)::numeric)) AS election_cycle, + f3p.tres_sign_nm, + f3p.tres_sign_dt, + f3p.tres_l_nm, + f3p.tres_f_nm, + f3p.tres_m_nm, + f3p.tres_prefix, + f3p.tres_suffix, + f3p.coh_bop, + GREATEST(f3p.ttl_receipts_sum_page_per, f3p.ttl_receipts_per) AS ttl_receipts_per, + f3p.ttl_receipts_sum_page_per, + f3p.subttl_sum_page_per, + GREATEST(f3p.ttl_disb_sum_page_per, f3p.ttl_disb_per) AS ttl_disb_per, + f3p.ttl_disb_sum_page_per, + f3p.coh_cop, + f3p.debts_owed_to_cmte, + f3p.debts_owed_by_cmte, + f3p.exp_subject_limits, + f3p.net_contb_sum_page_per, + f3p.net_op_exp_sum_page_per, + f3p.fed_funds_per, + f3p.indv_item_contb_per, + f3p.indv_unitem_contb_per, + f3p.indv_contb_per AS ttl_indiv_contb_per, + f3p.pol_pty_cmte_contb_per, + f3p.other_pol_cmte_contb_per, + f3p.cand_contb_per, + f3p.ttl_contb_per, + f3p.tranf_from_affilated_cmte_per, + f3p.loans_received_from_cand_per, + f3p.other_loans_received_per, + f3p.ttl_loans_received_per, + f3p.offsets_to_op_exp_per, + f3p.offsets_to_fndrsg_exp_per, + f3p.offsets_to_legal_acctg_per, + f3p.ttl_offsets_to_op_exp_per, + f3p.other_receipts_per, + f3p.ttl_receipts_per AS ttl_receipts_per_line_22, + f3p.op_exp_per, + f3p.tranf_to_other_auth_cmte_per, + f3p.fndrsg_disb_per, + f3p.exempt_legal_acctg_disb_per, + f3p.repymts_loans_made_by_cand_per, + f3p.repymts_other_loans_per, + f3p.ttl_loan_repymts_made_per, + f3p.ref_indv_contb_per, + f3p.ref_pol_pty_cmte_contb_per, + f3p.ref_other_pol_cmte_contb_per, + f3p.ttl_contb_ref_per, + f3p.other_disb_per, + f3p.ttl_disb_per AS ttl_disb_per_line_30, + f3p.items_on_hand_liquidated, + f3p.alabama_per, + f3p.alaska_per, + f3p.arizona_per, + f3p.arkansas_per, + f3p.california_per, + f3p.colorado_per, + f3p.connecticut_per, + f3p.delaware_per, + f3p.district_columbia_per, + f3p.florida_per, + f3p.georgia_per, + f3p.hawaii_per, + f3p.idaho_per, + f3p.illinois_per, + f3p.indiana_per, + f3p.iowa_per, + f3p.kansas_per, + f3p.kentucky_per, + f3p.louisiana_per, + f3p.maine_per, + f3p.maryland_per, + f3p.massachusetts_per, + f3p.michigan_per, + f3p.minnesota_per, + f3p.mississippi_per, + f3p.missouri_per, + f3p.montana_per, + f3p.nebraska_per, + f3p.nevada_per, + f3p.new_hampshire_per, + f3p.new_jersey_per, + f3p.new_mexico_per, + f3p.new_york_per, + f3p.north_carolina_per, + f3p.north_dakota_per, + f3p.ohio_per, + f3p.oklahoma_per, + f3p.oregon_per, + f3p.pennsylvania_per, + f3p.rhode_island_per, + f3p.south_carolina_per, + f3p.south_dakota_per, + f3p.tennessee_per, + f3p.texas_per, + f3p.utah_per, + f3p.vermont_per, + f3p.virginia_per, + f3p.washington_per, + f3p.west_virginia_per, + f3p.wisconsin_per, + f3p.wyoming_per, + f3p.puerto_rico_per, + f3p.guam_per, + f3p.virgin_islands_per, + f3p.ttl_per, + f3p.fed_funds_ytd, + f3p.indv_item_contb_ytd, + f3p.indv_unitem_contb_ytd, + f3p.indv_contb_ytd, + f3p.pol_pty_cmte_contb_ytd, + f3p.other_pol_cmte_contb_ytd, + f3p.cand_contb_ytd, + f3p.ttl_contb_ytd, + f3p.tranf_from_affiliated_cmte_ytd, + f3p.loans_received_from_cand_ytd, + f3p.other_loans_received_ytd, + f3p.ttl_loans_received_ytd, + f3p.offsets_to_op_exp_ytd, + f3p.offsets_to_fndrsg_exp_ytd, + f3p.offsets_to_legal_acctg_ytd, + f3p.ttl_offsets_to_op_exp_ytd, + f3p.other_receipts_ytd, + f3p.ttl_receipts_ytd, + f3p.op_exp_ytd, + f3p.tranf_to_other_auth_cmte_ytd, + f3p.fndrsg_disb_ytd, + f3p.exempt_legal_acctg_disb_ytd, + f3p.repymts_loans_made_cand_ytd, + f3p.repymts_other_loans_ytd, + f3p.ttl_loan_repymts_made_ytd, + f3p.ref_indv_contb_ytd, + f3p.ref_pol_pty_cmte_contb_ytd, + f3p.ref_other_pol_cmte_contb_ytd, + f3p.ttl_contb_ref_ytd, + f3p.other_disb_ytd, + f3p.ttl_disb_ytd, + f3p.alabama_ytd, + f3p.alaska_ytd, + f3p.arizona_ytd, + f3p.arkansas_ytd, + f3p.california_ytd, + f3p.colorado_ytd, + f3p.connecticut_ytd, + f3p.delaware_ytd, + f3p.district_columbia_ytd, + f3p.florida_ytd, + f3p.georgia_ytd, + f3p.hawaii_ytd, + f3p.idaho_ytd, + f3p.illinois_ytd, + f3p.indiana_ytd, + f3p.iowa_ytd, + f3p.kansas_ytd, + f3p.kentucky_ytd, + f3p.louisiana_ytd, + f3p.maine_ytd, + f3p.maryland_ytd, + f3p.massachusetts_ytd, + f3p.michigan_ytd, + f3p.minnesota_ytd, + f3p.mississippi_ytd, + f3p.missouri_ytd, + f3p.montana_ytd, + f3p.nebraska_ytd, + f3p.nevada_ytd, + f3p.new_hampshire_ytd, + f3p.new_jersey_ytd, + f3p.new_mexico_ytd, + f3p.new_york_ytd, + f3p.north_carolina_ytd, + f3p.north_dakota_ytd, + f3p.ohio_ytd, + f3p.oklahoma_ytd, + f3p.oregon_ytd, + f3p.pennsylvania_ytd, + f3p.rhode_island_ytd, + f3p.south_carolina_ytd, + f3p.south_dakota_ytd, + f3p.tennessee_ytd, + f3p.texas_ytd, + f3p.utah_ytd, + f3p.vermont_ytd, + f3p.virginia_ytd, + f3p.washington_ytd, + f3p.west_virginia_ytd, + f3p.wisconsin_ytd, + f3p.wyoming_ytd, + f3p.puerto_rico_ytd, + f3p.guam_ytd, + f3p.virgin_islands_ytd, + f3p.ttl_ytd, + f3p.begin_image_num, + f3p.end_image_num, + 'F3P'::character varying(8) AS form_tp, + f3p.form_tp_desc, + f3p.file_num, + f3p.prev_file_num, + f3p.mst_rct_file_num, + f3p.sub_id, + CASE + WHEN (vs.orig_sub_id IS NOT NULL) THEN 'Y'::text + ELSE 'N'::text + END AS most_recent_filing_flag + FROM (disclosure.nml_form_3p f3p + LEFT JOIN disclosure.v_sum_and_det_sum_report vs ON ((f3p.sub_id = vs.orig_sub_id))) + WHERE (f3p.delete_ind IS NULL); + +ALTER TABLE public.fec_vsum_f3p_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_vsum_f3p_vw TO fec_read; +-- ------------------ +-- fec_vsum_f3ps_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_vsum_f3ps_vw; +CREATE VIEW public.fec_vsum_f3ps_vw AS + SELECT f3ps.cmte_id, + f3ps.cmte_nm, + f3ps.election_dt, + f3ps.day_after_election_dt, + f3ps.net_contb, + f3ps.net_exp, + f3ps.fed_funds, + f3ps.indv_item_contb, + f3ps.indv_unitem_contb, + f3ps.indv_contb, + f3ps.pol_pty_cmte_contb, + f3ps.pac_contb, + f3ps.cand_contb, + f3ps.ttl_contb, + f3ps.tranf_from_affiliated_cmte, + f3ps.loans_received_from_cand, + f3ps.other_loans_received, + f3ps.ttl_loans, + f3ps.op_exp, + f3ps.fndrsg_exp, + f3ps.legal_and_acctg_exp, + f3ps.ttl_offsets_to_op_exp, + f3ps.other_receipts, + f3ps.ttl_receipts, + f3ps.op_exp2, + f3ps.tranf_to_other_auth_cmte, + f3ps.fndrsg_disb, + f3ps.exempt_legal_and_acctg_disb, + f3ps.loan_repymts_made_by_cand, + f3ps.other_repymts, + f3ps.ttl_loan_repymts_made, + f3ps.ref_indv_contb, + f3ps.ref_pol_pty_contb, + f3ps.ref_other_pol_cmte_contb, + f3ps.ttl_contb_ref, + f3ps.other_disb, + f3ps.ttl_disb, + f3ps.alabama, + f3ps.alaska, + f3ps.arizona, + f3ps.arkansas, + f3ps.california, + f3ps.colorado, + f3ps.connecticut, + f3ps.delaware, + f3ps.district_columbia, + f3ps.florida, + f3ps.georgia, + f3ps.hawaii, + f3ps.idaho, + f3ps.illinois, + f3ps.indiana, + f3ps.iowa, + f3ps.kansas, + f3ps.kentucky, + f3ps.louisiana, + f3ps.maine, + f3ps.maryland, + f3ps.massachusetts, + f3ps.michigan, + f3ps.minnesota, + f3ps.mississippi, + f3ps.missouri, + f3ps.montana, + f3ps.nebraska, + f3ps.nevada, + f3ps.new_hampshire, + f3ps.new_jersey, + f3ps.new_mexico, + f3ps.new_york, + f3ps.north_carolina, + f3ps.north_dakota, + f3ps.ohio, + f3ps.oklahoma, + f3ps.oregon, + f3ps.pennsylvania, + f3ps.rhode_island, + f3ps.south_carolina, + f3ps.south_dakota, + f3ps.tennessee, + f3ps.texas, + f3ps.utah, + f3ps.vermont, + f3ps.virginia, + f3ps.washington, + f3ps.west_virginia, + f3ps.wisconsin, + f3ps.wyoming, + f3ps.puerto_rico, + f3ps.guam, + f3ps.virgin_islands, + f3ps.ttl, + f3ps.file_num, + f3ps.link_id, + f3ps.image_num, + 'F3PS'::character varying(8) AS form_tp, + f3ps.form_tp_desc, + f3ps.sub_id, + f3p.receipt_dt, + f3p.rpt_tp, + f3p.rpt_yr, + (f3p.rpt_yr + (f3p.rpt_yr % (2)::numeric)) AS election_cycle, + CASE + WHEN (vs.orig_sub_id IS NOT NULL) THEN 'Y'::text + ELSE 'N'::text + END AS most_recent_filing_flag + FROM ((disclosure.nml_form_3ps f3ps + LEFT JOIN disclosure.v_sum_and_det_sum_report vs ON ((f3ps.link_id = vs.orig_sub_id))) + JOIN disclosure.nml_form_3p f3p ON ((f3ps.link_id = f3p.sub_id))) + WHERE (f3ps.delete_ind IS NULL); + +ALTER TABLE public.fec_vsum_f3ps_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_vsum_f3ps_vw TO fec_read; +-- ------------------ +-- fec_vsum_f3s_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_vsum_f3s_vw; +CREATE VIEW fec_vsum_f3s_vw AS + SELECT f3s.cmte_id, + f3s.cmte_nm, + f3s.election_dt, + f3s.day_after_election_dt, + f3s.ttl_contb, + f3s.ttl_contb_ref, + f3s.net_contb, + f3s.ttl_op_exp, + f3s.ttl_offsets_to_op_exp, + f3s.net_op_exp, + f3s.indv_item_contb, + f3s.indv_unitem_contb, + f3s.ttl_indv_contb, + f3s.pol_pty_cmte_contb, + f3s.other_pol_cmte_contb, + f3s.cand_contb, + f3s.ttl_contb_column_ttl, + f3s.tranf_from_other_auth_cmte, + f3s.loans_made_by_cand, + f3s.all_other_loans, + f3s.ttl_loans, + f3s.offsets_to_op_exp, + f3s.other_receipts, + f3s.ttl_receipts, + f3s.op_exp, + f3s.tranf_to_other_auth_cmte, + f3s.loan_repymts_cand_loans, + f3s.loan_repymts_other_loans, + f3s.ttl_loan_repymts, + f3s.ref_indv_contb, + f3s.ref_pol_pty_cmte_contb, + f3s.ref_other_pol_cmte_contb, + f3s.ttl_contb_ref_col_ttl, + f3s.other_disb, + f3s.ttl_disb, + f3s.file_num, + f3s.link_id, + f3s.image_num, + 'F3S'::character varying(8) AS form_tp, + f3s.form_tp_desc, + f3s.amndt_ind AS action_cd, + f3s.amndt_ind_desc AS action_cd_desc, + f3s.sub_id, + f3.receipt_dt, + f3.rpt_tp, + f3.rpt_yr, + (f3.rpt_yr + (f3.rpt_yr % (2)::numeric)) AS election_cycle, + CASE + WHEN (vs.orig_sub_id IS NOT NULL) THEN 'Y'::text + ELSE 'N'::text + END AS most_recent_filing_flag + FROM ((disclosure.nml_form_3s f3s + LEFT JOIN disclosure.v_sum_and_det_sum_report vs ON ((f3s.sub_id = vs.orig_sub_id))) + JOIN disclosure.nml_form_3 f3 ON ((f3s.link_id = f3.sub_id))) + WHERE (f3s.delete_ind IS NULL); + +ALTER TABLE public.fec_vsum_f3s_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_vsum_f3s_vw TO fec_read; +-- ------------------ +-- fec_vsum_f3x_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_vsum_f3x_vw; +CREATE VIEW public.fec_vsum_f3x_vw AS + SELECT f3x.cmte_id, + f3x.cmte_nm, + f3x.cmte_st1, + f3x.cmte_st2, + f3x.cmte_city, + f3x.cmte_st, + f3x.cmte_zip, + f3x.cmte_addr_chg_flg, + f3x.qual_cmte_flg, + f3x.amndt_ind, + f3x.amndt_ind_desc, + f3x.rpt_tp, + f3x.rpt_tp_desc, + f3x.rpt_pgi, + f3x.rpt_pgi_desc, + f3x.election_dt, + f3x.election_st, + f3x.election_st_desc, + f3x.cvg_start_dt, + f3x.cvg_end_dt, + f3x.rpt_yr, + f3x.receipt_dt, + (f3x.rpt_yr + (f3x.rpt_yr % (2)::numeric)) AS election_cycle, + f3x.tres_sign_nm, + f3x.tres_sign_dt, + f3x.tres_l_nm, + f3x.tres_f_nm, + f3x.tres_m_nm, + f3x.tres_prefix, + f3x.tres_suffix, + f3x.multicand_flg, + f3x.coh_bop, + GREATEST(f3x.ttl_receipts_sum_page_per, f3x.ttl_receipts_per) AS ttl_receipts, + f3x.ttl_receipts_sum_page_per, + f3x.subttl_sum_page_per, + GREATEST(f3x.ttl_disb_sum_page_per, f3x.ttl_disb_per) AS ttl_disb, + f3x.ttl_disb_sum_page_per, + f3x.coh_cop, + f3x.debts_owed_to_cmte, + f3x.debts_owed_by_cmte, + f3x.indv_item_contb_per, + f3x.indv_unitem_contb_per, + f3x.ttl_indv_contb, + f3x.pol_pty_cmte_contb_per_i, + f3x.other_pol_cmte_contb_per_i, + f3x.ttl_contb_col_ttl_per, + f3x.tranf_from_affiliated_pty_per, + f3x.all_loans_received_per, + f3x.loan_repymts_received_per, + GREATEST(f3x.offsets_to_op_exp_per_i, f3x.offsets_to_op_exp_per_ii) AS offests_to_op_exp, + f3x.offsets_to_op_exp_per_i AS offests_to_op_exp_line_15, + f3x.fed_cand_contb_ref_per, + f3x.other_fed_receipts_per, + f3x.tranf_from_nonfed_acct_per, + f3x.tranf_from_nonfed_levin_per, + f3x.ttl_nonfed_tranf_per, + f3x.ttl_receipts_per AS ttl_receipts_per_line_19, + f3x.ttl_fed_receipts_per, + f3x.shared_fed_op_exp_per, + f3x.shared_nonfed_op_exp_per, + f3x.other_fed_op_exp_per, + f3x.ttl_op_exp_per, + f3x.tranf_to_affliliated_cmte_per, + f3x.fed_cand_cmte_contb_per, + f3x.indt_exp_per, + f3x.coord_exp_by_pty_cmte_per, + f3x.loan_repymts_made_per, + f3x.loans_made_per, + f3x.indv_contb_ref_per, + f3x.pol_pty_cmte_contb_per_ii AS pol_pty_cmte_refund, + f3x.other_pol_cmte_contb_per_ii AS other_pol_cmte_refund, + GREATEST(f3x.ttl_contb_ref_per_i, f3x.ttl_contb_ref_per_ii) AS ttl_contb_refund, + f3x.ttl_contb_ref_per_i AS ttl_contb_refund_line_28d, + f3x.other_disb_per, + f3x.shared_fed_actvy_fed_shr_per, + f3x.shared_fed_actvy_nonfed_per, + f3x.non_alloc_fed_elect_actvy_per, + f3x.ttl_fed_elect_actvy_per, + f3x.ttl_disb_per AS ttl_disb_per_line_31, + f3x.ttl_fed_disb_per, + f3x.ttl_contb_per, + f3x.ttl_contb_ref_per_ii AS ttl_contb_refund_line_34, + f3x.net_contb_per, + f3x.ttl_fed_op_exp_per, + f3x.offsets_to_op_exp_per_ii AS offests_to_op_exp_line_37, + f3x.net_op_exp_per, + f3x.coh_begin_calendar_yr, + f3x.calendar_yr, + f3x.ttl_receipts_sum_page_ytd, + f3x.subttl_sum_ytd, + f3x.ttl_disb_sum_page_ytd, + f3x.coh_coy, + f3x.indv_item_contb_ytd, + f3x.indv_unitem_contb_ytd, + f3x.ttl_indv_contb_ytd, + f3x.pol_pty_cmte_contb_ytd_i, + f3x.other_pol_cmte_contb_ytd_i, + f3x.ttl_contb_col_ttl_ytd, + f3x.tranf_from_affiliated_pty_ytd, + f3x.all_loans_received_ytd, + f3x.loan_repymts_received_ytd, + f3x.offsets_to_op_exp_ytd_i, + f3x.fed_cand_cmte_contb_ytd, + f3x.other_fed_receipts_ytd, + f3x.tranf_from_nonfed_acct_ytd, + f3x.tranf_from_nonfed_levin_ytd, + f3x.ttl_nonfed_tranf_ytd, + f3x.ttl_receipts_ytd, + f3x.ttl_fed_receipts_ytd, + f3x.shared_fed_op_exp_ytd, + f3x.shared_nonfed_op_exp_ytd, + f3x.other_fed_op_exp_ytd, + f3x.ttl_op_exp_ytd, + f3x.tranf_to_affilitated_cmte_ytd, + f3x.fed_cand_cmte_contb_ref_ytd, + f3x.indt_exp_ytd, + f3x.coord_exp_by_pty_cmte_ytd, + f3x.loan_repymts_made_ytd, + f3x.loans_made_ytd, + f3x.indv_contb_ref_ytd, + f3x.pol_pty_cmte_contb_ytd_ii AS pol_pty_cmte_refund_ytd, + f3x.other_pol_cmte_contb_ytd_ii AS other_pol_cmte_refund_ytd, + f3x.ttl_contb_ref_ytd_i AS ttl_contb_refund_ytd, + f3x.other_disb_ytd, + f3x.shared_fed_actvy_fed_shr_ytd, + f3x.shared_fed_actvy_nonfed_ytd, + f3x.non_alloc_fed_elect_actvy_ytd, + f3x.ttl_fed_elect_actvy_ytd, + f3x.ttl_disb_ytd, + f3x.ttl_fed_disb_ytd, + f3x.ttl_contb_ytd, + f3x.ttl_contb_ref_ytd_ii, + f3x.net_contb_ytd, + f3x.ttl_fed_op_exp_ytd, + f3x.offsets_to_op_exp_ytd_ii, + f3x.net_op_exp_ytd, + f3x.begin_image_num, + f3x.end_image_num, + 'F3X'::character varying(8) AS form_tp, + f3x.form_tp_desc, + f3x.file_num, + f3x.prev_file_num, + f3x.mst_rct_file_num, + f3x.sub_id, + CASE + WHEN (vs.orig_sub_id IS NOT NULL) THEN 'Y'::text + ELSE 'N'::text + END AS most_recent_filing_flag + FROM (disclosure.nml_form_3x f3x + LEFT JOIN disclosure.v_sum_and_det_sum_report vs ON ((f3x.sub_id = vs.orig_sub_id))) + WHERE (f3x.delete_ind IS NULL); + +ALTER TABLE public.fec_vsum_f3x_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_vsum_f3x_vw TO fec_read; +-- ------------------ +-- fec_vsum_f7_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_vsum_f7_vw; +CREATE VIEW public.fec_vsum_f7_vw AS + SELECT f7.org_id, + f7.org_nm, + f7.org_st1, + f7.org_st2, + f7.org_city, + f7.org_st, + f7.org_zip, + f7.org_tp, + f7.org_tp_desc, + f7.rpt_tp, + f7.rpt_tp_desc, + f7.rpt_pgi, + f7.rpt_pgi_desc, + f7.amdnt_ind, + f7.amndt_ind_desc, + f7.election_dt, + f7.election_st, + f7.election_st_desc, + f7.cvg_start_dt, + f7.cvg_end_dt, + f7.ttl_communication_cost, + f7.filer_sign_nm, + f7.filer_l_nm, + f7.filer_f_nm, + f7.filer_m_nm, + f7.filer_prefix, + f7.filer_suffix, + f7.filer_sign_dt, + f7.filer_title, + f7.receipt_dt, + f7.rpt_yr, + (f7.rpt_yr + (f7.rpt_yr % (2)::numeric)) AS election_cycle, + f7.begin_image_num, + f7.end_image_num, + 'F7'::character varying(8) AS form_tp, + f7.form_tp_desc, + f7.file_num, + f7.prev_file_num, + f7.mst_rct_file_num, + f7.sub_id, + CASE + WHEN (vs.orig_sub_id IS NOT NULL) THEN 'Y'::text + ELSE 'N'::text + END AS most_recent_filing_flag + FROM (disclosure.nml_form_7 f7 + LEFT JOIN disclosure.v_sum_and_det_sum_report vs ON ((f7.sub_id = vs.orig_sub_id))) + WHERE (f7.delete_ind IS NULL); + +ALTER TABLE public.fec_vsum_f7_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_vsum_f7_vw TO fec_read; +-- ------------------ +-- fec_vsum_f9_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_vsum_f9_vw; +CREATE VIEW public.fec_vsum_f9_vw AS + SELECT f9.cmte_id, + f9.ind_org_corp_nm, + f9.indv_l_nm, + f9.indv_f_nm, + f9.indv_m_nm, + f9.indv_prefix, + f9.indv_suffix, + f9.ind_org_corp_st1, + f9.ind_org_corp_st2, + f9.ind_org_corp_city, + f9.ind_org_corp_st, + f9.ind_org_corp_st_desc, + f9.ind_org_corp_zip, + f9.entity_tp, + f9.addr_chg_flg, + f9.addr_chg_flg_desc, + f9.ind_org_corp_emp, + f9.ind_org_corp_occup, + f9.amndt_ind, + f9.rpt_tp, + f9.beg_cvg_dt, + f9.end_cvg_dt, + f9.comm_title, + f9.pub_distrib_dt, + f9.qual_nonprofit_flg, + f9.qual_nonprofit_flg_desc, + f9.segr_bank_acct_flg, + f9.segr_bank_acct_flg_desc, + f9.ind_custod_nm, + f9.cust_l_nm, + f9.cust_f_nm, + f9.cust_m_nm, + f9.cust_prefix, + f9.cust_suffix, + f9.ind_custod_st1, + f9.ind_custod_st2, + f9.ind_custod_city, + f9.ind_custod_st, + f9.ind_custod_st_desc, + f9.ind_custod_zip, + f9.ind_custod_emp, + f9.ind_custod_occup, + f9.ttl_dons_this_stmt, + f9.ttl_disb_this_stmt, + f9.filer_sign_nm, + f9.filer_l_nm, + f9.filer_f_nm, + f9.filer_m_nm, + f9.filer_prefix, + f9.filer_suffix, + f9.filer_sign_dt, + f9.filer_cd, + f9.filer_cd_desc, + f9.begin_image_num, + f9.end_image_num, + 'F9'::character varying(8) AS form_tp, + f9.form_tp_desc, + f9.receipt_dt, + f9.rpt_yr, + (f9.rpt_yr + (f9.rpt_yr % (2)::numeric)) AS election_cycle, + f9.file_num, + f9.prev_file_num, + f9.mst_rct_file_num, + f9.sub_id, + CASE + WHEN (vs.orig_sub_id IS NOT NULL) THEN 'Y'::text + ELSE 'N'::text + END AS most_recent_filing_flag + FROM (disclosure.nml_form_9 f9 + LEFT JOIN disclosure.v_sum_and_det_sum_report vs ON ((f9.sub_id = vs.orig_sub_id))) + WHERE (f9.delete_ind IS NULL); + +ALTER TABLE public.fec_vsum_f9_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_vsum_f9_vw TO fec_read; + + \ No newline at end of file diff --git a/webservices/flow.py b/webservices/flow.py index 488e20997..69af9fe3b 100644 --- a/webservices/flow.py +++ b/webservices/flow.py @@ -99,9 +99,7 @@ def get_graph(): ]) graph.add_edges_from([ - ('totals_house_senate', 'candidate_aggregates'), - ('totals_presidential', 'candidate_aggregates'), - ('candidate_election', 'candidate_aggregates'), + ('totals_combined', 'candidate_aggregates'), ('cand_cmte_linkage', 'candidate_aggregates'), ('cand_cmte_linkage', 'candidate_history'), ]) From 36a572deb06830adc9fd1226c33425572598f9fd Mon Sep 17 00:00:00 2001 From: Jean Date: Fri, 13 Sep 2019 14:49:47 -0400 Subject: [PATCH 5/8] drop unused views, correct views with column data type unknown, switch MV definition to use base tables. --- ...c_communication_cost_mv_replace_source.sql | 54 ++-- ...ct_views_with_column_data_type_unknown.sql | 282 ++++++++++-------- 2 files changed, 167 insertions(+), 169 deletions(-) diff --git a/data/migrations/V0161__ofec_communication_cost_mv_replace_source.sql b/data/migrations/V0161__ofec_communication_cost_mv_replace_source.sql index fb5a2974e..223fc0c5a 100644 --- a/data/migrations/V0161__ofec_communication_cost_mv_replace_source.sql +++ b/data/migrations/V0161__ofec_communication_cost_mv_replace_source.sql @@ -106,25 +106,6 @@ ALTER INDEX IF EXISTS idx_ofec_communication_cost_aggregate_candidate_mv_tmp_cyc ALTER INDEX IF EXISTS idx_ofec_communication_cost_aggregate_candidate_mv_tmp_total RENAME TO idx_ofec_communication_cost_aggregate_candidate_mv_total; -/* -SELECT f76.s_o_ind AS support_oppose_indicator, -f76.org_id AS cmte_id, -f76.s_o_cand_id AS cand_id, -sum(f76.communication_cost) AS total, -count(f76.communication_cost) AS count, -date_part('year'::text, f76.communication_dt)::integer + date_part('year'::text, f76.communication_dt)::integer % 2 AS cycle -FROM disclosure.fec_fitem_f76 as f76 -WHERE date_part('year'::text, f76.communication_dt) >= 1979::double precision AND f76.s_o_cand_id IS NOT NULL -GROUP BY f76.org_id, f76.s_o_cand_id, f76.s_o_ind, (date_part('year'::text, f76.communication_dt)::integer + date_part('year'::text, f76.communication_dt)::integer % 2) -except -select support_oppose_indicator, -cmte_id, -cand_id, -total, -count, -cycle -FROM public.ofec_communication_cost_aggregate_candidate_mv -*/ -- ------------------------------------------------ -- ofec_communication_cost_mv @@ -194,24 +175,6 @@ ALTER TABLE public.ofec_communication_cost_mv_tmp GRANT ALL ON TABLE public.ofec_communication_cost_mv_tmp TO fec; GRANT SELECT ON TABLE public.ofec_communication_cost_mv_tmp TO fec_read; --- -------------- --- recreate the view --- data type for column schedule_type in public.fec_fitem_f76_vw is undefined. --- data type for column schedule_type in disclosure.fec_fitem_f76 is varchar(8) --- can not repoint the view to the tmp MV with "CREATE OR REPLACE" --- Need to DROP and CREATE --- Since public.ofec_communication_cost_vw had no depending objects, it can be dropped and created without chain reaction -DROP VIEW public.ofec_communication_cost_vw; - -CREATE OR REPLACE VIEW public.ofec_communication_cost_vw AS - SELECT * FROM ofec_communication_cost_mv_tmp; - -ALTER TABLE public.ofec_communication_cost_vw - OWNER TO fec; -GRANT ALL ON TABLE public.ofec_communication_cost_vw TO fec; -GRANT SELECT ON TABLE public.ofec_communication_cost_vw TO fec_read; --- -------------- - -- indexes CREATE UNIQUE INDEX idx_ofec_communication_cost_mv_tmp_sub_id ON public.ofec_communication_cost_mv_tmp @@ -278,6 +241,23 @@ CREATE INDEX idx_ofec_communication_cost_mv_tmp_s_o_ind USING btree (s_o_ind COLLATE pg_catalog."default"); +-- -------------- +-- recreate the view +-- data type for column schedule_type in public.fec_fitem_f76_vw is undefined. +-- data type for column schedule_type in disclosure.fec_fitem_f76 is varchar(8) +-- can not repoint the view to the tmp MV with "CREATE OR REPLACE" +-- Need to DROP and CREATE +-- Since public.ofec_communication_cost_vw had no depending objects, it can be dropped and created without chain reaction +DROP VIEW public.ofec_communication_cost_vw; + +CREATE OR REPLACE VIEW public.ofec_communication_cost_vw AS + SELECT * FROM ofec_communication_cost_mv_tmp; + +ALTER TABLE public.ofec_communication_cost_vw + OWNER TO fec; +GRANT ALL ON TABLE public.ofec_communication_cost_vw TO fec; +GRANT SELECT ON TABLE public.ofec_communication_cost_vw TO fec_read; +-- -------------- -- drop old MV DROP MATERIALIZED VIEW IF EXISTS public.ofec_communication_cost_mv; diff --git a/data/migrations/V0164__correct_views_with_column_data_type_unknown.sql b/data/migrations/V0164__correct_views_with_column_data_type_unknown.sql index 20cd21f3e..cca99c473 100644 --- a/data/migrations/V0164__correct_views_with_column_data_type_unknown.sql +++ b/data/migrations/V0164__correct_views_with_column_data_type_unknown.sql @@ -10,9 +10,93 @@ This set of views need to be dropped for In addition, there are several views with columns of data type "unknown". In this ticket, this will be corrected. + fec_f5_notice_vw | form_tp + + fec_f56_notice_vw | filing_form + fec_f56_notice_vw | schedule_type + + fec_f57_notice_vw | filing_form + fec_f57_notice_vw | schedule_type + + fec_f65_notice_vw | filing_form + fec_f65_notice_vw | schedule_type + + fec_sched_e_notice_vw | filing_form + fec_sched_e_notice_vw | schedule_type + + fec_form_1m_vw | form_tp + fec_vsum_f2_vw | form_tp + fec_vsum_f3_vw | form_tp + fec_vsum_f3p_vw | form_tp + fec_vsum_f3ps_vw | form_tp + fec_vsum_f3s_vw | form_tp + fec_vsum_f3x_vw | form_tp + fec_vsum_f5_vw | form_tp + fec_vsum_f7_vw | form_tp + fec_vsum_f9_vw | form_tp */ -- ------------------ +-- fec_f5_notice_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_f5_notice_vw; +CREATE VIEW public.fec_f5_notice_vw AS + SELECT f5.indv_org_id, + f5.indv_org_nm, + f5.indv_l_nm, + f5.indv_f_nm, + f5.indv_m_nm, + f5.indv_prefix, + f5.indv_suffix, + f5.indv_org_st1, + f5.indv_org_st2, + f5.indv_org_city, + f5.indv_org_st, + f5.indv_org_zip, + f5.entity_tp, + f5.addr_chg_flg, + f5.qual_nonprofit_corp_ind, + f5.indv_org_employer, + f5.indv_org_occupation, + f5.amndt_ind, + f5.amndt_ind_desc, + f5.orig_amndt_dt, + f5.rpt_tp, + f5.rpt_tp_desc, + f5.rpt_pgi, + f5.rpt_pgi_desc, + f5.cvg_start_dt, + f5.cvg_end_dt, + f5.rpt_yr, + f5.receipt_dt, + (f5.rpt_yr + mod(f5.rpt_yr, (2)::numeric)) AS cycle, + f5.ttl_indt_contb, + f5.ttl_indt_exp, + f5.filer_nm, + f5.filer_sign_nm, + f5.filer_sign_dt, + f5.filer_l_nm, + f5.filer_f_nm, + f5.filer_m_nm, + f5.filer_prefix, + f5.filer_suffix, + f5.notary_sign_dt, + f5.notary_commission_exprtn_dt, + f5.notary_nm, + f5.sub_id, + f5.begin_image_num, + f5.end_image_num, + 'F5'::character varying(8) AS form_tp, + f5.form_tp_desc, + f5.file_num, + f5.prev_file_num, + f5.mst_rct_file_num + FROM disclosure.nml_form_5 f5 + WHERE ((f5.delete_ind IS NULL) AND ((f5.rpt_tp)::text = ANY (ARRAY[('24'::character varying)::text, ('48'::character varying)::text]))); + +ALTER TABLE public.fec_f5_notice_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_f5_notice_vw TO fec_read; +-------------------- -- fec_f56_notice_vw -- ------------------ DROP VIEW IF EXISTS public.fec_f56_notice_vw; @@ -70,11 +154,9 @@ CREATE VIEW public.fec_f56_notice_vw AS disclosure.nml_form_5 f5 WHERE ((f56.link_id = f5.sub_id) AND ((f5.rpt_tp)::text = ANY (ARRAY[('24'::character varying)::text, ('48'::character varying)::text])) AND ((f56.amndt_ind)::text <> 'D'::text) AND (f56.delete_ind IS NULL) AND (f5.delete_ind IS NULL)); - ALTER TABLE public.fec_f56_notice_vw OWNER TO fec; GRANT SELECT ON TABLE public.fec_f56_notice_vw TO fec_read; - -- ------------------ -- fec_f57_notice_vw -- ------------------ @@ -148,71 +230,9 @@ CREATE VIEW public.fec_f57_notice_vw AS disclosure.nml_form_5 f5 WHERE ((f57.link_id = f5.sub_id) AND ((f5.rpt_tp)::text = ANY (ARRAY[('24'::character varying)::text, ('48'::character varying)::text])) AND ((f57.amndt_ind)::text <> 'D'::text) AND (f57.delete_ind IS NULL) AND (f5.delete_ind IS NULL)); - ALTER TABLE public.fec_f57_notice_vw OWNER TO fec; GRANT SELECT ON TABLE public.fec_f57_notice_vw TO fec_read; --- ------------------ --- fec_f5_notice_vw --- ------------------ -DROP VIEW IF EXISTS public.fec_f5_notice_vw; -CREATE VIEW public.fec_f5_notice_vw AS - SELECT f5.indv_org_id, - f5.indv_org_nm, - f5.indv_l_nm, - f5.indv_f_nm, - f5.indv_m_nm, - f5.indv_prefix, - f5.indv_suffix, - f5.indv_org_st1, - f5.indv_org_st2, - f5.indv_org_city, - f5.indv_org_st, - f5.indv_org_zip, - f5.entity_tp, - f5.addr_chg_flg, - f5.qual_nonprofit_corp_ind, - f5.indv_org_employer, - f5.indv_org_occupation, - f5.amndt_ind, - f5.amndt_ind_desc, - f5.orig_amndt_dt, - f5.rpt_tp, - f5.rpt_tp_desc, - f5.rpt_pgi, - f5.rpt_pgi_desc, - f5.cvg_start_dt, - f5.cvg_end_dt, - f5.rpt_yr, - f5.receipt_dt, - (f5.rpt_yr + mod(f5.rpt_yr, (2)::numeric)) AS cycle, - f5.ttl_indt_contb, - f5.ttl_indt_exp, - f5.filer_nm, - f5.filer_sign_nm, - f5.filer_sign_dt, - f5.filer_l_nm, - f5.filer_f_nm, - f5.filer_m_nm, - f5.filer_prefix, - f5.filer_suffix, - f5.notary_sign_dt, - f5.notary_commission_exprtn_dt, - f5.notary_nm, - f5.sub_id, - f5.begin_image_num, - f5.end_image_num, - 'F5'::character varying(8) AS form_tp, - f5.form_tp_desc, - f5.file_num, - f5.prev_file_num, - f5.mst_rct_file_num - FROM disclosure.nml_form_5 f5 - WHERE ((f5.delete_ind IS NULL) AND ((f5.rpt_tp)::text = ANY (ARRAY[('24'::character varying)::text, ('48'::character varying)::text]))); - - -ALTER TABLE public.fec_f5_notice_vw OWNER TO fec; -GRANT SELECT ON TABLE public.fec_f5_notice_vw TO fec_read; -- ------------------ -- fec_f65_notice_vw -- ------------------ @@ -271,7 +291,6 @@ CREATE VIEW public.fec_f65_notice_vw AS disclosure.nml_form_6 f6 WHERE ((f65.link_id = f6.sub_id) AND ((f65.amndt_ind)::text <> 'D'::text) AND (f65.delete_ind IS NULL) AND (f6.delete_ind IS NULL)); - ALTER TABLE public.fec_f65_notice_vw OWNER TO fec; GRANT SELECT ON TABLE public.fec_f65_notice_vw TO fec_read; @@ -370,76 +389,9 @@ CREATE VIEW public.fec_sched_e_notice_vw AS disclosure.nml_form_24 f24 WHERE ((se.link_id = f24.sub_id) AND (f24.delete_ind IS NULL) AND (se.delete_ind IS NULL) AND ((se.amndt_ind)::text <> 'D'::text)); - ALTER TABLE public.fec_sched_e_notice_vw OWNER TO fec; GRANT SELECT ON TABLE public.fec_sched_e_notice_vw TO fec_read; --- ------------------ --- fec_vsum_f5_vw --- ------------------ -DROP VIEW IF EXISTS public.fec_vsum_f5_vw; -CREATE VIEW public.fec_vsum_f5_vw AS - SELECT f5.indv_org_id, - f5.indv_org_nm, - f5.indv_l_nm, - f5.indv_f_nm, - f5.indv_m_nm, - f5.indv_prefix, - f5.indv_suffix, - f5.indv_org_st1, - f5.indv_org_st2, - f5.indv_org_city, - f5.indv_org_st, - f5.indv_org_zip, - f5.entity_tp, - f5.addr_chg_flg, - f5.qual_nonprofit_corp_ind, - f5.indv_org_employer, - f5.indv_org_occupation, - f5.amndt_ind, - f5.amndt_ind_desc, - f5.orig_amndt_dt, - f5.rpt_tp, - f5.rpt_tp_desc, - f5.rpt_pgi, - f5.rpt_pgi_desc, - f5.cvg_start_dt, - f5.cvg_end_dt, - f5.rpt_yr, - f5.receipt_dt, - (f5.rpt_yr + mod(f5.rpt_yr, (2)::numeric)) AS election_cycle, - f5.ttl_indt_contb, - f5.ttl_indt_exp, - f5.filer_nm, - f5.filer_sign_nm, - f5.filer_sign_dt, - f5.filer_l_nm, - f5.filer_f_nm, - f5.filer_m_nm, - f5.filer_prefix, - f5.filer_suffix, - f5.notary_sign_dt, - f5.notary_commission_exprtn_dt, - f5.notary_nm, - f5.begin_image_num, - f5.end_image_num, - 'F5'::character varying(8) AS form_tp, - f5.form_tp_desc, - f5.file_num, - f5.prev_file_num, - f5.mst_rct_file_num, - f5.sub_id, - CASE - WHEN (vs.orig_sub_id IS NOT NULL) THEN 'Y'::text - ELSE 'N'::text - END AS most_recent_filing_flag - FROM (disclosure.nml_form_5 f5 - LEFT JOIN disclosure.v_sum_and_det_sum_report vs ON ((f5.sub_id = vs.orig_sub_id))) - WHERE ((f5.delete_ind IS NULL) AND ((f5.rpt_tp)::text <> ALL (ARRAY[('24'::character varying)::text, ('48'::character varying)::text]))); - -ALTER TABLE public.fec_vsum_f5_vw OWNER TO fec; -GRANT SELECT ON TABLE public.fec_vsum_f5_vw TO fec_read; - -- ------------------ -- fec_form_1m_vw -- ------------------ @@ -1361,6 +1313,72 @@ CREATE VIEW public.fec_vsum_f3x_vw AS ALTER TABLE public.fec_vsum_f3x_vw OWNER TO fec; GRANT SELECT ON TABLE public.fec_vsum_f3x_vw TO fec_read; +-- ------------------ +-- fec_vsum_f5_vw +-- ------------------ +DROP VIEW IF EXISTS public.fec_vsum_f5_vw; +CREATE VIEW public.fec_vsum_f5_vw AS + SELECT f5.indv_org_id, + f5.indv_org_nm, + f5.indv_l_nm, + f5.indv_f_nm, + f5.indv_m_nm, + f5.indv_prefix, + f5.indv_suffix, + f5.indv_org_st1, + f5.indv_org_st2, + f5.indv_org_city, + f5.indv_org_st, + f5.indv_org_zip, + f5.entity_tp, + f5.addr_chg_flg, + f5.qual_nonprofit_corp_ind, + f5.indv_org_employer, + f5.indv_org_occupation, + f5.amndt_ind, + f5.amndt_ind_desc, + f5.orig_amndt_dt, + f5.rpt_tp, + f5.rpt_tp_desc, + f5.rpt_pgi, + f5.rpt_pgi_desc, + f5.cvg_start_dt, + f5.cvg_end_dt, + f5.rpt_yr, + f5.receipt_dt, + (f5.rpt_yr + mod(f5.rpt_yr, (2)::numeric)) AS election_cycle, + f5.ttl_indt_contb, + f5.ttl_indt_exp, + f5.filer_nm, + f5.filer_sign_nm, + f5.filer_sign_dt, + f5.filer_l_nm, + f5.filer_f_nm, + f5.filer_m_nm, + f5.filer_prefix, + f5.filer_suffix, + f5.notary_sign_dt, + f5.notary_commission_exprtn_dt, + f5.notary_nm, + f5.begin_image_num, + f5.end_image_num, + 'F5'::character varying(8) AS form_tp, + f5.form_tp_desc, + f5.file_num, + f5.prev_file_num, + f5.mst_rct_file_num, + f5.sub_id, + CASE + WHEN (vs.orig_sub_id IS NOT NULL) THEN 'Y'::text + ELSE 'N'::text + END AS most_recent_filing_flag + FROM (disclosure.nml_form_5 f5 + LEFT JOIN disclosure.v_sum_and_det_sum_report vs ON ((f5.sub_id = vs.orig_sub_id))) + WHERE ((f5.delete_ind IS NULL) AND ((f5.rpt_tp)::text <> ALL (ARRAY[('24'::character varying)::text, ('48'::character varying)::text]))); + +ALTER TABLE public.fec_vsum_f5_vw OWNER TO fec; +GRANT SELECT ON TABLE public.fec_vsum_f5_vw TO fec_read; + -- ------------------ -- fec_vsum_f7_vw -- ------------------ From 124a80c7ac43cb66dcf5ca8b9e868473d5375ea5 Mon Sep 17 00:00:00 2001 From: Jason Upchurch Date: Fri, 13 Sep 2019 17:14:43 -0400 Subject: [PATCH 6/8] update python version to 3.7.4 in runtime.txt, config.yml, and related requirements files add manual deploy step squash commit history; update python to 3.7.4 --- .circleci/config.yml | 2 +- README.md | 2 +- requirements-dev.txt | 2 +- requirements.txt | 4 ++-- runtime.txt | 2 +- 5 files changed, 6 insertions(+), 6 deletions(-) diff --git a/.circleci/config.yml b/.circleci/config.yml index 69fa61262..3baa4768f 100644 --- a/.circleci/config.yml +++ b/.circleci/config.yml @@ -9,7 +9,7 @@ jobs: # use `-browsers` prefix for selenium tests, e.g. `-browsers` # Python - - image: circleci/python:3.6.4-stretch + - image: circleci/python:3.7.4-buster environment: TZ: America/New_York SQLA_TEST_CONN: postgresql://postgres@0.0.0.0/cfdm_unit_test diff --git a/README.md b/README.md index f0e806c2a..2a5a3945f 100644 --- a/README.md +++ b/README.md @@ -44,7 +44,7 @@ We are always trying to improve our documentation. If you have suggestions or ru ### Project prerequisites 1. Ensure you have the following requirements installed: - * Python (the latest 3.6 release, which includes `pip` and and a built-in version of `virtualenv` called `venv`). + * Python (the 3.7.4 release, which includes `pip` and and a built-in version of `virtualenv` called `venv`). * The latest long term support (LTS) or stable release of Node.js (which includes npm) * PostgreSQL (the latest 9.6 release). * Read a [Mac OSX tutorial](https://www.moncefbelyamani.com/how-to-install-postgresql-on-a-mac-with-homebrew-and-lunchy/) diff --git a/requirements-dev.txt b/requirements-dev.txt index a3606e7c9..eab90a2c3 100644 --- a/requirements-dev.txt +++ b/requirements-dev.txt @@ -15,5 +15,5 @@ pygments==2.2.0 click==6.7 #efiling -pandas==0.16.2 +pandas==0.23.0 # this is a temporary upgrade to allow python 3.7.4--eventually pandas will be removed xlrd==0.9.4 diff --git a/requirements.txt b/requirements.txt index 5539fbd91..0f7c6e34d 100644 --- a/requirements.txt +++ b/requirements.txt @@ -15,8 +15,8 @@ networkx==1.11 SQLAlchemy==1.3.1 icalendar==3.9.1 GitPython==1.0.1 -gunicorn==19.7.1 -gevent==1.2.2 +gunicorn==19.9.0 +gevent==1.4.0 webargs==5.3.1 ujson==1.33 requests==2.21.0 diff --git a/runtime.txt b/runtime.txt index 62ce9c02a..42731f2fb 100644 --- a/runtime.txt +++ b/runtime.txt @@ -1 +1 @@ -python-3.6.x +python-3.7.4 From 049562ece6c23cdfea00f8ce2f0a1c9ec2174834 Mon Sep 17 00:00:00 2001 From: Jean Date: Wed, 25 Sep 2019 13:15:42 -0400 Subject: [PATCH 7/8] add ofec_sched_a_agg_state_mv --- .../V0165__ofec_sched_a_agg_state_mv.sql | 61 +++++++++++++++++++ manage.py | 1 + webservices/flow.py | 1 + 3 files changed, 63 insertions(+) create mode 100644 data/migrations/V0165__ofec_sched_a_agg_state_mv.sql diff --git a/data/migrations/V0165__ofec_sched_a_agg_state_mv.sql b/data/migrations/V0165__ofec_sched_a_agg_state_mv.sql new file mode 100644 index 000000000..71057adbf --- /dev/null +++ b/data/migrations/V0165__ofec_sched_a_agg_state_mv.sql @@ -0,0 +1,61 @@ +/* +This migration file solve issue #3970 ScheduleAByStateCandidateView slowness + +Originally, this endpoint use a view public.ofec_sched_a_agg_state_vw to sum up all the non-real state as 'OT' +Although views can not have indexes, they will take advantage from the indexes of its base tables. +However, the original query use a subquery and a view composed of multiple base tables and database optimizer somehow decided not to use the view's base tables' indexes and cause the slowness. +We can choose to re-write the query or create a MV to replace the view. + +There are more than one endpoints share the same function in resource file to generate final query, it would be less impact to create a MV to replace the view. +Also for better readability. + +Since this is a new MV, flow.py and manage.py had been updated to add the refresh of MV +*/ + +-- ------------------------------------------------ +-- ofec_sched_a_agg_state_mv +-- this is a new MATERIALIZED VIEW so there is no need to go through _tmp process +-- ------------------------------------------------ +DROP MATERIALIZED VIEW IF EXISTS public.ofec_sched_a_agg_state_mv; + +CREATE MATERIALIZED VIEW IF NOT EXISTS public.ofec_sched_a_agg_state_mv AS + SELECT sa.cmte_id, + sa.cycle, + COALESCE(st.st, 'OT'::character varying) AS state, + COALESCE(sa.state_full, 'Other'::text) AS state_full, + sum(sa.total) AS total, + sum(sa.count) AS count + FROM disclosure.dsc_sched_a_aggregate_state sa + LEFT JOIN staging.ref_st st ON sa.state::text = st.st::text + GROUP BY sa.cmte_id, sa.cycle, st.st, sa.state_full; + +ALTER TABLE public.ofec_sched_a_agg_state_mv OWNER TO fec; +GRANT ALL ON TABLE public.ofec_sched_a_agg_state_mv TO fec; +GRANT SELECT ON TABLE public.ofec_sched_a_agg_state_mv TO fec_read; + +-- indexes +CREATE UNIQUE INDEX idx_ofec_sched_a_agg_state_mv_cmte_id_cycle_state + ON public.ofec_sched_a_agg_state_mv + USING btree + (cmte_id, cycle, state); + +ANALYZE public.ofec_sched_a_agg_state_mv; + +-- ------------------ +-- recreate the view +-- the new MV removed one unnecessary column +-- (which was created for historical reason but we don't use it here) +-- max(sa.idx) AS idx +-- So view need to be recreate instead of create or replace +-- there is no other MV depending on this view, it is better to clean it now +-- ------------------ +DROP VIEW IF EXISTS public.ofec_sched_a_agg_state_vw; +CREATE OR REPLACE VIEW public.ofec_sched_a_agg_state_vw AS + SELECT * FROM public.ofec_sched_a_agg_state_mv; + +ALTER TABLE public.ofec_sched_a_agg_state_vw + OWNER TO fec; +GRANT ALL ON TABLE public.ofec_sched_a_agg_state_vw TO fec; +GRANT SELECT ON TABLE public.ofec_sched_a_agg_state_vw TO fec_read; + + diff --git a/manage.py b/manage.py index f5499a566..00193ca79 100755 --- a/manage.py +++ b/manage.py @@ -208,6 +208,7 @@ def refresh_materialized(concurrent=True): 'ofec_filings_mv', 'ofec_filings_all_mv'], 'ofec_agg_coverage_date': ['ofec_agg_coverage_date_mv'], + 'ofec_sched_a_agg_state': ['ofec_sched_a_agg_state_mv'], 'ofec_sched_e_mv': ['ofec_sched_e_mv'], 'reports_house_senate': ['ofec_reports_house_senate_mv'], 'reports_ie': ['ofec_reports_ie_only_mv'], diff --git a/webservices/flow.py b/webservices/flow.py index 69af9fe3b..16b231bda 100644 --- a/webservices/flow.py +++ b/webservices/flow.py @@ -31,6 +31,7 @@ def get_graph(): 'filing_amendments_presidential', 'filings', 'ofec_agg_coverage_date', + 'ofec_sched_a_agg_state', 'ofec_sched_e_mv', 'reports_house_senate', 'reports_ie', From dc46af5b4ca4050489883ec8459dd6b74e5261d9 Mon Sep 17 00:00:00 2001 From: Jean Date: Wed, 25 Sep 2019 16:35:46 -0400 Subject: [PATCH 8/8] add back the idx column to the mv/vw --- .../V0165__ofec_sched_a_agg_state_mv.sql | 36 +++++++++++++++---- 1 file changed, 29 insertions(+), 7 deletions(-) diff --git a/data/migrations/V0165__ofec_sched_a_agg_state_mv.sql b/data/migrations/V0165__ofec_sched_a_agg_state_mv.sql index 71057adbf..3d08c95af 100644 --- a/data/migrations/V0165__ofec_sched_a_agg_state_mv.sql +++ b/data/migrations/V0165__ofec_sched_a_agg_state_mv.sql @@ -12,6 +12,34 @@ Also for better readability. Since this is a new MV, flow.py and manage.py had been updated to add the refresh of MV */ +-- ------------------ +-- recreate the view +-- first edition: the new MV removed one column originally thought unnecessary +-- max(sa.idx) AS idx +-- So view need to be recreate instead of create or replace +-- +-- second edition: another endpoint do need to use the idx column. Add it back. +-- (the model ScheduleAByState inherits from BaseAggregate which inherits from BaseModel which references column idx) +-- since the orginal migration file already run, this view still need to be recreated. +-- ------------------ +DROP VIEW IF EXISTS public.ofec_sched_a_agg_state_vw; +CREATE OR REPLACE VIEW public.ofec_sched_a_agg_state_vw AS +SELECT sa.cmte_id, + sa.cycle, + COALESCE(st.st, 'OT'::character varying) AS state, + COALESCE(sa.state_full, 'Other'::text) AS state_full, + max(sa.idx) AS idx, + sum(sa.total) AS total, + sum(sa.count) AS count + FROM disclosure.dsc_sched_a_aggregate_state sa + LEFT JOIN staging.ref_st st ON sa.state::text = st.st::text + GROUP BY sa.cmte_id, sa.cycle, st.st, sa.state_full; + +ALTER TABLE public.ofec_sched_a_agg_state_vw + OWNER TO fec; +GRANT ALL ON TABLE public.ofec_sched_a_agg_state_vw TO fec; +GRANT SELECT ON TABLE public.ofec_sched_a_agg_state_vw TO fec_read; + -- ------------------------------------------------ -- ofec_sched_a_agg_state_mv -- this is a new MATERIALIZED VIEW so there is no need to go through _tmp process @@ -23,6 +51,7 @@ CREATE MATERIALIZED VIEW IF NOT EXISTS public.ofec_sched_a_agg_state_mv AS sa.cycle, COALESCE(st.st, 'OT'::character varying) AS state, COALESCE(sa.state_full, 'Other'::text) AS state_full, + max(sa.idx) AS idx, sum(sa.total) AS total, sum(sa.count) AS count FROM disclosure.dsc_sched_a_aggregate_state sa @@ -42,14 +71,7 @@ CREATE UNIQUE INDEX idx_ofec_sched_a_agg_state_mv_cmte_id_cycle_state ANALYZE public.ofec_sched_a_agg_state_mv; -- ------------------ --- recreate the view --- the new MV removed one unnecessary column --- (which was created for historical reason but we don't use it here) --- max(sa.idx) AS idx --- So view need to be recreate instead of create or replace --- there is no other MV depending on this view, it is better to clean it now -- ------------------ -DROP VIEW IF EXISTS public.ofec_sched_a_agg_state_vw; CREATE OR REPLACE VIEW public.ofec_sched_a_agg_state_vw AS SELECT * FROM public.ofec_sched_a_agg_state_mv;