RE: Running a Simple Update Statement Fails, Second Time Suceeds. - Mailing list pgsql-general
From | Kumar, Virendra |
---|---|
Subject | RE: Running a Simple Update Statement Fails, Second Time Suceeds. |
Date | |
Msg-id | 7f6d75f52c0a4ec4b87790c5e17a7d53@USFKL11XG20CN01.mercer.com Whole thread Raw |
In response to | Re: Running a Simple Update Statement Fails, Second Time Suceeds. ("Kumar, Virendra" <Virendra.Kumar@guycarp.com>) |
Responses |
Re: Running a Simple Update Statement Fails, Second Time Suceeds.
Re: Running a Simple Update Statement Fails, Second Time Suceeds. |
List | pgsql-general |
Here is function code: -- CREATE OR REPLACE FUNCTION sddf_update.tps_update_1(p_pres_id_in bigint, p_last_audit_update_dt_in timestamp without timezone, OUT p_err_code_out bigint, OUT p_err_mesg_out text, p_expiration_dt_in timestamp without time zone DEFAULT '1600-01-01'::date,p_audit_insert_user_name_tx_in character varying DEFAULT '0.000000001'::character varying, p_audit_update_user_name_tx_incharacter varying DEFAULT '0.000000001'::character varying, p_latest_version_in_in charactervarying DEFAULT '0'::character varying, p_delete_in_in character varying DEFAULT '0'::character varying, p_class_code_id_incharacter varying DEFAULT '0.000000001'::character varying, p_major_classification_cd_in character varyingDEFAULT '.000000001'::character varying, p_major_class_name_tx_in character varying DEFAULT '0.000000001'::charactervarying, p_coverage_short_name_tx_in character varying DEFAULT '0.000000001'::character varying,p_coverage_name_tx_in character varying DEFAULT '0.000000001'::character varying, p_cdt_source_system_cd_in charactervarying DEFAULT '0.000000001'::character varying, p_cdt_submitting_country_cd_in character varying DEFAULT '0.000000001'::charactervarying, p_cdt_status_cd_in character varying DEFAULT '0.000000001'::character varying, p_effective_dt_intimestamp without time zone DEFAULT '1600-01-01'::date) RETURNS record LANGUAGE plpgsql SECURITY DEFINER AS $function$ DECLARE ora2pg_rowcount int; lv_audit_update_dt product_owner.external_sys_class_code_pres.audit_update_dt%TYPE; --lv_audit_update_dt product_owner.external_sys_class_code_pres.audit_update_dt%TYPE; BEGIN UPDATE product_owner.external_sys_class_code_pres SET class_code_id = CASE WHEN p_class_code_id_in='0.000000001' THEN class_code_id ELSE p_class_code_id_in END , major_classification_cd = CASE WHEN p_major_classification_cd_in='.000000001' THEN major_classification_cd ELSE p_major_classification_cd_inEND , major_classification_name_tx = CASE WHEN p_major_class_name_tx_in='0.000000001' THEN major_classification_name_tx ELSE p_major_class_name_tx_inEND , coverage_short_name_tx = CASE WHEN p_coverage_short_name_tx_in='0.000000001' THEN coverage_short_name_tx ELSE p_coverage_short_name_tx_inEND , coverage_name_tx = CASE WHEN p_coverage_name_tx_in='0.000000001' THEN coverage_name_tx ELSE p_coverage_name_tx_in END , cdt_source_system_cd = CASE WHEN p_cdt_source_system_cd_in='0.000000001' THEN cdt_source_system_cd ELSE p_cdt_source_system_cd_inEND , cdt_submitting_country_cd = CASE WHEN p_cdt_submitting_country_cd_in='0.000000001' THEN cdt_submitting_country_cd ELSE p_cdt_submitting_country_cd_inEND , cdt_status_cd = CASE WHEN p_cdt_status_cd_in='0.000000001' THEN cdt_status_cd ELSE p_cdt_status_cd_in END , effective_dt = CASE WHEN p_effective_dt_in=TO_DATE('01/01/1600', 'mm/dd/yyyy') THEN effective_dt ELSE p_effective_dt_inEND , expiration_dt = CASE WHEN p_expiration_dt_in=TO_DATE('01/01/1600', 'mm/dd/yyyy') THEN expiration_dt ELSE p_expiration_dt_inEND , audit_insert_user_name_tx = CASE WHEN p_audit_insert_user_name_tx_in='0.000000001' THEN audit_insert_user_name_tx ELSE p_audit_insert_user_name_tx_inEND , audit_update_dt = CURRENT_TIMESTAMP, audit_update_user_name_tx = CASE WHEN p_audit_update_user_name_tx_in='0.000000001' THEN audit_update_user_name_tx ELSE p_audit_update_user_name_tx_inEND , latest_version_in = CASE WHEN p_latest_version_in_in='0' THEN latest_version_in ELSE p_latest_version_in_in END , delete_in = CASE WHEN p_delete_in_in='0' THEN delete_in ELSE p_delete_in_in END WHERE pres_id = p_pres_id_in AND audit_update_dt = p_last_audit_update_dt_in; GET DIAGNOSTICS ora2pg_rowcount = ROW_COUNT; p_err_code_out := 0; EXCEPTION WHEN SQLSTATE '50001' THEN p_err_code_out := -20999; p_err_mesg_out := 'Record has been modified since last retrieved - Resubmit transaction for parameter(s) ' || ' p_pres_id_in values of which are => ' || p_pres_id_in; RAISE EXCEPTION '%', p_err_mesg_out USING ERRCODE = '45999'; END; $function$ Table definition is below: -- product_master_fdw=# \d product_owner.external_sys_class_code_pres; Table "product_owner.external_sys_class_code_pres" Column | Type | Collation | Nullable | Default ------------------------------+-----------------------------+-----------+----------+--------- pres_id | bigint | | not null | major_classification_cd | character varying(10) | | not null | major_classification_name_tx | character varying(100) | | not null | coverage_short_name_tx | character varying(50) | | | coverage_name_tx | character varying(100) | | not null | cdt_source_system_cd | character varying(50) | | not null | cdt_status_cd | character varying(50) | | not null | effective_dt | timestamp without time zone | | not null | expiration_dt | timestamp without time zone | | | audit_insert_dt | timestamp without time zone | | not null | audit_insert_user_name_tx | character varying(50) | | not null | audit_update_dt | timestamp without time zone | | | audit_update_user_name_tx | character varying(50) | | | latest_version_in | character varying(1) | | | delete_in | character varying(1) | | | class_code_id | character varying(50) | | not null | cdt_submitting_country_cd | character varying(50) | | not null | Indexes: "external_sys_class_code_pres_pkey" PRIMARY KEY, btree (pres_id) "pres_fk_cdt_submitting_ctry_cd" btree (cdt_submitting_country_cd) Referenced by: TABLE "product_owner.cov_category_detail_class_prcc" CONSTRAINT "prcc_fk_pres_detail_class" FOREIGN KEY (pres_id) REFERENCESproduct_owner.external_sys_class_code_pres(pres_id) DEFERRABLE TABLE "product_owner.ext_class_prod_class_map_prcm" CONSTRAINT "prcm_fk_pres_class_code" FOREIGN KEY (pres_id) REFERENCESproduct_owner.external_sys_class_code_pres(pres_id) DEFERRABLE NOT VALID TABLE "product_owner.ext_class_prod_cvg_map_prcv" CONSTRAINT "prcv_fk_pres_id" FOREIGN KEY (pres_id) REFERENCES product_owner.external_sys_class_code_pres(pres_id)DEFERRABLE TABLE "product_owner.external_prod_dtl_presd" CONSTRAINT "presd_fk_pres_id" FOREIGN KEY (pres_id) REFERENCES product_owner.external_sys_class_code_pres(pres_id)DEFERRABLE Regards, Virendra -----Original Message----- From: Kumar, Virendra Sent: Tuesday, September 03, 2019 6:09 PM To: Tom Lane Cc: Adrian Klaver; pgsql-general@lists.postgresql.org Subject: Re: Running a Simple Update Statement Fails, Second Time Suceeds. Hi Tom, Sincere apologies for that privacy notice in email, this company policy which I cannot skip. Adrian, The function is really simple. I’ll share the code as soon as I can. Regards, Virendra > On Sep 3, 2019, at 5:41 PM, Tom Lane <tgl@sss.pgh.pa.us> wrote: > > Adrian Klaver <adrian.klaver@aklaver.com> writes: >>> On 9/3/19 1:56 PM, Kumar, Virendra wrote: >>> Here is simple query, I am running via function call. This statement >>> runs fine as SQL but when put in function as plpgsql it failes with >>> error below, when I ran second times in same session it succeeds: > >> We will need to see the function definition. > > Also, what PG version is that? This looks a bit like bug #15913, > but it might be something else. > >>> This message is intended only for the use of the addressee and may contain >>> information that is PRIVILEGED AND CONFIDENTIAL. >>> >>> If you are not the intended recipient, you are hereby notified that any >>> dissemination of this communication is strictly prohibited. If you have >>> received this communication in error, please erase all copies of the message >>> and its attachments and notify the sender immediately. Thank you. > > I rather wonder whether I'm even allowed to read this, let alone > answer it. You do realize that this sort of add-on is completely > silly on a public mailing list? > > regards, tom lane ________________________________ This message is intended only for the use of the addressee and may contain information that is PRIVILEGED AND CONFIDENTIAL. If you are not the intended recipient, you are hereby notified that any dissemination of this communication is strictly prohibited. If you have received this communication in error, please erase all copies of the message and its attachments and notify the sender immediately. Thank you. ________________________________ This message is intended only for the use of the addressee and may contain information that is PRIVILEGED AND CONFIDENTIAL. If you are not the intended recipient, you are hereby notified that any dissemination of this communication is strictly prohibited. If you have received this communication in error, please erase all copies of the message and its attachments and notify the sender immediately. Thank you.
pgsql-general by date: