Skip to content

Commit

Permalink
Update categories and eligibilities for DCYF. (#744)
Browse files Browse the repository at this point in the history
This adds a migration that makes a large number of changes to categories
and eligibilities, to match the changes requested by DCYF. Each group of
categories and elgibilities is handled a little bit differently, but
they roughly fall into one of the following patterns:

- Create a new category/eligibility
- Rename a category/eligibility
- Mass migrate a number of resources and services from a set of old
  categories/eligibilities to a new one
- Sometimes delete the old categories/eligibilities when doing said mass
  migration, though in some cases preserve the old ones

This was implemented as a pure data migration that does not change the
schema. Since data migrations must be agnostic to the actual models, we
cannot use any of the model code, and instead we construct a number of
raw SQL queries. These queries have been factored into independent
methods so that the main migration code can be read top to bottom with
high-level method calls describing the exact changes being made.
  • Loading branch information
richardxia committed Jun 13, 2024
1 parent 8c5697b commit c812f84
Show file tree
Hide file tree
Showing 2 changed files with 322 additions and 1 deletion.
321 changes: 321 additions & 0 deletions db/migrate/20240610165140_update_dcyf_categories_and_eligibilties.rb
Original file line number Diff line number Diff line change
@@ -0,0 +1,321 @@
class UpdateDcyfCategoriesAndEligibilties < ActiveRecord::Migration[6.1]
def up
ActiveRecord::Base.transaction do
# Set this to true to enable assertions
@assertions_enabled = true

## Categories

# Arts and Creative Expression
['Creative Writing', 'Music', 'Performing Arts', 'Photography and Film', 'Spoken Word', 'Theater', 'Visual Arts'].each do |from|
migrate_resources_and_services_to_new_category from: from, to: 'Arts and Creative Expression'
delete_category from
end

# Digital Media Production
rename_category from: 'Digital Arts', to: 'Digital Media Production'

# Disability Support
rename_category from: 'Disability', to: 'Disability Support'

# Justice Involvement
create_category 'Justice Involvement'

# LGBTQ+ Support
rename_category from: 'LGBTQ', to: 'LGBTQ+ Support'

# After & Before School Care
create_category 'After & Before School Care'

['After School Care', 'Afterschool Programs', 'Before School Care'].each do |from|
migrate_resources_and_services_to_new_category from: from, to: 'After & Before School Care'
delete_category from
end

# Playgroups
create_category 'Playgroups'

# Academic Support
create_category 'Academic Support'

['Academic', 'Education', 'Educational Supports', 'Tutoring', 'School Care'].each do |from|
migrate_resources_and_services_to_new_category from: from, to: 'Academic Support'
delete_category from
end
# Summer Programs is special in that we do not want to delete it, only
# copy its resources and services over to Academic Support
migrate_resources_and_services_to_new_category from: 'Summer Programs', to: 'Academic Support'

# Alternative Education & GED
create_category 'Alternative Education & GED'

['Alternative Education', 'GED/High School Equivalency', 'GED/High-School Equivalency'].each do |from|
migrate_resources_and_services_to_new_category from: from, to: 'Alternative Education & GED'
delete_category from
end

# Free City College
create_category 'Free City College'

# Learning English
rename_category from: 'Language', to: 'Learning English'

# Public Schools
create_category 'Public Schools'

# Reading & Literacy
rename_category from: 'Literacy Supports', to: 'Reading & Literacy'

# Child Welfare Services
create_category 'Child Welfare Services'

# Foster Care Services
rename_category from: 'Foster Care', to: 'Foster Care Services'

# Housing & Rental Assistance
rename_category from: 'Housing', to: 'Housing & Rental Assistance'

['Housing Assistance', 'Emergency Rental Assistance'].each do |from|
migrate_resources_and_services_to_new_category from: from, to: 'Housing & Rental Assistance'
end

# Immigration Assistance
create_category 'Immigration Assistance'

migrate_resources_and_services_to_new_category from: 'Citizenship & Immigration', to: 'Immigration Assistance'

# Teen Parents
create_category 'Teen Parents'

# Crisis Intervention
create_category 'Crisis Intervention'

['Suicide', 'Sexual Assault Hotlines', 'Hotlines and Case Management', 'Help Hotlines', 'Domestic Violence Hotlines'].each do |from|
migrate_resources_and_services_to_new_category from: from, to: 'Crisis Intervention'
end

# Gardening
rename_category from: 'Nature & Gardening', to: 'Gardening'

# Physical Fitness
create_category 'Physical Fitness'

['Fitness & Exercise', 'Fitness/Exercise'].each do |from|
migrate_resources_and_services_to_new_category from: from, to: 'Physical Fitness'
delete_category from
end

# Team Sports
create_category 'Team Sports'

['Basketball', 'Cheer', 'Dance', 'Football', 'Rec Teams', 'Soccer', 'Sports', 'Surfing', 'Swimming', 'Ultimate Frisbee'].each do |from|
migrate_resources_and_services_to_new_category from: from, to: 'Team Sports'
delete_category from
end

# Apprenticeship
create_category 'Apprenticeship'

# Career Exploration
rename_category from: 'Career Awareness', to: 'Career Exploration'

# Youth Jobs & Internships
rename_category from: 'Internships', to: 'Youth Jobs & Internships'


## Eligibilities

# Hispanic/Latinx
rename_eligibility from: 'Latinx', to: 'Hispanic/Latinx'

# Middle School
rename_eligibility from: 'Middle School Students', to: 'Middle School'

# High School
rename_eligibility from: 'High School Students', to: 'High School'

# College
rename_eligibility from: 'College Students', to: 'College'

# CSF
create_eligibility 'CCSF'

# Experiencing Homelessness
rename_eligibility from: 'I am someone experiencing homelessness', to: 'Experiencing Homelessness'
migrate_services_to_new_eligibility from: 'Homeless', to: 'Experiencing Homelessness'
delete_eligibility 'Homeless'

# Boys
create_eligibility 'Boys'

# Girls
create_eligibility 'Girls'
end
end

def down
raise ActiveRecord::IrreversibleMigration
end

private

def rename_category(from:, to:)
assert_category_exists from
assert_category_does_not_exist to

exec_query <<-SQL, "rename category from #{from} to #{to}", [to, from]
UPDATE categories
SET name = $1
WHERE name = $2;
SQL
end

def create_category(name)
assert_category_does_not_exist name

exec_query <<-SQL, "create category #{name}", [name]
INSERT INTO categories (name, created_at, updated_at)
VALUES ($1, now(), now())
ON CONFLICT (name) DO NOTHING;
SQL
end

# Note: This does not create the new category or delete the old ones, since
# for some migrations, we already have the new category, and for some
# migrations, we should preserve the existing categories.
def migrate_resources_and_services_to_new_category(from:, to:)
assert_category_exists from
assert_category_exists to

exec_query <<-SQL, "migrate resources from #{from} to #{to}", [to, from]
INSERT INTO categories_resources
SELECT DISTINCT resources.id as resource_id, (SELECT categories.id FROM categories WHERE categories.name = $1 LIMIT 1) as category_id
FROM resources
INNER JOIN categories_resources ON categories_resources.resource_id = resources.id
INNER JOIN categories ON categories_resources.category_id = categories.id
WHERE categories.name = $2
-- Avoid inserting duplicate rows by excluding resources already associated with this category
AND resource_id NOT IN (
SELECT categories_resources.resource_id
FROM categories_resources
INNER JOIN categories ON categories_resources.category_id = categories.id
WHERE categories.name = $1
);
SQL

exec_query <<-SQL, "migrate services from #{from} to #{to}", [to, from]
INSERT INTO categories_services
SELECT DISTINCT services.id as service_id, (SELECT categories.id FROM categories WHERE categories.name = $1 LIMIT 1) as category_id
FROM services
INNER JOIN categories_services ON categories_services.service_id = services.id
INNER JOIN categories ON categories_services.category_id = categories.id
WHERE categories.name = $2
-- Avoid inserting duplicate rows by excluding services already associated with this category
AND service_id NOT IN (
SELECT categories_services.service_id
FROM categories_services
INNER JOIN categories ON categories_services.category_id = categories.id
WHERE categories.name = $1
);
SQL
end

def delete_category(name)
assert_category_exists name

# categories_sites doesn't have a cascade delete for categories, so we have to manually delete from it
exec_query <<-SQL, "delete category_sites category #{name}", [name]
DELETE FROM categories_sites
WHERE category_id IN (SELECT id FROM categories WHERE name = $1);
SQL

exec_query <<-SQL, "delete category #{name}", [name]
DELETE FROM categories
WHERE name = $1;
SQL
end

def assert_category_exists(name)
return unless @assertions_enabled

count = select_value("SELECT COUNT(*) FROM categories WHERE name = $1", "count category #{name}", [name])
raise "Expected category #{name} to exist, got #{count} results" unless count == 1
end

def assert_category_does_not_exist(name)
return unless @assertions_enabled

count = select_value("SELECT COUNT(*) FROM categories WHERE name = $1", "count category #{name}", [name])
raise "Expected category #{name} to not exist, got #{count} results" unless count == 0
end

def create_eligibility(name)
assert_eligibility_does_not_exist name

exec_query <<-SQL, "create eligibility #{name}", [name]
INSERT INTO eligibilities (name, created_at, updated_at)
VALUES ($1, now(), now())
ON CONFLICT (name) DO NOTHING;
SQL
end

def rename_eligibility(from:, to:)
assert_eligibility_exists from
assert_eligibility_does_not_exist to

exec_query <<-SQL, "rename eligibility from #{from} to #{to}", [to, from]
UPDATE eligibilities
SET name = $1
WHERE name = $2;
SQL
end

def delete_eligibility(name)
assert_eligibility_exists name

exec_query <<-SQL, "delete eligibility #{name}", [name]
DELETE FROM eligibilities
WHERE name = $1;
SQL
end

# Note: This does not create the new eligibility or delete the old ones, since
# for some migrations, we already have the new eligibility, and for some
# migrations, we should preserve the existing eligibilities.
# Also note that there is no m2m join table between eligibilities and
# resources, so this only performs the migration for services.
def migrate_services_to_new_eligibility(from:, to:)
assert_eligibility_exists from
assert_eligibility_exists to

exec_query <<-SQL, "migrate services from #{from} to #{to}", [to, from]
INSERT INTO eligibilities_services
SELECT DISTINCT services.id as service_id, (SELECT eligibilities.id FROM eligibilities WHERE eligibilities.name = $1 LIMIT 1) as eligibility_id
FROM services
INNER JOIN eligibilities_services ON eligibilities_services.service_id = services.id
INNER JOIN eligibilities ON eligibilities_services.eligibility_id = eligibilities.id
WHERE eligibilities.name = $2
-- Avoid inserting duplicate rows by excluding services already associated with this eligibility
AND service_id NOT IN (
SELECT eligibilities_services.service_id
FROM eligibilities_services
INNER JOIN eligibilities ON eligibilities_services.eligibility_id = eligibilities.id
WHERE eligibilities.name = $1
);
SQL
end

def assert_eligibility_exists(name)
return unless @assertions_enabled

count = select_value("SELECT COUNT(*) FROM eligibilities WHERE name = $1", "count eligibility #{name}", [name])
raise "Expected eligibility #{name} to exist, got #{count} results" unless count == 1
end

def assert_eligibility_does_not_exist(name)
return unless @assertions_enabled

count = select_value("SELECT COUNT(*) FROM eligibilities WHERE name = $1", "count eligibility #{name}", [name])
raise "Expected eligibility #{name} to not exist, got #{count} results" unless count == 0
end
end
2 changes: 1 addition & 1 deletion db/schema.rb
Original file line number Diff line number Diff line change
Expand Up @@ -10,7 +10,7 @@
#
# It's strongly recommended that you check this file into your version control system.

ActiveRecord::Schema.define(version: 2024_05_01_005404) do
ActiveRecord::Schema.define(version: 2024_06_10_165140) do

# These are extensions that must be enabled in order to support this database
enable_extension "plpgsql"
Expand Down

0 comments on commit c812f84

Please sign in to comment.