-
Notifications
You must be signed in to change notification settings - Fork 15
Replace DROP INDEX IF EXISTS by a DO block #487
Conversation
…s and impact DB performance
AND tablename = 'records' | ||
) THEN | ||
|
||
CREATE UNIQUE INDEX idx_records_parent_id_collection_id_last_modified | ||
ON records(parent_id, collection_id, last_modified DESC); |
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
/me wondering: Since we are in a DO
block, couldn't we catch the creation exception instead (less verbose) ?
(It might fill the server logs with meaningless errors though)
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
What do you mean exactly, by now if the index is not exists it will be created, and if it exists nothing will happen. I fixed an error in rodo@1477c25 suppose it's related on what you mean.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Well, what I mean is that there are two ways to write the same behaviour.
For example, in python:
if key in mydict:
print mydict[key]
is equivalent (and less performant btw) to:
try:
print mydict[key]
except KeyError:
pass
So for the index creation I guess it's the same.
Either :
DO $$
BEGIN
IF NOT EXISTS ( ... )
THEN
CREATE INDEX
END IF;
END$$;
or
DO $$
BEGIN
BEGIN
CREATE INDEX ...
EXCEPTION WHEN <error> THEN
RAISE NOTICE 'Index exists with this name';
END;
END$$;
Indeed, it would have prevented the typo you add in the commit you mentionned :)
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Yes we can do that, but the log will be more verbose as at each time you'll execute the file on your DB you'll have an error, I think we have a different goal. As a DBA I always want to reduce log amount, I prefer script that run without raising error, even if I have less information, here you want to Raise an error if you try to create an already existing index, the opposite side of view.
We have to define the goal before choosing a solution.
Be careful of the line number 4 that set min_loglevel to ERROR you won't see the NOTICE
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
log will be more verbose
Yes, that what I thought in my first comment :)
This works for me ! I just wanted to challenge your choice :)
Thanks for the details !
\o/ Thanks for this awesome contribution ! You can add your name to CONTRIBUTORS.rst :) We maintain it by hand. |
ADD Rodolphe to contributors file
I realize that we should mimic the same improvements in the other backends Idempotence for the win! |
Replace DROP INDEX with conditional creation in PostgreSQL backends
It's often a bad idea to DROP an index and recreate it just after to ensure the script is idempotent.
Even if the CREATE INDEX IF NOT EXISTS will be available soon in PostgreSQL 9.5 I suggest to replace the DROP INDEX instructions