From d9945e0c55fff1b1af29cdb99f2bce8d4019d258 Mon Sep 17 00:00:00 2001 From: Liam Date: Sun, 18 Aug 2024 14:35:26 -0400 Subject: [PATCH] Major database cleanup --- lib/philomena/adverts/advert.ex | 2 +- lib/philomena/badges/award.ex | 6 +- lib/philomena/bans/fingerprint.ex | 2 +- lib/philomena/bans/subnet.ex | 2 +- lib/philomena/bans/user.ex | 2 +- lib/philomena/channels/automatic_updater.ex | 2 +- lib/philomena/channels/channel.ex | 5 +- lib/philomena/commissions/commission.ex | 8 +- lib/philomena/commissions/item.ex | 2 +- .../duplicate_reports/duplicate_report.ex | 2 +- lib/philomena/filters/filter.ex | 8 +- lib/philomena/poll_votes/poll_vote.ex | 2 - .../migrations/20240818182358_cleanup.exs | 310 ++++++++++++++++++ priv/repo/structure.sql | 282 +++++----------- 14 files changed, 410 insertions(+), 225 deletions(-) create mode 100644 priv/repo/migrations/20240818182358_cleanup.exs diff --git a/lib/philomena/adverts/advert.ex b/lib/philomena/adverts/advert.ex index 7150f043..fd975b4e 100644 --- a/lib/philomena/adverts/advert.ex +++ b/lib/philomena/adverts/advert.ex @@ -12,7 +12,7 @@ defmodule Philomena.Adverts.Advert do field :start_date, PhilomenaQuery.Ecto.RelativeDate field :finish_date, PhilomenaQuery.Ecto.RelativeDate field :restrictions, :string - field :notes, :string + field :notes, :string, default: "" field :image_mime_type, :string, virtual: true field :image_size, :integer, virtual: true diff --git a/lib/philomena/badges/award.ex b/lib/philomena/badges/award.ex index e6ca3bef..a3945c8c 100644 --- a/lib/philomena/badges/award.ex +++ b/lib/philomena/badges/award.ex @@ -10,10 +10,10 @@ defmodule Philomena.Badges.Award do belongs_to :awarded_by, User belongs_to :badge, Badge - field :label, :string field :awarded_on, :utc_datetime - field :reason, :string - field :badge_name, :string + field :label, :string, default: "" + field :reason, :string, default: "" + field :badge_name, :string, default: "" timestamps(inserted_at: :created_at, type: :utc_datetime) end diff --git a/lib/philomena/bans/fingerprint.ex b/lib/philomena/bans/fingerprint.ex index 5b499554..c903032f 100644 --- a/lib/philomena/bans/fingerprint.ex +++ b/lib/philomena/bans/fingerprint.ex @@ -9,7 +9,7 @@ defmodule Philomena.Bans.Fingerprint do belongs_to :banning_user, User field :reason, :string - field :note, :string + field :note, :string, default: "" field :enabled, :boolean, default: true field :valid_until, PhilomenaQuery.Ecto.RelativeDate field :fingerprint, :string diff --git a/lib/philomena/bans/subnet.ex b/lib/philomena/bans/subnet.ex index 2eeb424a..bc62a277 100644 --- a/lib/philomena/bans/subnet.ex +++ b/lib/philomena/bans/subnet.ex @@ -9,7 +9,7 @@ defmodule Philomena.Bans.Subnet do belongs_to :banning_user, User field :reason, :string - field :note, :string + field :note, :string, default: "" field :enabled, :boolean, default: true field :valid_until, PhilomenaQuery.Ecto.RelativeDate field :specification, EctoNetwork.INET diff --git a/lib/philomena/bans/user.ex b/lib/philomena/bans/user.ex index efae6214..0d128762 100644 --- a/lib/philomena/bans/user.ex +++ b/lib/philomena/bans/user.ex @@ -10,7 +10,7 @@ defmodule Philomena.Bans.User do belongs_to :banning_user, User field :reason, :string - field :note, :string + field :note, :string, default: "" field :enabled, :boolean, default: true field :valid_until, PhilomenaQuery.Ecto.RelativeDate field :generated_ban_id, :string diff --git a/lib/philomena/channels/automatic_updater.ex b/lib/philomena/channels/automatic_updater.ex index 3da29870..efb9a6ba 100644 --- a/lib/philomena/channels/automatic_updater.ex +++ b/lib/philomena/channels/automatic_updater.ex @@ -57,7 +57,7 @@ defmodule Philomena.Channels.AutomaticUpdater do attrs = live_channels |> Map.get(channel.short_name, %{}) - |> Map.merge(%{last_live_at: now, last_fetched_at: now}) + |> Map.merge(%{last_fetched_at: now}) Channels.update_channel_state(channel, attrs) end diff --git a/lib/philomena/channels/channel.ex b/lib/philomena/channels/channel.ex index 7f70351a..62df2a07 100644 --- a/lib/philomena/channels/channel.ex +++ b/lib/philomena/channels/channel.ex @@ -16,8 +16,6 @@ defmodule Philomena.Channels.Channel do field :nsfw, :boolean, default: false field :is_live, :boolean, default: false field :last_fetched_at, :utc_datetime - field :next_check_at, :utc_datetime - field :last_live_at, :utc_datetime field :thumbnail_url, :string, default: "" timestamps(inserted_at: :created_at, type: :utc_datetime) @@ -39,8 +37,7 @@ defmodule Philomena.Channels.Channel do :nsfw, :viewers, :thumbnail_url, - :last_fetched_at, - :last_live_at + :last_fetched_at ]) end diff --git a/lib/philomena/commissions/commission.ex b/lib/philomena/commissions/commission.ex index d1948457..c4108cee 100644 --- a/lib/philomena/commissions/commission.ex +++ b/lib/philomena/commissions/commission.ex @@ -13,10 +13,10 @@ defmodule Philomena.Commissions.Commission do field :open, :boolean field :categories, {:array, :string}, default: [] - field :information, :string - field :contact, :string - field :will_create, :string - field :will_not_create, :string + field :information, :string, default: "" + field :contact, :string, default: "" + field :will_create, :string, default: "" + field :will_not_create, :string, default: "" field :commission_items_count, :integer, default: 0 timestamps(inserted_at: :created_at, type: :utc_datetime) diff --git a/lib/philomena/commissions/item.ex b/lib/philomena/commissions/item.ex index 59682f7a..34f1a153 100644 --- a/lib/philomena/commissions/item.ex +++ b/lib/philomena/commissions/item.ex @@ -12,7 +12,7 @@ defmodule Philomena.Commissions.Item do field :item_type, :string field :description, :string field :base_price, :decimal - field :add_ons, :string + field :add_ons, :string, default: "" timestamps(inserted_at: :created_at, type: :utc_datetime) end diff --git a/lib/philomena/duplicate_reports/duplicate_report.ex b/lib/philomena/duplicate_reports/duplicate_report.ex index 0b0b07d3..fbf80f45 100644 --- a/lib/philomena/duplicate_reports/duplicate_report.ex +++ b/lib/philomena/duplicate_reports/duplicate_report.ex @@ -11,7 +11,7 @@ defmodule Philomena.DuplicateReports.DuplicateReport do belongs_to :user, User belongs_to :modifier, User - field :reason, :string + field :reason, :string, default: "" field :state, :string, default: "open" timestamps(inserted_at: :created_at, type: :utc_datetime) diff --git a/lib/philomena/filters/filter.ex b/lib/philomena/filters/filter.ex index 29d542f7..6e2be8d9 100644 --- a/lib/philomena/filters/filter.ex +++ b/lib/philomena/filters/filter.ex @@ -13,10 +13,10 @@ defmodule Philomena.Filters.Filter do field :name, :string field :description, :string, default: "" - field :system, :boolean - field :public, :boolean - field :hidden_complex_str, :string - field :spoilered_complex_str, :string + field :system, :boolean, default: false + field :public, :boolean, default: false + field :hidden_complex_str, :string, default: "" + field :spoilered_complex_str, :string, default: "" field :hidden_tag_ids, {:array, :integer}, default: [] field :spoilered_tag_ids, {:array, :integer}, default: [] field :user_count, :integer, default: 0 diff --git a/lib/philomena/poll_votes/poll_vote.ex b/lib/philomena/poll_votes/poll_vote.ex index ca4f4cd4..70531378 100644 --- a/lib/philomena/poll_votes/poll_vote.ex +++ b/lib/philomena/poll_votes/poll_vote.ex @@ -9,8 +9,6 @@ defmodule Philomena.PollVotes.PollVote do belongs_to :poll_option, PollOption belongs_to :user, User - field :rank, :integer - timestamps(inserted_at: :created_at, updated_at: false, type: :utc_datetime) end diff --git a/priv/repo/migrations/20240818182358_cleanup.exs b/priv/repo/migrations/20240818182358_cleanup.exs new file mode 100644 index 00000000..d3e45bd5 --- /dev/null +++ b/priv/repo/migrations/20240818182358_cleanup.exs @@ -0,0 +1,310 @@ +defmodule Philomena.Repo.Migrations.Cleanup do + use Ecto.Migration + + def change do + # NULL values + updates = + """ + update badge_awards set label='' where label is null; + update badge_awards set reason='' where reason is null; + update badge_awards set badge_name='' where badge_name is null; + update channels set thumbnail_url='' where thumbnail_url is null; + delete from commission_items where commission_id is null; + update commission_items set add_ons='' where add_ons is null; + update commissions set will_create='' where will_create is null; + update commissions set will_not_create='' where will_not_create is null; + update comments set ip='127.0.0.1' where ip is null; + update comments set fingerprint='bd41d8cd98f00b204e9800998ecf8427e' where fingerprint is null; + update duplicate_reports set reason='' where reason is null; + update filters set hidden_complex_str='' where hidden_complex_str is null; + update filters set spoilered_complex_str='' where spoilered_complex_str is null; + update fingerprint_bans set note='' where note is null; + update images set ip='127.0.0.1' where ip is null; + update images set fingerprint='bd41d8cd98f00b204e9800998ecf8427e' where fingerprint is null; + update posts set ip='127.0.0.1' where ip is null; + update posts set fingerprint='bd41d8cd98f00b204e9800998ecf8427e' where fingerprint is null; + update source_changes set fingerprint='bd41d8cd98f00b204e9800998ecf8427e' where fingerprint is null; + update subnet_bans set note='' where note is null; + update tag_changes set ip='127.0.0.1' where ip is null; + update tag_changes set fingerprint='bd41d8cd98f00b204e9800998ecf8427e' where fingerprint is null; + update user_bans set note='' where note is null; + """ + + # These statements should not be run by the migration in production. + # Run them manually in psql before this migration instead. + if direction() == :up and System.get_env("MIX_ENV") != "prod" do + for stmt <- String.split(updates, "\n") do + execute(stmt) + end + end + + # Missing default values + missing_default = [ + adverts: [:notes], + badge_awards: [:label, :reason, :badge_name], + commission_items: [:add_ons], + commissions: [:will_create, :will_not_create], + duplicate_reports: [:reason], + filters: [:hidden_complex_str, :spoilered_complex_str], + fingerprint_bans: [:note], + subnet_bans: [:note], + user_bans: [:note] + ] + + for {table, columns} <- missing_default do + add_default = Enum.map_join(columns, ", ", &"alter column #{&1} set default ''") + remove_default = Enum.map_join(columns, ", ", &"alter column #{&1} drop default") + + execute( + "alter table #{table} #{add_default};", + "alter table #{table} #{remove_default};" + ) + end + + # Missing NOT NULL constraints + missing_not_null = [ + adverts: [ + :image, + :clicks, + :impressions, + :live, + :link, + :title, + :notes, + :start_date, + :finish_date, + :restrictions + ], + badges: [:image, :priority], + badge_awards: [:label, :reason, :badge_name], + channels: [:thumbnail_url], + comments: [:approved, :anonymous, :destroyed_content, :image_id, :ip, :fingerprint], + commission_items: [:commission_id, :item_type, :description, :base_price, :add_ons], + commissions: [:information, :contact, :will_create, :will_not_create], + duplicate_reports: [:reason], + filters: [:hidden_complex_str, :spoilered_complex_str], + fingerprint_bans: [:fingerprint, :note], + images: [:anonymous, :approved, :ip, :fingerprint, :image_orig_size], + messages: [:approved], + posts: [:approved, :ip, :fingerprint], + reports: [:system], + source_changes: [:fingerprint], + subnet_bans: [:note, :specification], + tag_changes: [:ip, :fingerprint], + topics: [:anonymous], + user_bans: [:note], + versions: [:created_at] + ] + + for {table, columns} <- missing_not_null do + add_not_null = Enum.map_join(columns, ", ", &"alter column #{&1} set not null") + remove_not_null = Enum.map_join(columns, ", ", &"alter column #{&1} drop not null") + + execute( + "alter table #{table} #{add_not_null};", + "alter table #{table} #{remove_not_null};" + ) + end + + # Unused columns + alter table(:artist_links) do + remove :path, :"character varying(255)" + remove :hostname, :"character varying(255)" + end + + alter table(:channels) do + remove :watcher_ids, {:array, :integer}, default: [], null: false + remove :watcher_count, :integer, default: 0, null: false + + remove :tags, :string + + remove :viewer_minutes_today, :integer, default: 0, null: false + remove :viewer_minutes_thisweek, :integer, default: 0, null: false + remove :viewer_minutes_thismonth, :integer, default: 0, null: false + remove :total_viewer_minutes, :integer, default: 0, null: false + remove :next_check_at, :"timestamp without time zone" + remove :last_live_at, :"timestamp without time zone" + + remove :banner_image, :string + remove :channel_image, :string + remove :remote_stream_id, :integer + end + + alter table(:comments) do + remove :user_agent, :string, default: "" + remove :referrer, :string, default: "" + + remove :name_at_post_time, :string + + remove :body_textile, :string, default: "", null: false + end + + alter table(:commission_items) do + remove :description_textile, :string + remove :add_ons_textile, :string + end + + alter table(:commissions) do + remove :information_textile, :string + remove :contact_textile, :string + remove :will_create_textile, :string + remove :will_not_create_textile, :string + end + + alter table(:dnp_entries) do + remove :conditions_textile, :string, default: "", null: false + remove :reason_textile, :string, default: "", null: false + remove :instructions_textile, :string, default: "", null: false + end + + alter table(:forums) do + remove :watcher_ids, {:array, :integer}, default: [], null: false + remove :watcher_count, :integer, default: 0, null: false + end + + alter table(:galleries) do + remove :watcher_ids, {:array, :integer}, default: [], null: false + remove :watcher_count, :integer, default: 0, null: false + end + + alter table(:images) do + remove :tag_ids, {:array, :integer}, default: [], null: false + remove :watcher_ids, {:array, :integer}, default: [], null: false + remove :watcher_count, :integer, default: 0, null: false + + remove :user_agent, :string, default: "" + remove :referrer, :string, default: "" + + remove :votes_count, :integer, default: 0, null: false + + remove :tag_list_cache, :string + remove :tag_list_plus_alias_cache, :string + remove :file_name_cache, :string + + remove :ne_intensity, :"double precision" + remove :nw_intensity, :"double precision" + remove :se_intensity, :"double precision" + remove :sw_intensity, :"double precision" + remove :average_intensity, :"double precision" + + remove :description_textile, :string, default: "", null: false + remove :scratchpad_textile, :string + end + + alter table(:messages) do + remove :body_textile, :string, default: "", null: false + end + + alter table(:mod_notes) do + remove :body_textile, :text, default: "", null: false + end + + alter table(:poll_votes) do + remove :rank, :integer + end + + alter table(:polls) do + remove :deleted_by_id, references(:users, name: "fk_rails_2bf9149369") + + remove :hidden_from_users, :boolean, default: false, null: false + remove :deletion_reason, :string, default: "", null: false + end + + alter table(:posts) do + remove :user_agent, :string, default: "" + remove :referrer, :string, default: "" + + remove :name_at_post_time, :string + + remove :body_textile, :string, default: "", null: false + end + + alter table(:reports) do + remove :referrer, :string, default: "" + + remove :reason_textile, :string, default: "", null: false + end + + alter table(:roles) do + remove :resource_id, :integer + + remove :created_at, :"timestamp without time zone" + remove :updated_at, :"timestamp without time zone" + end + + alter table(:source_changes) do + remove :user_agent, :string, size: 255, default: "" + remove :referrer, :string, size: 255, default: "" + end + + alter table(:tags) do + remove :description_textile, :string, default: "" + end + + alter table(:tag_changes) do + remove :user_agent, :string, default: "" + remove :referrer, :string, default: "" + end + + alter table(:topics) do + remove :watcher_ids, {:array, :integer}, default: [], null: false + remove :watcher_count, :integer, default: 0, null: false + end + + alter table(:users) do + remove :sign_in_count, :integer, default: 0, null: false + remove :current_sign_in_at, :"timestamp without time zone" + remove :current_sign_in_ip, :inet + remove :last_sign_in_at, :"timestamp without time zone" + remove :last_sign_in_ip, :inet + remove :unread_notification_ids, {:array, :integer}, default: [], null: false + + remove :last_donation_at, :"timestamp without time zone" + + remove :description_textile, :string + remove :scratchpad_textile, :text + end + + # Wrong data type, created by Phoenix (timestamp(0) without time zone) + for table <- [ + :channel_live_notifications, + :forum_post_notifications, + :forum_topic_notifications, + :gallery_image_notifications, + :image_comment_notifications, + :image_merge_notifications, + :source_changes + ] do + alter table(table) do + modify :created_at, :"timestamp without time zone", + from: :"timestamp(0) without time zone" + + modify :updated_at, :"timestamp without time zone", + from: :"timestamp(0) without time zone" + end + end + + for table <- [:autocomplete, :moderation_logs, :user_tokens] do + alter table(table) do + modify :created_at, :"timestamp without time zone", + from: :"timestamp(0) without time zone" + end + end + + alter table(:users) do + modify :confirmed_at, :"timestamp without time zone", + from: :"timestamp(0) without time zone" + end + + # Wrong data type, created by Rails (timestamp(6) without time zone) + for table <- [:image_features, :static_pages, :static_page_versions] do + alter table(table) do + modify :created_at, :"timestamp without time zone", + from: :"timestamp(6) without time zone" + + modify :updated_at, :"timestamp without time zone", + from: :"timestamp(6) without time zone" + end + end + end +end diff --git a/priv/repo/structure.sql b/priv/repo/structure.sql index 49678d33..b7bd0cda 100644 --- a/priv/repo/structure.sql +++ b/priv/repo/structure.sql @@ -2,7 +2,7 @@ -- PostgreSQL database dump -- --- Dumped from database version 16.3 +-- Dumped from database version 16.4 -- Dumped by pg_dump version 16.3 SET statement_timeout = 0; @@ -40,18 +40,18 @@ SET default_table_access_method = heap; CREATE TABLE public.adverts ( id integer NOT NULL, - image character varying, - link character varying, - title character varying, - clicks integer DEFAULT 0, - impressions integer DEFAULT 0, - live boolean DEFAULT false, - start_date timestamp without time zone, - finish_date timestamp without time zone, + image character varying NOT NULL, + link character varying NOT NULL, + title character varying NOT NULL, + clicks integer DEFAULT 0 NOT NULL, + impressions integer DEFAULT 0 NOT NULL, + live boolean DEFAULT false NOT NULL, + start_date timestamp without time zone NOT NULL, + finish_date timestamp without time zone NOT NULL, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, - restrictions character varying, - notes character varying + restrictions character varying NOT NULL, + notes character varying DEFAULT ''::character varying NOT NULL ); @@ -82,8 +82,6 @@ CREATE TABLE public.artist_links ( id integer NOT NULL, aasm_state character varying NOT NULL, uri character varying NOT NULL, - hostname character varying, - path character varying, verification_code character varying NOT NULL, public boolean DEFAULT true NOT NULL, next_check_at timestamp without time zone, @@ -122,7 +120,7 @@ ALTER SEQUENCE public.artist_links_id_seq OWNED BY public.artist_links.id; CREATE TABLE public.autocomplete ( content bytea NOT NULL, - created_at timestamp(0) without time zone NOT NULL + created_at timestamp without time zone NOT NULL ); @@ -132,15 +130,15 @@ CREATE TABLE public.autocomplete ( CREATE TABLE public.badge_awards ( id integer NOT NULL, - label character varying, + label character varying DEFAULT ''::character varying NOT NULL, awarded_on timestamp without time zone NOT NULL, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, user_id integer NOT NULL, badge_id integer NOT NULL, awarded_by_id integer NOT NULL, - reason character varying, - badge_name character varying + reason character varying DEFAULT ''::character varying NOT NULL, + badge_name character varying DEFAULT ''::character varying NOT NULL ); @@ -171,11 +169,11 @@ CREATE TABLE public.badges ( id integer NOT NULL, title character varying NOT NULL, description character varying NOT NULL, - image character varying, + image character varying NOT NULL, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, disable_award boolean DEFAULT false NOT NULL, - priority boolean DEFAULT false + priority boolean DEFAULT false NOT NULL ); @@ -205,8 +203,8 @@ ALTER SEQUENCE public.badges_id_seq OWNED BY public.badges.id; CREATE TABLE public.channel_live_notifications ( channel_id bigint NOT NULL, user_id bigint NOT NULL, - created_at timestamp(0) without time zone NOT NULL, - updated_at timestamp(0) without time zone NOT NULL, + created_at timestamp without time zone NOT NULL, + updated_at timestamp without time zone NOT NULL, read boolean DEFAULT false NOT NULL ); @@ -229,27 +227,15 @@ CREATE TABLE public.channels ( id integer NOT NULL, short_name character varying NOT NULL, title character varying NOT NULL, - channel_image character varying, - tags character varying, viewers integer DEFAULT 0 NOT NULL, nsfw boolean DEFAULT false NOT NULL, is_live boolean DEFAULT false NOT NULL, last_fetched_at timestamp without time zone, - next_check_at timestamp without time zone, - last_live_at timestamp without time zone, - watcher_ids integer[] DEFAULT '{}'::integer[] NOT NULL, - watcher_count integer DEFAULT 0 NOT NULL, type character varying NOT NULL, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, associated_artist_tag_id integer, - viewer_minutes_today integer DEFAULT 0 NOT NULL, - viewer_minutes_thisweek integer DEFAULT 0 NOT NULL, - viewer_minutes_thismonth integer DEFAULT 0 NOT NULL, - total_viewer_minutes integer DEFAULT 0 NOT NULL, - banner_image character varying, - remote_stream_id integer, - thumbnail_url character varying DEFAULT ''::character varying + thumbnail_url character varying DEFAULT ''::character varying NOT NULL ); @@ -278,25 +264,21 @@ ALTER SEQUENCE public.channels_id_seq OWNED BY public.channels.id; CREATE TABLE public.comments ( id integer NOT NULL, - body_textile character varying DEFAULT ''::character varying NOT NULL, - ip inet, - fingerprint character varying, - user_agent character varying DEFAULT ''::character varying, - referrer character varying DEFAULT ''::character varying, - anonymous boolean DEFAULT false, + ip inet NOT NULL, + fingerprint character varying NOT NULL, + anonymous boolean DEFAULT false NOT NULL, hidden_from_users boolean DEFAULT false NOT NULL, user_id integer, deleted_by_id integer, - image_id integer, + image_id integer NOT NULL, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, edit_reason character varying, edited_at timestamp without time zone, deletion_reason character varying DEFAULT ''::character varying NOT NULL, - destroyed_content boolean DEFAULT false, - name_at_post_time character varying, + destroyed_content boolean DEFAULT false NOT NULL, body character varying NOT NULL, - approved boolean DEFAULT false + approved boolean DEFAULT false NOT NULL ); @@ -325,16 +307,14 @@ ALTER SEQUENCE public.comments_id_seq OWNED BY public.comments.id; CREATE TABLE public.commission_items ( id integer NOT NULL, - commission_id integer, - item_type character varying, - description_textile character varying, - base_price numeric, - add_ons_textile character varying, + commission_id integer NOT NULL, + item_type character varying NOT NULL, + base_price numeric NOT NULL, example_image_id integer, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, - description character varying, - add_ons character varying + description character varying NOT NULL, + add_ons character varying DEFAULT ''::character varying NOT NULL ); @@ -366,18 +346,14 @@ CREATE TABLE public.commissions ( user_id integer NOT NULL, open boolean NOT NULL, categories character varying[] DEFAULT '{}'::character varying[] NOT NULL, - information_textile character varying, - contact_textile character varying, sheet_image_id integer, - will_create_textile character varying, - will_not_create_textile character varying, commission_items_count integer DEFAULT 0 NOT NULL, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, - information character varying, - contact character varying, - will_create character varying, - will_not_create character varying + information character varying NOT NULL, + contact character varying NOT NULL, + will_create character varying DEFAULT ''::character varying NOT NULL, + will_not_create character varying DEFAULT ''::character varying NOT NULL ); @@ -450,10 +426,7 @@ CREATE TABLE public.dnp_entries ( tag_id integer NOT NULL, aasm_state character varying DEFAULT 'requested'::character varying NOT NULL, dnp_type character varying NOT NULL, - conditions_textile character varying DEFAULT ''::character varying NOT NULL, - reason_textile character varying DEFAULT ''::character varying NOT NULL, hide_reason boolean DEFAULT false NOT NULL, - instructions_textile character varying DEFAULT ''::character varying NOT NULL, feedback character varying NOT NULL, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, @@ -525,7 +498,7 @@ ALTER SEQUENCE public.donations_id_seq OWNED BY public.donations.id; CREATE TABLE public.duplicate_reports ( id integer NOT NULL, - reason character varying, + reason character varying DEFAULT ''::character varying NOT NULL, state character varying DEFAULT 'open'::character varying NOT NULL, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, @@ -565,8 +538,8 @@ CREATE TABLE public.filters ( description character varying NOT NULL, system boolean DEFAULT false NOT NULL, public boolean DEFAULT false NOT NULL, - hidden_complex_str character varying, - spoilered_complex_str character varying, + hidden_complex_str character varying DEFAULT ''::character varying NOT NULL, + spoilered_complex_str character varying DEFAULT ''::character varying NOT NULL, hidden_tag_ids integer[] DEFAULT '{}'::integer[] NOT NULL, spoilered_tag_ids integer[] DEFAULT '{}'::integer[] NOT NULL, user_count integer DEFAULT 0 NOT NULL, @@ -602,10 +575,10 @@ ALTER SEQUENCE public.filters_id_seq OWNED BY public.filters.id; CREATE TABLE public.fingerprint_bans ( id integer NOT NULL, reason character varying NOT NULL, - note character varying, + note character varying DEFAULT ''::character varying NOT NULL, enabled boolean DEFAULT true NOT NULL, valid_until timestamp without time zone NOT NULL, - fingerprint character varying, + fingerprint character varying NOT NULL, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, banning_user_id integer NOT NULL, @@ -641,8 +614,8 @@ CREATE TABLE public.forum_post_notifications ( topic_id bigint NOT NULL, post_id bigint NOT NULL, user_id bigint NOT NULL, - created_at timestamp(0) without time zone NOT NULL, - updated_at timestamp(0) without time zone NOT NULL, + created_at timestamp without time zone NOT NULL, + updated_at timestamp without time zone NOT NULL, read boolean DEFAULT false NOT NULL ); @@ -664,8 +637,8 @@ CREATE TABLE public.forum_subscriptions ( CREATE TABLE public.forum_topic_notifications ( topic_id bigint NOT NULL, user_id bigint NOT NULL, - created_at timestamp(0) without time zone NOT NULL, - updated_at timestamp(0) without time zone NOT NULL, + created_at timestamp without time zone NOT NULL, + updated_at timestamp without time zone NOT NULL, read boolean DEFAULT false NOT NULL ); @@ -682,8 +655,6 @@ CREATE TABLE public.forums ( access_level character varying DEFAULT 'normal'::character varying NOT NULL, topic_count integer DEFAULT 0 NOT NULL, post_count integer DEFAULT 0 NOT NULL, - watcher_ids integer[] DEFAULT '{}'::integer[] NOT NULL, - watcher_count integer DEFAULT 0 NOT NULL, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, last_post_id integer, @@ -723,8 +694,6 @@ CREATE TABLE public.galleries ( creator_id integer NOT NULL, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, - watcher_ids integer[] DEFAULT '{}'::integer[] NOT NULL, - watcher_count integer DEFAULT 0 NOT NULL, image_count integer DEFAULT 0 NOT NULL, order_position_asc boolean DEFAULT false NOT NULL ); @@ -756,8 +725,8 @@ ALTER SEQUENCE public.galleries_id_seq OWNED BY public.galleries.id; CREATE TABLE public.gallery_image_notifications ( gallery_id bigint NOT NULL, user_id bigint NOT NULL, - created_at timestamp(0) without time zone NOT NULL, - updated_at timestamp(0) without time zone NOT NULL, + created_at timestamp without time zone NOT NULL, + updated_at timestamp without time zone NOT NULL, read boolean DEFAULT false NOT NULL ); @@ -811,8 +780,8 @@ CREATE TABLE public.image_comment_notifications ( image_id bigint NOT NULL, comment_id bigint NOT NULL, user_id bigint NOT NULL, - created_at timestamp(0) without time zone NOT NULL, - updated_at timestamp(0) without time zone NOT NULL, + created_at timestamp without time zone NOT NULL, + updated_at timestamp without time zone NOT NULL, read boolean DEFAULT false NOT NULL ); @@ -836,8 +805,8 @@ CREATE TABLE public.image_features ( id bigint NOT NULL, image_id bigint NOT NULL, user_id bigint NOT NULL, - created_at timestamp(6) without time zone NOT NULL, - updated_at timestamp(6) without time zone NOT NULL + created_at timestamp without time zone NOT NULL, + updated_at timestamp without time zone NOT NULL ); @@ -912,8 +881,8 @@ CREATE TABLE public.image_merge_notifications ( target_id bigint NOT NULL, source_id bigint NOT NULL, user_id bigint NOT NULL, - created_at timestamp(0) without time zone NOT NULL, - updated_at timestamp(0) without time zone NOT NULL, + created_at timestamp without time zone NOT NULL, + updated_at timestamp without time zone NOT NULL, read boolean DEFAULT false NOT NULL ); @@ -985,28 +954,18 @@ CREATE TABLE public.images ( image_format character varying, image_mime_type character varying, image_aspect_ratio double precision, - ip inet, - fingerprint character varying, - user_agent character varying DEFAULT ''::character varying, - referrer character varying DEFAULT ''::character varying, - anonymous boolean DEFAULT false, + ip inet NOT NULL, + fingerprint character varying NOT NULL, + anonymous boolean DEFAULT false NOT NULL, score integer DEFAULT 0 NOT NULL, faves_count integer DEFAULT 0 NOT NULL, upvotes_count integer DEFAULT 0 NOT NULL, downvotes_count integer DEFAULT 0 NOT NULL, - votes_count integer DEFAULT 0 NOT NULL, - watcher_ids integer[] DEFAULT '{}'::integer[] NOT NULL, - watcher_count integer DEFAULT 0 NOT NULL, source_url character varying, - description_textile character varying DEFAULT ''::character varying NOT NULL, image_sha512_hash character varying, image_orig_sha512_hash character varying, deletion_reason character varying, - tag_list_cache character varying, - tag_list_plus_alias_cache character varying, - file_name_cache character varying, duplicate_id integer, - tag_ids integer[] DEFAULT '{}'::integer[] NOT NULL, comments_count integer DEFAULT 0 NOT NULL, processed boolean DEFAULT false NOT NULL, thumbnails_generated boolean DEFAULT false NOT NULL, @@ -1018,24 +977,18 @@ CREATE TABLE public.images ( is_animated boolean NOT NULL, first_seen_at timestamp without time zone NOT NULL, featured_on timestamp without time zone, - se_intensity double precision, - sw_intensity double precision, - ne_intensity double precision, - nw_intensity double precision, - average_intensity double precision, user_id integer, deleted_by_id integer, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, destroyed_content boolean DEFAULT false NOT NULL, hidden_image_key character varying, - scratchpad_textile character varying, hides_count integer DEFAULT 0 NOT NULL, image_duration double precision, description character varying DEFAULT ''::character varying NOT NULL, scratchpad character varying, - approved boolean DEFAULT false, - image_orig_size integer + approved boolean DEFAULT false NOT NULL, + image_orig_size integer NOT NULL ); @@ -1064,13 +1017,12 @@ ALTER SEQUENCE public.images_id_seq OWNED BY public.images.id; CREATE TABLE public.messages ( id integer NOT NULL, - body_textile character varying DEFAULT ''::character varying NOT NULL, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, from_id integer NOT NULL, conversation_id integer NOT NULL, body character varying NOT NULL, - approved boolean DEFAULT false + approved boolean DEFAULT false NOT NULL ); @@ -1102,7 +1054,6 @@ CREATE TABLE public.mod_notes ( moderator_id integer NOT NULL, notable_id integer NOT NULL, notable_type character varying NOT NULL, - body_textile text DEFAULT ''::text NOT NULL, deleted boolean DEFAULT false NOT NULL, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, @@ -1139,7 +1090,7 @@ CREATE TABLE public.moderation_logs ( body character varying NOT NULL, subject_path character varying NOT NULL, type character varying NOT NULL, - created_at timestamp(0) without time zone NOT NULL + created_at timestamp without time zone NOT NULL ); @@ -1273,7 +1224,6 @@ ALTER SEQUENCE public.poll_options_id_seq OWNED BY public.poll_options.id; CREATE TABLE public.poll_votes ( id integer NOT NULL, - rank integer, poll_option_id integer NOT NULL, user_id integer NOT NULL, created_at timestamp without time zone NOT NULL @@ -1311,9 +1261,6 @@ CREATE TABLE public.polls ( total_votes integer DEFAULT 0 NOT NULL, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, - hidden_from_users boolean DEFAULT false NOT NULL, - deleted_by_id integer, - deletion_reason character varying DEFAULT ''::character varying NOT NULL, topic_id integer NOT NULL ); @@ -1343,12 +1290,9 @@ ALTER SEQUENCE public.polls_id_seq OWNED BY public.polls.id; CREATE TABLE public.posts ( id integer NOT NULL, - body_textile character varying DEFAULT ''::character varying NOT NULL, edit_reason character varying, - ip inet, - fingerprint character varying, - user_agent character varying DEFAULT ''::character varying, - referrer character varying DEFAULT ''::character varying, + ip inet NOT NULL, + fingerprint character varying NOT NULL, topic_position integer NOT NULL, hidden_from_users boolean DEFAULT false NOT NULL, anonymous boolean DEFAULT false, @@ -1360,9 +1304,8 @@ CREATE TABLE public.posts ( edited_at timestamp without time zone, deletion_reason character varying DEFAULT ''::character varying NOT NULL, destroyed_content boolean DEFAULT false NOT NULL, - name_at_post_time character varying, body character varying NOT NULL, - approved boolean DEFAULT false + approved boolean DEFAULT false NOT NULL ); @@ -1394,8 +1337,6 @@ CREATE TABLE public.reports ( ip inet NOT NULL, fingerprint character varying, user_agent character varying DEFAULT ''::character varying, - referrer character varying DEFAULT ''::character varying, - reason_textile character varying DEFAULT ''::character varying NOT NULL, state character varying DEFAULT 'open'::character varying NOT NULL, open boolean DEFAULT true NOT NULL, created_at timestamp without time zone NOT NULL, @@ -1405,7 +1346,7 @@ CREATE TABLE public.reports ( reportable_id integer NOT NULL, reportable_type character varying NOT NULL, reason character varying NOT NULL, - system boolean DEFAULT false + system boolean DEFAULT false NOT NULL ); @@ -1435,10 +1376,7 @@ ALTER SEQUENCE public.reports_id_seq OWNED BY public.reports.id; CREATE TABLE public.roles ( id integer NOT NULL, name character varying, - resource_id integer, - resource_type character varying, - created_at timestamp without time zone, - updated_at timestamp without time zone + resource_type character varying ); @@ -1518,12 +1456,10 @@ CREATE TABLE public.source_changes ( image_id bigint NOT NULL, user_id bigint, ip inet NOT NULL, - created_at timestamp(0) without time zone NOT NULL, - updated_at timestamp(0) without time zone NOT NULL, + created_at timestamp without time zone NOT NULL, + updated_at timestamp without time zone NOT NULL, added boolean NOT NULL, - fingerprint character varying(255), - user_agent character varying(255) DEFAULT ''::character varying, - referrer character varying(255) DEFAULT ''::character varying, + fingerprint character varying(255) NOT NULL, value character varying(255) NOT NULL ); @@ -1555,8 +1491,8 @@ CREATE TABLE public.static_page_versions ( id bigint NOT NULL, user_id bigint NOT NULL, static_page_id bigint NOT NULL, - created_at timestamp(6) without time zone NOT NULL, - updated_at timestamp(6) without time zone NOT NULL, + created_at timestamp without time zone NOT NULL, + updated_at timestamp without time zone NOT NULL, title text NOT NULL, slug text NOT NULL, body text NOT NULL @@ -1588,8 +1524,8 @@ ALTER SEQUENCE public.static_page_versions_id_seq OWNED BY public.static_page_ve CREATE TABLE public.static_pages ( id bigint NOT NULL, - created_at timestamp(6) without time zone NOT NULL, - updated_at timestamp(6) without time zone NOT NULL, + created_at timestamp without time zone NOT NULL, + updated_at timestamp without time zone NOT NULL, title text NOT NULL, slug text NOT NULL, body text NOT NULL @@ -1622,13 +1558,13 @@ ALTER SEQUENCE public.static_pages_id_seq OWNED BY public.static_pages.id; CREATE TABLE public.subnet_bans ( id integer NOT NULL, reason character varying NOT NULL, - note character varying, + note character varying DEFAULT ''::character varying NOT NULL, enabled boolean DEFAULT true NOT NULL, valid_until timestamp without time zone NOT NULL, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, banning_user_id integer NOT NULL, - specification inet, + specification inet NOT NULL, generated_ban_id character varying NOT NULL, CONSTRAINT subnet_ban_duration_must_be_valid CHECK ((valid_until < '4000-01-01 00:00:00'::timestamp without time zone)) ); @@ -1659,10 +1595,8 @@ ALTER SEQUENCE public.subnet_bans_id_seq OWNED BY public.subnet_bans.id; CREATE TABLE public.tag_changes ( id integer NOT NULL, - ip inet, - fingerprint character varying, - user_agent character varying DEFAULT ''::character varying, - referrer character varying DEFAULT ''::character varying, + ip inet NOT NULL, + fingerprint character varying NOT NULL, added boolean NOT NULL, tag_name_cache character varying DEFAULT ''::character varying NOT NULL, created_at timestamp without time zone NOT NULL, @@ -1700,7 +1634,6 @@ CREATE TABLE public.tags ( id integer NOT NULL, name character varying NOT NULL, slug character varying NOT NULL, - description_textile character varying DEFAULT ''::character varying, short_description character varying DEFAULT ''::character varying, namespace character varying, name_in_namespace character varying, @@ -1771,9 +1704,7 @@ CREATE TABLE public.topics ( deletion_reason character varying, lock_reason character varying, slug character varying NOT NULL, - anonymous boolean DEFAULT false, - watcher_ids integer[] DEFAULT '{}'::integer[] NOT NULL, - watcher_count integer DEFAULT 0 NOT NULL, + anonymous boolean DEFAULT false NOT NULL, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, forum_id integer NOT NULL, @@ -1841,7 +1772,7 @@ ALTER SEQUENCE public.unread_notifications_id_seq OWNED BY public.unread_notific CREATE TABLE public.user_bans ( id integer NOT NULL, reason character varying NOT NULL, - note character varying, + note character varying DEFAULT ''::character varying NOT NULL, enabled boolean DEFAULT true NOT NULL, valid_until timestamp without time zone NOT NULL, created_at timestamp without time zone NOT NULL, @@ -2017,7 +1948,7 @@ CREATE TABLE public.user_tokens ( token bytea NOT NULL, context character varying(255) NOT NULL, sent_to character varying(255), - created_at timestamp(0) without time zone NOT NULL + created_at timestamp without time zone NOT NULL ); @@ -2083,11 +2014,6 @@ CREATE TABLE public.users ( reset_password_token character varying, reset_password_sent_at timestamp without time zone, remember_created_at timestamp without time zone, - sign_in_count integer DEFAULT 0 NOT NULL, - current_sign_in_at timestamp without time zone, - last_sign_in_at timestamp without time zone, - current_sign_in_ip inet, - last_sign_in_ip inet, created_at timestamp without time zone NOT NULL, updated_at timestamp without time zone NOT NULL, deleted_at timestamp without time zone, @@ -2095,7 +2021,6 @@ CREATE TABLE public.users ( name character varying NOT NULL, slug character varying NOT NULL, role character varying DEFAULT 'user'::character varying NOT NULL, - description_textile character varying, avatar character varying, spoiler_type character varying DEFAULT 'static'::character varying NOT NULL, theme character varying DEFAULT 'default'::character varying NOT NULL, @@ -2121,7 +2046,6 @@ CREATE TABLE public.users ( forum_posts_count integer DEFAULT 0 NOT NULL, topic_count integer DEFAULT 0 NOT NULL, recent_filter_ids integer[] DEFAULT '{}'::integer[] NOT NULL, - unread_notification_ids integer[] DEFAULT '{}'::integer[] NOT NULL, watched_tag_ids integer[] DEFAULT '{}'::integer[] NOT NULL, deleted_by_user_id integer, current_filter_id integer, @@ -2133,8 +2057,6 @@ CREATE TABLE public.users ( comments_posted_count integer DEFAULT 0 NOT NULL, metadata_updates_count integer DEFAULT 0 NOT NULL, images_favourited_count integer DEFAULT 0 NOT NULL, - last_donation_at timestamp without time zone, - scratchpad_textile text, use_centered_layout boolean DEFAULT true NOT NULL, secondary_role character varying, hide_default_role boolean DEFAULT false NOT NULL, @@ -2150,7 +2072,7 @@ CREATE TABLE public.users ( otp_backup_codes character varying[], last_renamed_at timestamp without time zone DEFAULT '1970-01-01 00:00:00'::timestamp without time zone NOT NULL, forced_filter_id bigint, - confirmed_at timestamp(0) without time zone, + confirmed_at timestamp without time zone, senior_staff boolean DEFAULT false, description character varying, scratchpad character varying, @@ -2200,7 +2122,7 @@ CREATE TABLE public.versions ( event character varying NOT NULL, whodunnit character varying, object text, - created_at timestamp without time zone + created_at timestamp without time zone NOT NULL ); @@ -3318,13 +3240,6 @@ CREATE INDEX index_channels_on_is_live ON public.channels USING btree (is_live); CREATE INDEX index_channels_on_last_fetched_at ON public.channels USING btree (last_fetched_at); --- --- Name: index_channels_on_next_check_at; Type: INDEX; Schema: public; Owner: - --- - -CREATE INDEX index_channels_on_next_check_at ON public.channels USING btree (next_check_at); - - -- -- Name: index_comments_on_created_at; Type: INDEX; Schema: public; Owner: - -- @@ -3780,13 +3695,6 @@ CREATE INDEX index_images_on_featured_on ON public.images USING btree (featured_ CREATE INDEX index_images_on_image_orig_sha512_hash ON public.images USING btree (image_orig_sha512_hash); --- --- Name: index_images_on_tag_ids; Type: INDEX; Schema: public; Owner: - --- - -CREATE INDEX index_images_on_tag_ids ON public.images USING gin (tag_ids); - - -- -- Name: index_images_on_updated_at; Type: INDEX; Schema: public; Owner: - -- @@ -3878,13 +3786,6 @@ CREATE UNIQUE INDEX index_poll_votes_on_poll_option_id_and_user_id ON public.pol CREATE INDEX index_poll_votes_on_user_id ON public.poll_votes USING btree (user_id); --- --- Name: index_polls_on_deleted_by_id; Type: INDEX; Schema: public; Owner: - --- - -CREATE INDEX index_polls_on_deleted_by_id ON public.polls USING btree (deleted_by_id) WHERE (deleted_by_id IS NOT NULL); - - -- -- Name: index_polls_on_topic_id; Type: INDEX; Schema: public; Owner: - -- @@ -3948,13 +3849,6 @@ CREATE INDEX index_reports_on_open ON public.reports USING btree (open); CREATE INDEX index_reports_on_user_id ON public.reports USING btree (user_id); --- --- Name: index_roles_on_name_and_resource_type_and_resource_id; Type: INDEX; Schema: public; Owner: - --- - -CREATE INDEX index_roles_on_name_and_resource_type_and_resource_id ON public.roles USING btree (name, resource_type, resource_id); - - -- -- Name: index_site_notices_on_start_date_and_finish_date; Type: INDEX; Schema: public; Owner: - -- @@ -4382,13 +4276,6 @@ CREATE INDEX index_versions_on_item_type_and_item_id ON public.versions USING bt CREATE INDEX index_vpns_on_ip ON public.vpns USING gist (ip inet_ops); --- --- Name: intensities_index; Type: INDEX; Schema: public; Owner: - --- - -CREATE INDEX intensities_index ON public.images USING btree (se_intensity, sw_intensity, ne_intensity, nw_intensity, average_intensity); - - -- -- Name: moderation_logs_created_at_index; Type: INDEX; Schema: public; Owner: - -- @@ -4565,14 +4452,6 @@ ALTER TABLE ONLY public.messages ADD CONSTRAINT fk_rails_2bcf7eed31 FOREIGN KEY (from_id) REFERENCES public.users(id) ON UPDATE CASCADE ON DELETE RESTRICT; --- --- Name: polls fk_rails_2bf9149369; Type: FK CONSTRAINT; Schema: public; Owner: - --- - -ALTER TABLE ONLY public.polls - ADD CONSTRAINT fk_rails_2bf9149369 FOREIGN KEY (deleted_by_id) REFERENCES public.users(id) ON UPDATE CASCADE ON DELETE SET NULL; - - -- -- Name: image_hides fk_rails_335978518a; Type: FK CONSTRAINT; Schema: public; Owner: - -- @@ -5447,3 +5326,4 @@ INSERT INTO public."schema_migrations" (version) VALUES (20211219194836); INSERT INTO public."schema_migrations" (version) VALUES (20220321173359); INSERT INTO public."schema_migrations" (version) VALUES (20240723122759); INSERT INTO public."schema_migrations" (version) VALUES (20240728191353); +INSERT INTO public."schema_migrations" (version) VALUES (20240818182358);