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

Implement function DBMS_UTILITY.GET_TIME #135

Closed
wants to merge 4 commits into from
Closed

Implement function DBMS_UTILITY.GET_TIME #135

wants to merge 4 commits into from

Conversation

darold
Copy link
Contributor

@darold darold commented May 18, 2021

No description provided.

100th's of a second from a point in time in the past. This function
is used for determining elapsed time. This function is widely used
in some Oracle installation for timing of functions or statements.

Example of use:

	DO $$
	DECLARE
	    start_time integer;
	    end_time integer;
	BEGIN
	    start_time := DBMS_UTILITY.GET_TIME;
	    PERFORM pg_sleep(10);
	    end_time := DBMS_UTILITY.GET_TIME;
	    RAISE NOTICE 'Execution time: % seconds', (end_time - start_time)/100;
	END
	$$;

This function do not return the same value as the Oracle implementation
but it doesn't matter, it is used to get an elapsed time between two
execution of the function.
@darold
Copy link
Contributor Author

darold commented May 19, 2021

Hi Pavel, more though this morning about this function. Let me know if it should be implemented in C, I have used SQL to be able to import the function without recompiling but I can keep it on my side and provide a probably faster C implementation.

@okbob
Copy link
Contributor

okbob commented May 19, 2021

Hi. for simple things I prefer C implementation. Is question if it can be possible do this without lot of type conversions (there are four in one expression).

@darold
Copy link
Contributor Author

darold commented May 19, 2021

Yes this is why I think a C implementation will be faster, ok will do.

@okbob
Copy link
Contributor

okbob commented May 21, 2021

I hope so some like this code should to be enough

gettimeofday(&tv, NULL);
PG_RETURN_INT32((int32) (tv.tv_sec*1000000+tv.tv_usec)/(1000 * 10));

I believe so it does almost all, what your code.

Probably it is not fully compatible with Oracle, because Oracle probably does

PG_RETURN_INT32((int32) ((tv.tv_sec*1000000+tv.tv_usec)/(1000 * 10) + PG_INT32_MIN));

With last transformation, there are enough bits for interval 492 days, without it only for half days

@darold
Copy link
Contributor Author

darold commented May 21, 2021

I have tried to understand how Oracle is calculating its value and the more approaching method I have found is the SELECT round(extract(...)...) above which returns the nearest value. Saying that we don't need to return the same value but just a hundredth seconds value big enough to support several months of timing.

Here are the result of the different methods, the value returned by the function is the actual one, the other method are reported through NOTICE:

contrib_regression=# SELECT dbms_utility.get_time();
NOTICE:  "(int32) (tv.tv_sec*1000000+tv.tv_usec)/(1000 * 10)" returns: -1050170546
NOTICE:  "(int32) ((tv.tv_sec*1000000+tv.tv_usec)/(1000 * 10) + PG_INT32_MIN)" returns: 1097313102
 get_time  
-----------
 158586702
(1 row)

The second method looks acceptable for me even if the number of digit (10) doesn't correspond to the number of digit returned by the Oracle function (9). I'll push the fix.

@okbob
Copy link
Contributor

okbob commented May 21, 2021

Maybe + PG_INT32_MIN is useless. Now it is positive, but next year, the number will be negative

@darold
Copy link
Contributor Author

darold commented May 21, 2021

Right, so we fall back to your first solution that has negative value too. What I can propose it to take a far enough arbitrary time in the past to retrieved to epoch so that we will have a correct value. For example:

Datum
dbms_utility_get_time(PG_FUNCTION_ARGS)
{
        struct timeval tv;
        long reftime = 327456000*100;
        long a;

        gettimeofday(&tv,NULL);
        a = (tv.tv_sec*1000000+tv.tv_usec)/10000;
        PG_RETURN_INT32((int32) (a-reftime));
}

which gives

contrib_regression=# SELECT dbms_utility.get_time();
 get_time  
-----------
 564629656
(1 row)

@okbob okbob closed this May 21, 2021
@okbob okbob reopened this May 21, 2021
@okbob
Copy link
Contributor

okbob commented May 21, 2021

I have no strong opinion about it. This move to positive numbers now, but after 10 years the number will be negative again. Oracle allows negative numbers there -

Numbers are returned in the range -2147483648 to 2147483647 depending on platform and machine, and your application must take the sign of the number into account in determining the interval. For instance, in the case of two negative numbers, application logic must allow that the first (earlier) number will be larger than the second (later) number which is closer to zero. By the same token, your application should also allow that the first (earlier) number be negative and the second (later) number be positive.

I prefer to just cast from int64 to int32 only. It looks to most safe for me.

@darold
Copy link
Contributor Author

darold commented May 21, 2021

A right the Oracle function can return negative value too, so yes the form PG_RETURN_INT32((int32) (tv.tv_sec*1000000+tv.tv_usec)/10000); can be used and as it is mainly used to get an elapsed time normally there is no need to rewrite the application. Do you want me to post a new PR to avoid pollution with all this commit history?

@okbob
Copy link
Contributor

okbob commented May 21, 2021 via email

@darold darold closed this May 21, 2021
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.

None yet

2 participants