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

Convert longer media varchar fields to text in the catalog db #4357

Merged
merged 2 commits into from
May 24, 2024

Conversation

AetherUnbound
Copy link
Contributor

@AetherUnbound AetherUnbound commented May 17, 2024

Fixes

Fixes #4312 by @AetherUnbound

Description

This PR alters the SQL DDL files for the catalog database to reflect the changes that will be made to the existing catalog database with the following migration:

-- Alter image table
ALTER TABLE image ALTER COLUMN title TYPE TEXT USING title :: TEXT;
ALTER TABLE image ALTER COLUMN foreign_identifier TYPE TEXT USING foreign_identifier :: TEXT;
ALTER TABLE image ALTER COLUMN foreign_landing_url TYPE TEXT USING foreign_landing_url :: TEXT;
ALTER TABLE image ALTER COLUMN url TYPE TEXT USING url :: TEXT;
ALTER TABLE image ALTER COLUMN thumbnail TYPE TEXT USING thumbnail :: TEXT;
ALTER TABLE image ALTER COLUMN creator TYPE TEXT USING creator :: TEXT;
ALTER TABLE image ALTER COLUMN creator_url TYPE TEXT USING creator_url :: TEXT;

-- audioset_view must be dropped and recreated
-- THe view is also dependent on audio_set_foreign_identifier so we need to drop it before altering the base table
DROP VIEW IF EXISTS audioset_view;

-- Alter audio table
ALTER TABLE audio ALTER COLUMN title TYPE TEXT USING title :: TEXT;
ALTER TABLE audio ALTER COLUMN foreign_identifier TYPE TEXT USING foreign_identifier :: TEXT;
ALTER TABLE audio ALTER COLUMN foreign_landing_url TYPE TEXT USING foreign_landing_url :: TEXT;
ALTER TABLE audio ALTER COLUMN url TYPE TEXT USING url :: TEXT;
ALTER TABLE audio ALTER COLUMN thumbnail TYPE TEXT USING thumbnail :: TEXT;
ALTER TABLE audio ALTER COLUMN creator TYPE TEXT USING creator :: TEXT;
ALTER TABLE audio ALTER COLUMN creator_url TYPE TEXT USING creator_url :: TEXT;
ALTER TABLE audio ALTER COLUMN audio_set_foreign_identifier TYPE TEXT USING audio_set_foreign_identifier :: TEXT;

-- Recreate the audioset_view 
CREATE VIEW audioset_view AS
  SELECT DISTINCT ON (audio.audio_set_foreign_identifier, audio.provider)
    audio.audio_set_foreign_identifier          ::text AS foreign_identifier,
    audio.audio_set ->> 'title'                 ::text AS title,
    audio.audio_set ->> 'foreign_landing_url'   ::text AS foreign_landing_url,
    audio.audio_set ->> 'creator'               ::text AS creator,
    audio.audio_set ->> 'creator_url'           ::text AS creator_url,
    audio.audio_set ->> 'url'                   ::text AS url,
    (audio.audio_set ->> 'filesize'::text)      ::integer AS filesize,
    (audio.audio_set ->> 'filetype'::text)      ::character varying(80) AS filetype,
    audio.audio_set ->> 'thumbnail'             ::text AS thumbnail,
    audio.provider
FROM audio
WHERE (audio.audio_set_foreign_identifier IS NOT NULL AND audio.audio_set IS NOT NULL)
ORDER BY
    audio.audio_set_foreign_identifier,
    audio.provider,
    audio.updated_on DESC;

Once the above migration is reviewed and approved, we can run it on the catalog database and merge this PR.

I've also updated some of the mock schemas for the ingestion server testing. We won't need these in perpetuity, fortunately, thanks to #3925.

Testing Instructions

  1. Checkout main
  2. Run just down -v && just api/init
  3. Check out this branch
  4. Run just catalog/pgcli, then the above migrations in order (you'll need to copy out each block below the comments, pgcli doesn't seem to play nicely with comments)
  5. Run \d image, \d audio, and \d audioset_view in the shell to verify the tables are now using text
  6. Run just c to start the catalog and start the Jamendo and SMK DAGs to pull in new data
  7. Enable both data refreshes to verify that the data gets pulled and moved without issue
  8. (Optional) Run just down -v && just catalog/pgcli and verify that the freshly created tables/views now use text

Checklist

  • My pull request has a descriptive title (not a vague title likeUpdate index.md).
  • My pull request targets the default branch of the repository (main) or a parent feature branch.
  • My commit messages follow best practices.
  • My code follows the established code style of the repository.
  • I added or updated tests for the changes I made (if applicable).
  • I added or updated documentation (if applicable).
  • I tried running the project locally and verified that there are no visible errors.
  • I ran the DAG documentation generator (just catalog/generate-docs for catalog
    PRs) or the media properties generator (just catalog/generate-docs media-props
    for the catalog or just api/generate-docs for the API) where applicable.

