diff --git a/sql/upgrade/11.0/README.rst b/sql/upgrade/11.0/README.rst new file mode 100644 index 0000000000..5f704a542b --- /dev/null +++ b/sql/upgrade/11.0/README.rst @@ -0,0 +1,17 @@ +11.0 Database Updates +===================== + +This batch makes the following database changes: + +bug #752074 + Add new functions for adding a manual release to releases_raw, + and changing the featured versions. + Some changes based on changes to the mware. + +bug #?????? + Add product sorting column to product_info. + +... + +The above changes should take only a few minutes to deploy. +This upgrade does not require a downtime. \ No newline at end of file diff --git a/sql/upgrade/11.0/add_release.sql b/sql/upgrade/11.0/add_release.sql new file mode 100644 index 0000000000..4ef33c064b --- /dev/null +++ b/sql/upgrade/11.0/add_release.sql @@ -0,0 +1,66 @@ +\set ON_ERROR_STOP 1 + +CREATE OR REPLACE FUNCTION add_new_release ( + product citext, + version citext, + release_channel citext, + build_id numeric, + platform citext, + beta_number integer default NULL, + repository text default 'release', + update_products boolean default false +) +RETURNS boolean +LANGUAGE plpgsql +AS $f$ +BEGIN +-- adds a new release to the releases_raw table +-- to be picked up by update_products later +-- does some light format validation + +-- check for NULLs, blanks +IF NOT ( nonzero_string(product) AND nonzero_string(version) + AND nonzero_string(release_channel) and nonzero_string(platform) + AND build_id IS NOT NULL ) THEN + RAISE EXCEPTION 'product, version, release_channel, platform and build ID are all required'; +END IF; + +--validations +-- validate product +PERFORM validate_lookup('products','product_name',product,'product'); +--validate channel +PERFORM validate_lookup('release_channels','release_channel',release_channel,'release channel'); +--validate build +IF NOT ( build_date(build_id) BETWEEN '2005-01-01' + AND (current_date + '1 month') ) THEN + RAISE EXCEPTION 'invalid buildid'; +END IF; + +--add row +--duplicate check will occur in the EXECEPTION section +INSERT INTO releases_raw ( + product_name, version, platform, build_id, + build_type, beta_number, repository ) +VALUES ( product, version, platform, build_id, + release_channel, beta_number, repository ); + +--call update_products, if desired +IF update_products THEN + PERFORM update_product_versions(); +END IF; + +--return +RETURN TRUE; + +--exception clause, mainly catches duplicate rows. +EXCEPTION + WHEN UNIQUE_VIOLATION THEN + RAISE EXCEPTION 'the release you have entered is already present in he database'; +END;$f$; + + + + + + + diff --git a/sql/upgrade/11.0/feature_versions.sql b/sql/upgrade/11.0/feature_versions.sql new file mode 100644 index 0000000000..cb6d66b484 --- /dev/null +++ b/sql/upgrade/11.0/feature_versions.sql @@ -0,0 +1,40 @@ +\set ON_ERROR_STOP 1 + +CREATE OR REPLACE FUNCTION edit_featured_versions ( + product citext, + VARIADIC featured_versions text[] +) +RETURNS boolean +LANGUAGE plpgsql +AS $f$ +-- this function allows admins to change the featured versions +-- for a particular product +BEGIN + +--check required parameters +IF NOT ( nonzero_string(product) AND nonzero_string(featured_versions[1]) ) THEN + RAISE EXCEPTION 'a product name and at least one version are required'; +END IF; + +--check that all versions are not expired +SELECT 1 FROM product_versions +WHERE product_name = product + AND version_string = ANY ( featured_versions ) + AND sunset_date < current_date; +IF FOUND THEN + RAISE EXCEPTION 'one or more of the versions you have selected is already expired'; +END IF; + +--Remove disfeatured versions +UPDATE product_versions SET featured_version = false +WHERE featured_version + AND NOT ( version_string = ANY( featured_versions ) ); + +--feature new versions +UPDATE product_versions SET featured_version = true +WHERE version_string = ANY ( featured_versions ) + AND NOT featured_version; + +RETURN TRUE; + +END;$f$; diff --git a/sql/upgrade/11.0/product_views.sql b/sql/upgrade/11.0/product_views.sql new file mode 100644 index 0000000000..da299de642 --- /dev/null +++ b/sql/upgrade/11.0/product_views.sql @@ -0,0 +1,66 @@ +\set ON_ERROR_STOP 1 + +begin; + +drop view if exists product_selector; + +create or replace view product_selector as +select product_name, version_string, 'new'::text as which_table, + version_sort +from product_versions +where now() <= sunset_date +union all +select product, version, 'old'::text as which_ui, + productdims.version_sort +from productdims join product_visibility + on productdims.id = product_visibility.productdims_id + left join product_versions on productdims.product = product_versions.product_name + and ( productdims.version = product_versions.release_version + or productdims.version = product_versions.version_string ) +where product_versions.product_name is null + and now() between product_visibility.start_date and ( product_visibility.end_date + interval '1 day') +order by product_name, version_string; + +alter view product_selector owner to breakpad_rw; + +end; + +-- product_info view +-- used to power several different views of the application + +begin; + +drop view if exists product_info; + +create or replace view product_info as +select product_versions.product_version_id, product_versions.product_name, version_string, 'new'::text as which_table, + build_date as start_date, sunset_date as end_date, + featured_version as is_featured, build_type, + (throttle * 100)::numeric(5,2) as throttle, + version_sort, products.sort as product_sort +from product_versions + JOIN product_release_channels + ON product_versions.product_name = product_release_channels.product_name + AND product_versions.build_type = product_release_channels.release_channel + JOIN products ON product_versions.product_name = products.product_name +union all +select productdims.id, product, version, 'old'::text, + product_visibility.start_date, product_visibility.end_date, + featured, release_build_type_map.build_type, + throttle, + productdims.version_sort, + products.sort as product_sort +from productdims join product_visibility + on productdims.id = product_visibility.productdims_id + join release_build_type_map ON + productdims.release = release_build_type_map.release + JOIN products ON productdims.product::citext = products.product_name + left join product_versions on productdims.product = product_versions.product_name + and ( productdims.version = product_versions.release_version + or productdims.version = product_versions.version_string ) +where product_versions.product_name is null +order by product_name, version_string; + +alter view product_info owner to breakpad_rw; + +end; \ No newline at end of file diff --git a/sql/upgrade/11.0/upgrade.sh b/sql/upgrade/11.0/upgrade.sh new file mode 100755 index 0000000000..4b8a366c0b --- /dev/null +++ b/sql/upgrade/11.0/upgrade.sh @@ -0,0 +1,25 @@ +#!/bin/bash +#please see README + +set -e + +CURDIR=$(dirname $0) +VERSION=11.0 + +echo '*********************************************************' +echo 'functions for adding new releases manually and changing featured versions' +echo 'bug 752074' +psql -f ${CURDIR}/add_release.sql breakpad +psql -f ${CURDIR}/feature_versions.sql breakpad + +echo '*********************************************************' +echo 'add product sorting column to product_info' +echo 'bug ??????' +psql -f ${CURDIR}/product_views.sql breakpad + +#change version in DB +psql -c "SELECT update_socorro_db_version( '$VERSION' )" breakpad + +echo "$VERSION upgrade done" + +exit 0 \ No newline at end of file