Skip to content
This repository has been archived by the owner on Mar 28, 2019. It is now read-only.

Replace DROP INDEX IF EXISTS by a DO block #487

Merged
merged 2 commits into from
Oct 22, 2015
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 1 addition & 0 deletions CONTRIBUTORS.rst
Original file line number Diff line number Diff line change
Expand Up @@ -11,4 +11,5 @@ Contributors
* Michiel de Jong <michiel@unhosted.org>
* Nicolas Perriault <nperriault@mozilla.com>
* Rémy Hubscher <rhubscher@mozilla.com>
* Rodolphe Quiédeville <rodolphe@quiedeville.org>
* Tarek Ziade <tarek@mozilla.com>
84 changes: 76 additions & 8 deletions cliquet/storage/postgresql/schema.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,8 @@
--
-- Automated script, we do not need NOTICE and WARNING
--
SET client_min_messages TO ERROR;
--
-- Convert timestamps to milliseconds epoch integer
--
CREATE OR REPLACE FUNCTION as_epoch(ts TIMESTAMP) RETURNS BIGINT AS $$
Expand Down Expand Up @@ -26,13 +30,53 @@ CREATE TABLE IF NOT EXISTS records (

PRIMARY KEY (id, parent_id, collection_id)
);
--
-- CREATE INDEX IF NOT EXISTS will be available in PostgreSQL 9.5
-- http://www.postgresql.org/docs/9.5/static/sql-createindex.html
DO $$
BEGIN

DROP INDEX IF EXISTS idx_records_parent_id_collection_id_last_modified;
CREATE UNIQUE INDEX idx_records_parent_id_collection_id_last_modified
IF NOT EXISTS (
SELECT 1 FROM pg_indexes
WHERE indexname = 'idx_records_parent_id_collection_id_last_modified'
AND tablename = 'records'
) THEN

CREATE UNIQUE INDEX idx_records_parent_id_collection_id_last_modified
ON records(parent_id, collection_id, last_modified DESC);
Copy link
Contributor

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)

Copy link
Contributor Author

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.

Copy link
Contributor

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 :)

Copy link
Contributor Author

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

Copy link
Contributor

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 !

DROP INDEX IF EXISTS idx_records_last_modified_epoch;
CREATE INDEX idx_records_last_modified_epoch ON records(as_epoch(last_modified));

END IF;
END$$;

DO $$
BEGIN

IF NOT EXISTS (
SELECT 1 FROM pg_indexes
WHERE indexname = 'idx_records_parent_id_collection_id_last_modified'
AND tablename = 'records'
) THEN

CREATE UNIQUE INDEX idx_records_parent_id_collection_id_last_modified
ON records(parent_id, collection_id, last_modified DESC);

END IF;
END$$;

DO $$
BEGIN

IF NOT EXISTS (
SELECT 1 FROM pg_indexes
WHERE indexname = 'idx_records_last_modified_epoch'
AND tablename = 'records'
) THEN

CREATE INDEX idx_records_last_modified_epoch
ON records(as_epoch(last_modified));

END IF;
END$$;

--
-- Deleted records, without data.
Expand All @@ -45,12 +89,36 @@ CREATE TABLE IF NOT EXISTS deleted (

PRIMARY KEY (id, parent_id, collection_id)
);
DROP INDEX IF EXISTS idx_deleted_parent_id_collection_id_last_modified;
CREATE UNIQUE INDEX idx_deleted_parent_id_collection_id_last_modified

DO $$
BEGIN

IF NOT EXISTS (
SELECT 1 FROM pg_indexes
WHERE indexname = 'idx_deleted_parent_id_collection_id_last_modified'
AND tablename = 'deleted'
) THEN

CREATE UNIQUE INDEX idx_deleted_parent_id_collection_id_last_modified
ON deleted(parent_id, collection_id, last_modified DESC);
DROP INDEX IF EXISTS idx_deleted_last_modified_epoch;
CREATE INDEX idx_deleted_last_modified_epoch ON deleted(as_epoch(last_modified));

END IF;
END$$;

DO $$
BEGIN

IF NOT EXISTS (
SELECT 1 FROM pg_indexes
WHERE indexname = 'idx_deleted_last_modified_epoch'
AND tablename = 'deleted'
) THEN

CREATE INDEX idx_deleted_last_modified_epoch
ON deleted(as_epoch(last_modified));

END IF;
END$$;

--
-- Helper that returns the current collection timestamp.
Expand Down