Developer Certificate of Origin

Developer Certificate of Origin
Developer Certificate of Origin
Version 1.1

Copyright (C) 2004, 2006 The Linux Foundation and its contributors.
1 Letterman Drive
Suite D4700
San Francisco, CA, 94129

Everyone is permitted to copy and distribute verbatim copies of this
license document, but changing it is not allowed.


Developer's Certificate of Origin 1.1

By making a contribution to this project, I certify that:

(a) The contribution was created in whole or in part by me and I
    have the right to submit it under the open source license
    indicated in the file; or

(b) The contribution is based upon previous work that, to the best
    of my knowledge, is covered under an appropriate open source
    license and I have the right under that license to submit that
    work with modifications, whether created in whole or in part
    by me, under the same open source license (unless I am
    permitted to submit under a different license), as indicated
    in the file; or

(c) The contribution was provided directly to me by some other
    person who certified (a), (b) or (c) and I have not modified
    it.

(d) I understand and agree that this project and the contribution
    are public and that a record of the contribution (including all
    personal information I submit with it, including my sign-off) is
    maintained indefinitely and may be redistributed consistent with
    this project or the open source license(s) involved.

@AetherUnbound AetherUnbound requested review from a team as code owners May 17, 2024 21:10
@openverse-bot openverse-bot added 🟧 priority: high Stalls work on the project or its dependents 🧰 goal: internal improvement Improvement that benefits maintainers, not users 🗄️ aspect: data Concerns the data in our catalog and/or databases 🚦 status: awaiting triage Has not been triaged & therefore, not ready for work labels May 17, 2024
@github-actions github-actions bot added 🧱 stack: catalog Related to the catalog and Airflow DAGs 🧱 stack: ingestion server Related to the ingestion/data refresh server labels May 17, 2024
@AetherUnbound AetherUnbound removed the 🚦 status: awaiting triage Has not been triaged & therefore, not ready for work label May 17, 2024
Copy link
Member

@zackkrida zackkrida left a comment

Choose a reason for hiding this comment

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

The migrations look good; lgtm

Copy link

Full-stack documentation: https://docs.openverse.org/_preview/4357

Please note that GitHub pages takes a little time to deploy newly pushed code, if the links above don't work or you see old versions, wait 5 minutes and try again.

You can check the GitHub pages deployment action list to see the current status of the deployments.

Changed files 🔄:

Copy link
Member

Choose a reason for hiding this comment

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

Nice catch!

Copy link
Contributor

@sarayourfriend sarayourfriend left a comment

Choose a reason for hiding this comment

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

LGTM! Manually running the migrations locally works just fine 👍 I really can't wait until #1836, manually running destructive commands without any kind of real way to automatically test that it actually works is... a nightmare 🙂

Anyway, this does work, as far as I can tell, so LGTM!

we can run it on the catalog database and merge this PR.

@AetherUnbound will we need to pause running DAGs while this happens? I don't know whether any of the DAGs create long transactions, but if they do, is there any risk we need to consider when applying this migration to prevent a deadlock or some other timing issue?

(audio.audio_set ->> 'url'::text) ::character varying(1000) AS url,
(audio.audio_set ->> 'filesize'::text) ::integer AS filesize,
(audio.audio_set ->> 'filetype'::text) ::character varying(80) AS filetype,
(audio.audio_set ->> 'thumbnail'::text) ::character varying(1000) AS thumbnail,
Copy link
Contributor

Choose a reason for hiding this comment

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

This is a nice simplification 😀

@AetherUnbound
Copy link
Contributor Author

@AetherUnbound will we need to pause running DAGs while this happens? I don't know whether any of the DAGs create long transactions, but if they do, is there any risk we need to consider when applying this migration to prevent a deadlock or some other timing issue?

We should definitely wait for an opportunity to apply this when there are no running DAGs or data refresh. Currently we're running a staging data refresh for testing purposes so we'll want to wait until that's done copying data from the upstream database as well before running this migration. I'll wait to merge this until it's applied.

@AetherUnbound
Copy link
Contributor Author

I applied the steps above in order to the production database with one exception: foreign_identifier took longer than a second to apply, unlike all of the other columns. When trying to find out why, I realized that we had an index on the tables which was converting the field to TEXT as well:

    "audio_provider_fid_idx" UNIQUE, btree (provider, md5(foreign_identifier::text))

I theorized that we could drop the index, apply the alter, then re-add the index without the type coersion, and that ended up working! So for each table, here's the additional steps I took for foreign_identifier:

-- Audio update
DROP INDEX IF EXISTS audio_provider_fid_idx;
ALTER TABLE audio ALTER COLUMN foreign_identifier TYPE TEXT USING foreign_identifier :: TEXT;
CREATE UNIQUE INDEX audio_provider_fid_idx
    ON public.audio
        USING btree (provider, md5(foreign_identifier));

