Thread: Executing stored procs

Executing stored procs

From
Anthony Waye
Date:

Hi,

 

I’ve been currently trying to execute stored procs with psycopg2 on an AWS redshift cluster but no matter what I do I can’t figure out the syntax for how to get it to successfully execute.

 

CREATE OR REPLACE PROCEDURE stg_customervip.sp_STG_Customer ( 

                                                                    p_Audit_RunID IN bigint ,

                                                                    p_Audit_RunDTS IN timestamp

                                                                    )

AS $$

BEGIN

TRUNCATE table stg_customervip.Customer;

 

INSERT INTO stg_customervip.Customer

       (

        ,Audit_RunID    

        ,Audit_RunDTS

        )

SELECT 

        ,p_Audit_RunID  AS Audit_RunID

        ,p_Audit_RunDTS AS Audit_RunDTS

FROM stg_customervip_temp.customer;

END;

$$ LANGUAGE plpgsql; 

 

try:

    redshift_conn = psycopg2.connect(dbname=args.redshift_database_name, host=args.redshift_address,

                                        port=args.redshift_port, user=redshift_creds['username'], password=redshift_creds['password'])

except Exception as e:

    raise(e)

 

rand = random.randrange(

    1545)

timestamp = datetime.utcnow().strftime("%Y-%m-%d %H:%M:%S")

for proc in stored_procs_obj:

    qry_str = sql.SQL("CALL {proc}({int}::bigint, {timestamp}::timestamp)").format(

        proc=sql.Identifier(proc['schemaname'], proc['procedurename']), int=sql.Literal(rand), timestamp=sql.Literal(timestamp))

    logger.info(qry_str.as_string(redshift_conn))

    logger.info(redshift_conn.closed)

    redshift_conn.reset()

    try:

        with redshift_conn.cursor() as cursor:

            cursor.execute(qry_str)

            redshift_conn.commit()

            logger.info("Query successfully committed")

    except Exception as e:

        redshift_conn.close()

        send_sfn_failure(args.task_token, "Exception"str(e))

        raise

 

Essentially results in a SQL query of: CALL "stg_customervip"."sp_stg_customer"(37::bigint, '2020-01-15 05:52:31'::timestamp)

If I take that query and run it directly in redshift it runs successfully but via psycopg2 it returns:

 

psycopg2.errors.FeatureNotSupported: TRUNCATE cannot be invoked from a procedure that is executing in an atomic context.

HINT: Try calling the procedure as a top-level call i.e. not from within an explicit transaction block. Or, if this procedure (or one of its ancestors in the call chain) was created with SET config options, recreate the procedure without them.

CONTEXT: SQL statement "TRUNCATE table stg_customervip.Customer"

 

While that error sounds legitimate I think it might be a redherring because it does execute successfully if I do it manually against redshift.

 

I’ve also attempted to try: SELECT "stg_customervip"."sp_stg_customer"(37::bigint, '2020-01-15 05:52:31'::timestamp) but that returns: [Amazon](500310) Invalid operation: stg_customervip.sp_stg_customer(bigint, timestamp without time zone) is a procedure;

 

I did notice there was a callproc() function available to call a function or a procedure but that doesn’t make it any further

 

        param1 = str(rand) + "::bigint"

        param2 = timestamp + "::timestamp"

 

        try:

            with redshift_conn.cursor() as cursor:

                cursor.callproc(proc['fullprocedurename'], (param1, param2))

                redshift_conn.commit()

                logger.info("Query successfully committed")

        except Exception as e:

            redshift_conn.close()

            send_sfn_failure(args.task_token, "Exception"str(e))

            raise

 

returns:

psycopg2.errors.WrongObjectType: stg_connect.sp_stg_store("unknown", "unknown") is a procedure

HINT: To call a procedure, use CALL.

 

Has anyone encountered this or has any suggerstions?

 

Thanks

Anthony Waye

Senior Systems Engineer - DevOps (Microsoft)

M  0400167098
D  0732307463

Level 3, 192 Ann Street, Brisbane, QLD 4000
arq.group

The information contained in this email message may be confidential. If you are not the intended recipient any use, distribution, disclosure or copying of this information is prohibited. If you receive this email in error, please tell us by return email and delete it and any attachments from your system.

 

 

Attachment

Re: Executing stored procs

From
Daniele Varrazzo
Date:

On Wed, Jan 15, 2020 at 7:37 AM Anthony Waye <anthony.waye@arq.group> wrote:
 

Essentially results in a SQL query of: CALL "stg_customervip"."sp_stg_customer"(37::bigint, '2020-01-15 05:52:31'::timestamp)

If I take that query and run it directly in redshift it runs successfully but via psycopg2 it returns:

 

psycopg2.errors.FeatureNotSupported: TRUNCATE cannot be invoked from a procedure that is executing in an atomic context.

HINT: Try calling the procedure as a top-level call i.e. not from within an explicit transaction block. Or, if this procedure (or one of its ancestors in the call chain) was created with SET config options, recreate the procedure without them.

CONTEXT: SQL statement "TRUNCATE table stg_customervip.Customer"

 

While that error sounds legitimate I think it might be a redherring because it does execute successfully if I do it manually against redshift.


Probably if you run it manually you do it outside a transaction. Psycopg starts a transaction automatically (no, I don't think it's a good idea, but it's part of the specs)


Try setting `redshift_conn.autocommit = True` after connection creation, and do without the `commit()`s.

-- Daniele
Attachment

RE: Executing stored procs

From
Anthony Waye
Date:

Ah awesome! Thanks Daniele that appears to have worked!

 

Thanks

Anthony Waye

Senior Systems Engineer - DevOps (Microsoft)

M  0400167098
D  0732307463

Level 3, 192 Ann Street, Brisbane, QLD 4000
arq.group

The information contained in this email message may be confidential. If you are not the intended recipient any use, distribution, disclosure or copying of this information is prohibited. If you receive this email in error, please tell us by return email and delete it and any attachments from your system.

 

 

From: Daniele Varrazzo <daniele.varrazzo@gmail.com>
Sent: Wednesday, 15 January 2020 10:06 PM
To: Anthony Waye <anthony.waye@arq.group>
Cc: psycopg@postgresql.org
Subject: Re: Executing stored procs

 

 

On Wed, Jan 15, 2020 at 7:37 AM Anthony Waye <anthony.waye@arq.group> wrote:

 

Essentially results in a SQL query of: CALL "stg_customervip"."sp_stg_customer"(37::bigint, '2020-01-15 05:52:31'::timestamp)

If I take that query and run it directly in redshift it runs successfully but via psycopg2 it returns:

 

psycopg2.errors.FeatureNotSupported: TRUNCATE cannot be invoked from a procedure that is executing in an atomic context.

HINT: Try calling the procedure as a top-level call i.e. not from within an explicit transaction block. Or, if this procedure (or one of its ancestors in the call chain) was created with SET config options, recreate the procedure without them.

CONTEXT: SQL statement "TRUNCATE table stg_customervip.Customer"

 

While that error sounds legitimate I think it might be a redherring because it does execute successfully if I do it manually against redshift.

 

Probably if you run it manually you do it outside a transaction. Psycopg starts a transaction automatically (no, I don't think it's a good idea, but it's part of the specs)

 

 

Try setting `redshift_conn.autocommit = True` after connection creation, and do without the `commit()`s.

 

-- Daniele

Attachment