Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

PostgreSQL - Functions #578

Merged
merged 20 commits into from
Dec 2, 2019
Merged

PostgreSQL - Functions #578

merged 20 commits into from
Dec 2, 2019

Conversation

Papina
Copy link
Contributor

@Papina Papina commented Oct 15, 2019

Functions to be converted to PostgreSQL

papina and others added 7 commits August 27, 2019 14:40
set search path for schema.  schema qualified name no longer needed for creation and access of functions.
snake_case column fix for user_create, 
rename of users.sql file to lowercase

CREATE OR REPLACE FUNCTION user_update
(
_id UUID,
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

formatting seems weird in this file. Looks like tabs mixed with spaces. should just be spaces.

_public_key TEXT,
_private_key TEXT ,
_premium INT,
_premium_expiration_date TEXT,
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Why is this passed in as text and then cast to TIMESTAMPTZ later?

_key TEXT,
_public_key TEXT,
_private_key TEXT ,
_premium INT,
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Why is this passed as int and cast to bit later?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

actually ive fixed that timestamp issue now, i was messing with datatypes and missed that one initially when i was passing through NULLS and having issues due to the case (ie null vs NULL)

im recasting some of the datatypes within the functions (ie int/smallint) due to the values being passed as INT and having issues.

also bit v boolean, its better/easier to have the datatype as boolean to begin with, else it has to be passed in as int, and then cast to bit in the function.

this is just a weirdness of the function when its called normally, im not sure how your C code process would call it, but with these datatypes, it has to be cast before calling the function, or the function has to do it when doing the insert/update

eg
select * from fn_some_function(1::BIT,123::SMALLINT) ;
vs
select * from fn_some_function(false,123) ;
vs

for now i've chosen boolean instead of bit, but it can be changed back if this is too much of a change to work with.

@Papina
Copy link
Contributor Author

Papina commented Oct 16, 2019

last update has the case fixed

not sure on int v smallint change you want
did you want the function to cast it (pass in INT value and cast with the update statement),
or the function call to cast it (pass in value::SMALLINT)?

@kspearrin
Copy link
Member

last update has the case fixed

not sure on int v smallint change you want
did you want the function to cast it (pass in INT value and cast with the update statement),
or the function call to cast it (pass in value::SMALLINT)?

It should be like your update function where no casting is needed.

@Papina
Copy link
Contributor Author

Papina commented Oct 16, 2019

i've gone back and reviewed all the functions, and recast within the function to match the current table DDL. tested the removal statements for each also

@kspearrin
Copy link
Member

i've gone back and reviewed all the functions, and recast within the function to match the current table DDL. tested the removal statements for each also

Isn't that the opposite of what I suggested? I was suggesting that you do it like your update function was originally so that casting wasn't necessary. The proper type is defined in the parameters from the beginning.

@Papina
Copy link
Contributor Author

Papina commented Oct 16, 2019

ok, comms problem, lets resolve it
did you want

-1/ the function code to cast it (pass in INT value and cast with the update statement),
-2/ or the function call to cast it (pass in value::SMALLINT)?

currently it's set to -1 and there is no need to cast outside the function call (just pass in the value as-is), which is simpler and my preference, and allows for extra error control code within the function later to return values if these numbers are out of range

or -2, the code that calls the function (your c code) will need to cast it beforehand else PostgreSQL will complain the function does not exist since it cant resolve int v smallint with numbers smaller than the smallint range, and PostgreSQL is very specific about datatypes, more so than SQL Server. the error control code can still be added, but would need to be on the c code side, and may not show anything useful (just could not find function(unknown) kind of error)

If it's -2, great, no problem, ill make the changes, and assume the value is passed correctly

@kspearrin
Copy link
Member

I am suggesting option 2.

Dapper is what calls these functions from the .NET code, and I believe it will properly handle casting the type, if necessary, as it passes the value in. I have not tested this yet with Postgres, but it does with SQL Server.

Maybe I should test before we commit to one way or the other.

@kspearrin
Copy link
Member

I changed the query to the following, which uses the same parameter types as defined in the tables. Tested it with my local server and .NET code w/ dapper and it worked fine. No casting needed.

CREATE OR REPLACE FUNCTION user_create
(
    _id                                 UUID,
    _name                               VARCHAR,
    _email                              VARCHAR,
    _email_verified                     BOOLEAN,
    _master_password                    VARCHAR,
    _master_password_hINT               VARCHAR,
    _culture                            VARCHAR,
    _security_stamp                     VARCHAR,
    _two_factor_providers               TEXT,
    _two_factor_recovery_code           VARCHAR,
    _equivalent_domains                 TEXT,
    _excluded_global_equivalent_domains TEXT,
    _account_revision_date              TIMESTAMPTZ,
    _key                                TEXT,
    _public_key                         TEXT,
    _private_key                        TEXT,
    _premium                            BOOLEAN,
    _premium_expiration_date            TIMESTAMPTZ,
    _renewal_reminder_date              TIMESTAMPTZ,
    _storage                            BIGINT,
    _max_storage_gb                     SMALLINT,
    _gateway                            SMALLINT,
    _gateway_customer_id                VARCHAR,
    _gateway_subscription_id            VARCHAR,
    _license_key                        VARCHAR,
    _kdf                                SMALLINT,
    _kdf_iterations                     INT,
    _creation_date                      TIMESTAMPTZ,
    _revision_date                      TIMESTAMPTZ
)
RETURNS VOID
LANGUAGE 'plpgsql'
AS
$$
BEGIN
    INSERT INTO "user"
    (
        id,
        name,
        email,
        email_verified,
        master_password,
        master_password_hint,
        culture,
        security_stamp,
        two_factor_providers,
        two_factor_recovery_code,
        equivalent_domains,
        excluded_global_equivalent_domains,
        account_revision_date,
        key,
        public_key,
        private_key,
        premium,
        premium_expiration_date,
        renewal_reminder_date,
        storage,
        max_storage_gb,
        gateway,
        gateway_customer_id,
        gateway_subscription_id,
        license_key,
        kdf,
        kdf_iterations,
        creation_date,
        revision_date
    )
    VALUES
    (
        _id,
        _name,
        _email,
        _email_verified,
        _master_password,
        _master_password_hint,
        _culture,
        _security_stamp,
        _two_factor_providers,
        _two_factor_recovery_code,
        _equivalent_domains,
        _excluded_global_equivalent_domains,
        _account_revision_date,
        _key,
        _public_key,
        _private_key,
        _premium,
        _premium_expiration_date,
        _renewal_reminder_date,
        _storage,
        _max_storage_gb,
        _gateway,
        _gateway_customer_id,
        _gateway_subscription_id,
        _license_key,
        _kdf,
        _kdf_iterations,
        _creation_date,
        _revision_date
    );
END
$$

kdf and gateway are both .NET enums, that inherit from a byte type. max_storage_gb is .NET type short. Both of these worked find as SMALLINT in postgres.

@Papina
Copy link
Contributor Author

Papina commented Oct 17, 2019

great!
ive updated the functions affected

_email VARCHAR,
_email_verified BOOLEAN,
_master_password VARCHAR,
_master_password_hINT VARCHAR,
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

still typo with uppercase INT here

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

fixed

AS
$BODY$
BEGIN
-- functions dont support commit/rollback transactions, only v11+ procedures can do this
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

well that sucks

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@Papina why not use a procedure then?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@mnuccioarpae
I don't know Dapper, but apparently it cant use procedures

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@Papina Me neither, but it looks strange to me since CALL conforms to the SQL standard.

@@ -0,0 +1,75 @@
DROP FUNCTION IF EXISTS user_update(UUID,VARCHAR,VARCHAR,BOOLEAN,VARCHAR,VARCHAR,VARCHAR,VARCHAR,TEXT,VARCHAR,TEXT,TEXT,TIMESTAMPTZ,TEXT,TEXT,TEXT,BOOLEAN,TIMESTAMPTZ,TIMESTAMPTZ,BIGINT,SMALLINT,SMALLINT,VARCHAR,VARCHAR,VARCHAR,SMALLINT,INT,TIMESTAMPTZ,TIMESTAMPTZ)
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

do we really need these drops if we are using CREATE OR REPLACE? just seems like added headache to manage

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

from the postgres doco:

To replace the current definition of an existing function, use CREATE OR REPLACE FUNCTION. It is not possible to change the name or argument types of a function this way (if you tried, you would actually be creating a new, distinct function). Also, CREATE OR REPLACE FUNCTION will not let you change the return type of an existing function. To do that, you must drop and recreate the function. (When using OUT parameters, that means you cannot change the types of any OUT parameters except by dropping the function.)

So yes, ultimately not required once a function is confirmed as working as intended, but i'm using it currently to assist with the conversion, and not having it would be more of a headache for me. i can comment it out if you want

@kspearrin kspearrin merged commit 665e78e into bitwarden:master Dec 2, 2019
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

3 participants