-- Image update
DROP INDEX IF EXISTS image_provider_fid_idx;
ALTER TABLE image ALTER COLUMN foreign_identifier TYPE TEXT USING foreign_identifier :: TEXT;
CREATE UNIQUE INDEX image_provider_fid_idx
    ON public.image
    USING btree (provider, md5(foreign_identifier));

These are now applied and the catalog database tables look as expected:

deploy@localhost:openledger> \d audio;
+------------------------------+--------------------------+--------------------------------------+
| Column                       | Type                     | Modifiers                            |
|------------------------------+--------------------------+--------------------------------------|
| identifier                   | uuid                     |  not null default uuid_generate_v4() |
| created_on                   | timestamp with time zone |  not null                            |
| updated_on                   | timestamp with time zone |  not null                            |
| ingestion_type               | character varying(80)    |                                      |
| provider                     | character varying(80)    |                                      |
| source                       | character varying(80)    |                                      |
| foreign_identifier           | text                     |                                      |
| foreign_landing_url          | text                     |                                      |
| url                          | text                     |  not null                            |
| thumbnail                    | text                     |                                      |
| filetype                     | character varying(5)     |                                      |
| duration                     | integer                  |                                      |
| bit_rate                     | integer                  |                                      |
| sample_rate                  | integer                  |                                      |
| category                     | character varying(80)    |                                      |
| genres                       | character varying(80)[]  |                                      |
| audio_set                    | jsonb                    |                                      |
| set_position                 | integer                  |                                      |
| alt_files                    | jsonb                    |                                      |
| filesize                     | integer                  |                                      |
| license                      | character varying(50)    |  not null                            |
| license_version              | character varying(25)    |                                      |
| creator                      | text                     |                                      |
| creator_url                  | text                     |                                      |
| title                        | text                     |                                      |
| meta_data                    | jsonb                    |                                      |
| tags                         | jsonb                    |                                      |
| watermarked                  | boolean                  |                                      |
| last_synced_with_source      | timestamp with time zone |                                      |
| removed_from_source          | boolean                  |  not null                            |
| standardized_popularity      | double precision         |                                      |
| audio_set_foreign_identifier | text                     |                                      |
+------------------------------+--------------------------+--------------------------------------+
Indexes:
    "audio_pkey" PRIMARY KEY, btree (identifier)
    "audio_provider_fid_idx" UNIQUE, btree (provider, md5(foreign_identifier))
    "audio_url_key" UNIQUE, btree (url)

Time: 0.518s

deploy@localhost:openledger> \d image;
+-------------------------+--------------------------+--------------------------------------+
| Column                  | Type                     | Modifiers                            |
|-------------------------+--------------------------+--------------------------------------|
| identifier              | uuid                     |  not null default uuid_generate_v4() |
| created_on              | timestamp with time zone |  not null                            |
| updated_on              | timestamp with time zone |  not null                            |
| ingestion_type          | character varying(80)    |                                      |
| provider                | character varying(80)    |                                      |
| source                  | character varying(80)    |                                      |
| foreign_identifier      | text                     |                                      |
| foreign_landing_url     | text                     |                                      |
| url                     | text                     |  not null                            |
| thumbnail               | text                     |                                      |
| width                   | integer                  |                                      |
| height                  | integer                  |                                      |
| filesize                | integer                  |                                      |
| license                 | character varying(50)    |  not null                            |
| license_version         | character varying(25)    |                                      |
| creator                 | text                     |                                      |
| creator_url             | text                     |                                      |
| title                   | text                     |                                      |
| meta_data               | jsonb                    |                                      |
| tags                    | jsonb                    |                                      |
| watermarked             | boolean                  |                                      |
| last_synced_with_source | timestamp with time zone |                                      |
| removed_from_source     | boolean                  |  not null                            |
| filetype                | character varying(5)     |                                      |
| category                | character varying(80)    |                                      |
| standardized_popularity | double precision         |                                      |
+-------------------------+--------------------------+--------------------------------------+
Indexes:
    "image_pkey" PRIMARY KEY, btree (identifier)
    "image_provider_fid_idx" UNIQUE, btree (provider, md5(foreign_identifier))
    "image_url_key" UNIQUE, btree (url)

Time: 0.515s

@AetherUnbound AetherUnbound merged commit 4798866 into main May 24, 2024
47 checks passed
@AetherUnbound AetherUnbound deleted the feature/catalog-text-fields branch May 24, 2024 18:26
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
🗄️ aspect: data Concerns the data in our catalog and/or databases 🧰 goal: internal improvement Improvement that benefits maintainers, not users 🟧 priority: high Stalls work on the project or its dependents 🧱 stack: catalog Related to the catalog and Airflow DAGs 🧱 stack: ingestion server Related to the ingestion/data refresh server
Projects
Status: 🤝 Merged
Development

Successfully merging this pull request may close these issues.

Convert longer media varchar fields to text in the catalog database
4 participants