From 61130e8697051586b9b537a5071a1d2ae6882ba0 Mon Sep 17 00:00:00 2001 From: Raminder Singh Date: Tue, 5 Dec 2023 13:38:00 +0530 Subject: [PATCH 01/16] add default version to the app.packages table --- .../20231205051816_add_default_version.sql | 44 +++++++++++++++++++ 1 file changed, 44 insertions(+) create mode 100644 supabase/migrations/20231205051816_add_default_version.sql diff --git a/supabase/migrations/20231205051816_add_default_version.sql b/supabase/migrations/20231205051816_add_default_version.sql new file mode 100644 index 00000000..ad984aac --- /dev/null +++ b/supabase/migrations/20231205051816_add_default_version.sql @@ -0,0 +1,44 @@ +-- The original semver domain defined in 20220117141507_semver.sql doesn't allow null +-- app.semver_struct values, but we need a nullable app.semver column for the new +-- default_version_struct column in the app.packages table (see alter table app.package below). +-- So we modify the `is_valid` function such that it returns true if the input version itself is +-- null. All the existing tables where app.semver domain is used already have an additional +-- non null constraint, so their behaviour doesn't change. +create or replace function app.is_valid(version app.semver_struct) + returns boolean + immutable + language sql +as $$ + select ( + version is null or ( + version.major is not null + and version.minor is not null + and version.patch is not null + ) + ) +$$; + +-- same definition as the original function defined in 20220117141507_semver.sql with the only +-- difference being that this is marked strict. This is done so that the function returns null +-- on null input instead of `..` +create or replace function app.semver_to_text(version app.semver) + returns text + immutable + strict + language sql +as $$ + select + format('%s.%s.%s', version.major, version.minor, version.patch) +$$; + +-- default version columns are nullable for backward compatibility with older clients +alter table app.packages +add column default_version_struct app.semver, +add column default_version text generated always as (app.semver_to_text(default_version_struct)) stored; + +-- for now we set the default version to current latest version +-- new client will allow users to set a specific default version in the control file +update app.packages +set default_version_struct = app.text_to_semver(pp.latest_version) +from public.packages pp +where packages.id = pp.id; From 7398c4a74629547f2dcb511e37f32057c4834d49 Mon Sep 17 00:00:00 2001 From: Raminder Singh Date: Tue, 5 Dec 2023 14:32:30 +0530 Subject: [PATCH 02/16] update public.packages view to include default_version column --- .../20231205051816_add_default_version.sql | 22 +++++++++++++++++++ 1 file changed, 22 insertions(+) diff --git a/supabase/migrations/20231205051816_add_default_version.sql b/supabase/migrations/20231205051816_add_default_version.sql index ad984aac..8a8598e4 100644 --- a/supabase/migrations/20231205051816_add_default_version.sql +++ b/supabase/migrations/20231205051816_add_default_version.sql @@ -42,3 +42,25 @@ update app.packages set default_version_struct = app.text_to_semver(pp.latest_version) from public.packages pp where packages.id = pp.id; + +create or replace view public.packages as + select + pa.id, + pa.package_name, + pa.handle, + pa.partial_name, + newest_ver.version as latest_version, + newest_ver.description_md, + pa.control_description, + pa.control_requires, + pa.created_at, + pa.default_version + from + app.packages pa, + lateral ( + select * + from app.package_versions pv + where pv.package_id = pa.id + order by pv.version_struct + limit 1 + ) newest_ver; From 9f6819d079c5afc0b2b9f3feaab3f50d3ea7b781 Mon Sep 17 00:00:00 2001 From: Raminder Singh Date: Tue, 5 Dec 2023 14:45:08 +0530 Subject: [PATCH 03/16] add default_version arg in publish_package function --- .../20231205051816_add_default_version.sql | 43 +++++++++++++++++++ 1 file changed, 43 insertions(+) diff --git a/supabase/migrations/20231205051816_add_default_version.sql b/supabase/migrations/20231205051816_add_default_version.sql index 8a8598e4..70113a6b 100644 --- a/supabase/migrations/20231205051816_add_default_version.sql +++ b/supabase/migrations/20231205051816_add_default_version.sql @@ -43,6 +43,7 @@ set default_version_struct = app.text_to_semver(pp.latest_version) from public.packages pp where packages.id = pp.id; +-- add new default_version column to the view create or replace view public.packages as select pa.id, @@ -64,3 +65,45 @@ create or replace view public.packages as order by pv.version_struct limit 1 ) newest_ver; + +-- publish_package accepts an additional `default_version` argument +create or replace function public.publish_package( + package_name app.valid_name, + package_description varchar(1000), + relocatable bool default false, + requires text[] default '{}', + default_version text default null +) + returns void + language plpgsql +as $$ +declare + account app.accounts = account from app.accounts account where id = auth.uid(); + require text; +begin + if account.handle is null then + raise exception 'user not logged in'; + end if; + + foreach require in array requires + loop + if not exists ( + select true + from app.allowed_extensions + where + name = require + ) then + raise exception '`requires` in the control file can''t have `%` in it', require; + end if; + end loop; + + insert into app.packages(handle, partial_name, control_description, control_relocatable, control_requires, default_version_struct) + values (account.handle, package_name, package_description, relocatable, requires, app.text_to_semver(default_version)) + on conflict on constraint packages_handle_partial_name_key + do update + set control_description = excluded.control_description, + control_relocatable = excluded.control_relocatable, + control_requires = excluded.control_requires, + default_version_struct = excluded.default_version_struct; +end; +$$; From 74065894b28cbd49e98a783d8f90bc2004433a59 Mon Sep 17 00:00:00 2001 From: Raminder Singh Date: Tue, 5 Dec 2023 15:26:15 +0530 Subject: [PATCH 04/16] add missing permissions on the default_version_struct column --- .../migrations/20231205051816_add_default_version.sql | 8 ++++++++ 1 file changed, 8 insertions(+) diff --git a/supabase/migrations/20231205051816_add_default_version.sql b/supabase/migrations/20231205051816_add_default_version.sql index 70113a6b..f5b9c4ee 100644 --- a/supabase/migrations/20231205051816_add_default_version.sql +++ b/supabase/migrations/20231205051816_add_default_version.sql @@ -66,6 +66,14 @@ create or replace view public.packages as limit 1 ) newest_ver; +grant insert (partial_name, handle, control_description, control_relocatable, control_requires, default_version_struct) + on app.packages + to authenticated; + +grant update (control_description, control_relocatable, control_requires, default_version_struct) + on app.packages + to authenticated; + -- publish_package accepts an additional `default_version` argument create or replace function public.publish_package( package_name app.valid_name, From 40b55c154999f8b18fe185a78c1a26290ebceafd Mon Sep 17 00:00:00 2001 From: Raminder Singh Date: Tue, 5 Dec 2023 15:44:43 +0530 Subject: [PATCH 05/16] send default_version in 'dbdev publish' command --- cli/src/client.rs | 1 + cli/src/commands/publish.rs | 24 ++++++++++++++++++++++++ 2 files changed, 25 insertions(+) diff --git a/cli/src/client.rs b/cli/src/client.rs index c4c0244d..1afb04c1 100644 --- a/cli/src/client.rs +++ b/cli/src/client.rs @@ -165,6 +165,7 @@ pub struct PublishPackageRequest<'a> { pub package_description: &'a Option, pub relocatable: bool, pub requires: &'a [String], + pub default_version: &'a str, } #[derive(Serialize)] diff --git a/cli/src/commands/publish.rs b/cli/src/commands/publish.rs index c70bc193..3d25c9c9 100644 --- a/cli/src/commands/publish.rs +++ b/cli/src/commands/publish.rs @@ -1,3 +1,4 @@ +use std::collections::HashSet; use std::path::Path; use crate::client::{ @@ -21,7 +22,14 @@ pub async fn publish( return Err(anyhow::anyhow!("No `README.md` file found")); }; + let valid_versions = get_valid_versions(&payload); let request = create_publish_package_request(&payload); + if !valid_versions.contains(request.default_version) { + return Err(anyhow::anyhow!( + "default_version in control file should be set to one of the following: {}", + valid_versions.into_iter().collect::>().join(", ") + )); + } client.publish_package(&jwt, &request).await?; if payload.install_files.is_empty() { @@ -78,6 +86,7 @@ fn create_publish_package_request(payload: &Payload) -> PublishPackageRequest { package_description: &payload.metadata.comment, relocatable: payload.metadata.relocatable, requires: &payload.metadata.requires, + default_version: &payload.metadata.default_version, } } @@ -105,3 +114,18 @@ fn create_publich_package_upgrade_request<'a>( upgrade_source: &upgrade_file.body, } } + +fn get_valid_versions(payload: &Payload) -> HashSet<&str> { + let mut valid_versions: HashSet<&str> = HashSet::new(); + + for install_file in &payload.install_files { + valid_versions.insert(&install_file.version); + } + + for upgrade_file in &payload.upgrade_files { + valid_versions.insert(&upgrade_file.from_version); + valid_versions.insert(&upgrade_file.to_version); + } + + valid_versions +} From fc1860202adc864408c3a2429a104172d2dc8ade Mon Sep 17 00:00:00 2001 From: Raminder Singh Date: Tue, 5 Dec 2023 16:36:23 +0530 Subject: [PATCH 06/16] update dbdev in db client to support default_version --- ...5101809_dbdev_supports_default_version.sql | 334 ++++++++++++++++++ 1 file changed, 334 insertions(+) create mode 100644 supabase/migrations/20231205101809_dbdev_supports_default_version.sql diff --git a/supabase/migrations/20231205101809_dbdev_supports_default_version.sql b/supabase/migrations/20231205101809_dbdev_supports_default_version.sql new file mode 100644 index 00000000..c9837af2 --- /dev/null +++ b/supabase/migrations/20231205101809_dbdev_supports_default_version.sql @@ -0,0 +1,334 @@ +insert into app.package_versions(package_id, version_struct, sql, description_md) +values ( +(select id from app.packages where package_name = 'supabase-dbdev'), +(0,0,4), +$pkg$ + +create schema dbdev; + +create or replace function dbdev.install(package_name text) + returns bool + language plpgsql +as $$ +declare + -- Endpoint + base_url text = 'https://api.database.dev/rest/v1/'; + apikey text = 'eyJhbGciOiJIUzI1NiIsInR5cCI6IkpXVCJ9.eyJpc3MiOiJzdXBhYmFzZSIsInJlZiI6InhtdXB0cHBsZnZpaWZyYndtbXR2Iiwicm9sZSI6ImFub24iLCJpYXQiOjE2ODAxMDczNzIsImV4cCI6MTk5NTY4MzM3Mn0.z2CN0mvO2No8wSi46Gw59DFGCTJrzM0AQKsu_5k134s'; + + http_ext_schema regnamespace = extnamespace::regnamespace from pg_catalog.pg_extension where extname = 'http' limit 1; + pgtle_is_available bool = true from pg_catalog.pg_extension where extname = 'pg_tle' limit 1; + -- HTTP respones + rec jsonb; + status int; + contents json; + + -- Install Record + rec_sql text; + rec_ver text; + rec_from_ver text; + rec_to_ver text; + rec_package_name text; + rec_description text; + rec_requires text[]; + rec_default_ver text; +begin + + if http_ext_schema is null then + raise exception using errcode='22000', message=format('dbdev requires the http extension and it is not available'); + end if; + + if pgtle_is_available is null then + raise exception using errcode='22000', message=format('dbdev requires the pgtle extension and it is not available'); + end if; + + ------------------- + -- Base Versions -- + ------------------- + execute $stmt$select row_to_json(x) + from $stmt$ || pg_catalog.quote_ident(http_ext_schema::text) || $stmt$.http( + ( + 'GET', + format( + '%spackage_versions?select=package_name,version,sql,control_description,control_requires&limit=50&package_name=eq.%s', + $stmt$ || pg_catalog.quote_literal(base_url) || $stmt$, + $stmt$ || pg_catalog.quote_literal($1) || $stmt$ + ), + array[ + ('apiKey', $stmt$ || pg_catalog.quote_literal(apikey) || $stmt$)::http_header + ], + null, + null + ) + ) x + limit 1; $stmt$ + into rec; + + status = (rec ->> 'status')::int; + contents = to_json(rec ->> 'content') #>> '{}'; + + if status <> 200 then + raise notice using errcode='22000', message=format('DBDEV INFO: %s', contents); + raise exception using errcode='22000', message=format('Non-200 response code while loading versions from dbdev'); + end if; + + if contents is null or json_typeof(contents) <> 'array' or json_array_length(contents) = 0 then + raise exception using errcode='22000', message=format('No versions for package named %s', package_name); + end if; + + for rec_package_name, rec_ver, rec_sql, rec_description, rec_requires in select + (r ->> 'package_name'), + (r ->> 'version'), + (r ->> 'sql'), + (r ->> 'control_description'), + array(select json_array_elements_text((r -> 'control_requires'))) + from + json_array_elements(contents) as r + loop + + -- Install the primary version + if not exists ( + select true + from pgtle.available_extensions() + where + name = rec_package_name + ) then + perform pgtle.install_extension(rec_package_name, rec_ver, rec_package_name, rec_sql, rec_requires); + end if; + + -- Install other available versions + if not exists ( + select true + from pgtle.available_extension_versions() + where + name = rec_package_name + and version = rec_ver + ) then + perform pgtle.install_extension_version_sql(rec_package_name, rec_ver, rec_sql); + end if; + + end loop; + + ---------------------- + -- Upgrade Versions -- + ---------------------- + execute $stmt$select row_to_json(x) + from $stmt$ || pg_catalog.quote_ident(http_ext_schema::text) || $stmt$.http( + ( + 'GET', + format( + '%spackage_upgrades?select=package_name,from_version,to_version,sql&limit=50&package_name=eq.%s', + $stmt$ || pg_catalog.quote_literal(base_url) || $stmt$, + $stmt$ || pg_catalog.quote_literal($1) || $stmt$ + ), + array[ + ('apiKey', $stmt$ || pg_catalog.quote_literal(apikey) || $stmt$)::http_header + ], + null, + null + ) + ) x + limit 1; $stmt$ + into rec; + + status = (rec ->> 'status')::int; + contents = to_json(rec ->> 'content') #>> '{}'; + + if status <> 200 then + raise notice using errcode='22000', message=format('DBDEV INFO: %s', contents); + raise exception using errcode='22000', message=format('Non-200 response code while loading upgrade paths from dbdev'); + end if; + + if json_typeof(contents) <> 'array' then + raise exception using errcode='22000', message=format('Invalid response from dbdev upgrade paths'); + end if; + + for rec_package_name, rec_from_ver, rec_to_ver, rec_sql in select + (r ->> 'package_name'), + (r ->> 'from_version'), + (r ->> 'to_version'), + (r ->> 'sql') + from + json_array_elements(contents) as r + loop + + if not exists ( + select true + from pgtle.extension_update_paths(rec_package_name) + where + source = rec_from_ver + and target = rec_to_ver + and path is not null + ) then + perform pgtle.install_update_path(rec_package_name, rec_from_ver, rec_to_ver, rec_sql); + end if; + end loop; + + ------------------------- + -- Set Default Version -- + ------------------------- + execute $stmt$select row_to_json(x) + from $stmt$ || pg_catalog.quote_ident(http_ext_schema::text) || $stmt$.http( + ( + 'GET', + format( + '%spackages?select=package_name,default_version&limit=1&package_name=eq.%s', + $stmt$ || pg_catalog.quote_literal(base_url) || $stmt$, + $stmt$ || pg_catalog.quote_literal($1) || $stmt$ + ), + array[ + ('apiKey', $stmt$ || pg_catalog.quote_literal(apikey) || $stmt$)::http_header + ], + null, + null + ) + ) x + limit 1; $stmt$ + into rec; + + status = (rec ->> 'status')::int; + contents = to_json(rec ->> 'content') #>> '{}'; + + if status <> 200 then + raise notice using errcode='22000', message=format('DBDEV INFO: %s', contents); + raise exception using errcode='22000', message=format('Non-200 response code while loading packages from dbdev'); + end if; + + if contents is null or json_typeof(contents) <> 'array' or json_array_length(contents) = 0 then + raise exception using errcode='22000', message=format('No package named %s found', package_name); + end if; + + for rec_package_name, rec_default_ver in select + (r ->> 'package_name'), + (r ->> 'default_version') + from + json_array_elements(contents) as r + loop + + perform pgtle.set_default_version(rec_package_name, rec_default_ver); + + end loop; + + -------------------------- + -- Send Download Notice -- + -------------------------- + -- Notifies dbdev that a package has been downloaded and records IP + user agent so we can compute unique download counts + execute $stmt$select row_to_json(x) + from $stmt$ || pg_catalog.quote_ident(http_ext_schema::text) || $stmt$.http( + ( + 'POST', + format( + '%srpc/register_download', + $stmt$ || pg_catalog.quote_literal(base_url) || $stmt$ + ), + array[ + ('apiKey', $stmt$ || pg_catalog.quote_literal(apikey) || $stmt$)::http_header, + ('x-client-info', 'dbdev/0.0.2')::http_header + ], + 'application/json', + json_build_object('package_name', $stmt$ || pg_catalog.quote_literal($1) || $stmt$)::text + ) + ) x + limit 1; $stmt$ + into rec; + + return true; +end; +$$; + +$pkg$, +$description$ +# dbdev + +dbdev is the SQL client for database.new and is the primary way end users interact with the package (pglet) registry. + +dbdev can be used to load packages from the registry. For example: + +```sql +-- Load the package from the package index +select dbdev.install('olirice-index_advisor'); +``` +Where `olirice` is the handle of the author and `index_advisor` is the name of the pglet. + +Once installed, pglets are visible in PostgreSQL as extensions. At that point they can be enabled with standard Postgres commands i.e. the `create extension` + +To improve reproducibility, we recommend __always__ specifying the package version in your `create extension` statements. + +For example: +```sql +-- Enable the extension +create extension "olirice-index_advisor" + schema 'public' + version '0.1.0'; +``` + +Which creates all tables/indexes/functions/etc specified by the extension. + +## How to Install + +The in-database SQL client for the package registry is named `dbdev`. You can bootstrap the client with: + +```sql +/*--------------------- +---- install dbdev ---- +---------------------- +Requires: + - pg_tle: https://github.com/aws/pg_tle + - pgsql-http: https://github.com/pramsey/pgsql-http +*/ +create extension if not exists http with schema extensions; +create extension if not exists pg_tle; +select pgtle.uninstall_extension_if_exists('supabase-dbdev'); +drop extension if exists "supabase-dbdev"; +select + pgtle.install_extension( + 'supabase-dbdev', + resp.contents ->> 'version', + 'PostgreSQL package manager', + resp.contents ->> 'sql' + ) +from http( + ( + 'GET', + 'https://api.database.dev/rest/v1/' + || 'package_versions?select=sql,version' + || '&package_name=eq.supabase-dbdev' + || '&order=version.desc' + || '&limit=1', + array[ + ( + 'apiKey', + 'eyJhbGciOiJIUzI1NiIsInR5cCI6IkpXVCJ9.eyJp' + || 'c3MiOiJzdXBhYmFzZSIsInJlZiI6InhtdXB0cHBsZnZpaWZyY' + || 'ndtbXR2Iiwicm9sZSI6ImFub24iLCJpYXQiOjE2ODAxMDczNzI' + || 'sImV4cCI6MTk5NTY4MzM3Mn0.z2CN0mvO2No8wSi46Gw59DFGCTJ' + || 'rzM0AQKsu_5k134s' + )::http_header + ], + null, + null + ) +) x, +lateral ( + select + ((row_to_json(x) -> 'content') #>> '{}')::json -> 0 +) resp(contents); +create extension "supabase-dbdev"; +select dbdev.install('supabase-dbdev'); +drop extension if exists "supabase-dbdev"; +create extension "supabase-dbdev"; +``` + +With the client ready, search for packages on [database.dev](database.dev) and install them with + +```sql +select dbdev.install('handle-package_name'); +create extension "handle-package_name" + schema 'public' + version '1.2.3'; +``` +$description$ +); + +update app.packages +set default_version_struct = app.text_to_semver('0.0.4') +where package_name = 'supabase-dbdev'; From a29461d583df0df1a0e5b19a0d5a84d6155ed76b Mon Sep 17 00:00:00 2001 From: Raminder Singh Date: Tue, 5 Dec 2023 17:11:09 +0530 Subject: [PATCH 07/16] allow setting base_url and api_key in dbdev.install to help test locally --- ...5101809_dbdev_supports_default_version.sql | 20 +++++++++---------- 1 file changed, 10 insertions(+), 10 deletions(-) diff --git a/supabase/migrations/20231205101809_dbdev_supports_default_version.sql b/supabase/migrations/20231205101809_dbdev_supports_default_version.sql index c9837af2..1d4dfd6b 100644 --- a/supabase/migrations/20231205101809_dbdev_supports_default_version.sql +++ b/supabase/migrations/20231205101809_dbdev_supports_default_version.sql @@ -6,15 +6,15 @@ $pkg$ create schema dbdev; -create or replace function dbdev.install(package_name text) +create or replace function dbdev.install( + package_name text, + base_url text default 'https://api.database.dev/rest/v1/', + api_key text default 'eyJhbGciOiJIUzI1NiIsInR5cCI6IkpXVCJ9.eyJpc3MiOiJzdXBhYmFzZSIsInJlZiI6InhtdXB0cHBsZnZpaWZyYndtbXR2Iiwicm9sZSI6ImFub24iLCJpYXQiOjE2ODAxMDczNzIsImV4cCI6MTk5NTY4MzM3Mn0.z2CN0mvO2No8wSi46Gw59DFGCTJrzM0AQKsu_5k134s' +) returns bool language plpgsql as $$ declare - -- Endpoint - base_url text = 'https://api.database.dev/rest/v1/'; - apikey text = 'eyJhbGciOiJIUzI1NiIsInR5cCI6IkpXVCJ9.eyJpc3MiOiJzdXBhYmFzZSIsInJlZiI6InhtdXB0cHBsZnZpaWZyYndtbXR2Iiwicm9sZSI6ImFub24iLCJpYXQiOjE2ODAxMDczNzIsImV4cCI6MTk5NTY4MzM3Mn0.z2CN0mvO2No8wSi46Gw59DFGCTJrzM0AQKsu_5k134s'; - http_ext_schema regnamespace = extnamespace::regnamespace from pg_catalog.pg_extension where extname = 'http' limit 1; pgtle_is_available bool = true from pg_catalog.pg_extension where extname = 'pg_tle' limit 1; -- HTTP respones @@ -54,7 +54,7 @@ begin $stmt$ || pg_catalog.quote_literal($1) || $stmt$ ), array[ - ('apiKey', $stmt$ || pg_catalog.quote_literal(apikey) || $stmt$)::http_header + ('apiKey', $stmt$ || pg_catalog.quote_literal(api_key) || $stmt$)::http_header ], null, null @@ -72,7 +72,7 @@ begin end if; if contents is null or json_typeof(contents) <> 'array' or json_array_length(contents) = 0 then - raise exception using errcode='22000', message=format('No versions for package named %s', package_name); + raise exception using errcode='22000', message=format('No versions found for package named %s', package_name); end if; for rec_package_name, rec_ver, rec_sql, rec_description, rec_requires in select @@ -121,7 +121,7 @@ begin $stmt$ || pg_catalog.quote_literal($1) || $stmt$ ), array[ - ('apiKey', $stmt$ || pg_catalog.quote_literal(apikey) || $stmt$)::http_header + ('apiKey', $stmt$ || pg_catalog.quote_literal(api_key) || $stmt$)::http_header ], null, null @@ -176,7 +176,7 @@ begin $stmt$ || pg_catalog.quote_literal($1) || $stmt$ ), array[ - ('apiKey', $stmt$ || pg_catalog.quote_literal(apikey) || $stmt$)::http_header + ('apiKey', $stmt$ || pg_catalog.quote_literal(api_key) || $stmt$)::http_header ], null, null @@ -221,7 +221,7 @@ begin $stmt$ || pg_catalog.quote_literal(base_url) || $stmt$ ), array[ - ('apiKey', $stmt$ || pg_catalog.quote_literal(apikey) || $stmt$)::http_header, + ('apiKey', $stmt$ || pg_catalog.quote_literal(api_key) || $stmt$)::http_header, ('x-client-info', 'dbdev/0.0.2')::http_header ], 'application/json', From 005a3a14c001809dcb4a570ca7eaed2dfa1406f6 Mon Sep 17 00:00:00 2001 From: Raminder Singh Date: Tue, 5 Dec 2023 19:24:18 +0530 Subject: [PATCH 08/16] add a comment --- supabase/migrations/20231205051816_add_default_version.sql | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/supabase/migrations/20231205051816_add_default_version.sql b/supabase/migrations/20231205051816_add_default_version.sql index f5b9c4ee..cb2fb8ac 100644 --- a/supabase/migrations/20231205051816_add_default_version.sql +++ b/supabase/migrations/20231205051816_add_default_version.sql @@ -1,6 +1,6 @@ -- The original semver domain defined in 20220117141507_semver.sql doesn't allow null -- app.semver_struct values, but we need a nullable app.semver column for the new --- default_version_struct column in the app.packages table (see alter table app.package below). +-- default_version_struct column in the app.packages table (see alter table app.packages below). -- So we modify the `is_valid` function such that it returns true if the input version itself is -- null. All the existing tables where app.semver domain is used already have an additional -- non null constraint, so their behaviour doesn't change. @@ -66,6 +66,7 @@ create or replace view public.packages as limit 1 ) newest_ver; +-- grant insert and update permissions to authenticated users on the new default_version_struct column grant insert (partial_name, handle, control_description, control_relocatable, control_requires, default_version_struct) on app.packages to authenticated; From 8fecb4d464a278e7579638f4ee6e4478246a679c Mon Sep 17 00:00:00 2001 From: Raminder Singh Date: Tue, 5 Dec 2023 19:26:59 +0530 Subject: [PATCH 09/16] add a couple of more comments --- .../20231205101809_dbdev_supports_default_version.sql | 2 ++ 1 file changed, 2 insertions(+) diff --git a/supabase/migrations/20231205101809_dbdev_supports_default_version.sql b/supabase/migrations/20231205101809_dbdev_supports_default_version.sql index 1d4dfd6b..d3c40b14 100644 --- a/supabase/migrations/20231205101809_dbdev_supports_default_version.sql +++ b/supabase/migrations/20231205101809_dbdev_supports_default_version.sql @@ -6,6 +6,7 @@ $pkg$ create schema dbdev; +-- base_url and api_key have been added as arguments with default values to help test locally create or replace function dbdev.install( package_name text, base_url text default 'https://api.database.dev/rest/v1/', @@ -329,6 +330,7 @@ create extension "handle-package_name" $description$ ); +-- set supabase-dbdev package's default_version to 0.0.4 update app.packages set default_version_struct = app.text_to_semver('0.0.4') where package_name = 'supabase-dbdev'; From cf226c830b22f4bd063d5c1f6065d0a19cde4ca4 Mon Sep 17 00:00:00 2001 From: Raminder Singh Date: Tue, 5 Dec 2023 20:30:30 +0530 Subject: [PATCH 10/16] correct version ordering --- supabase/migrations/20231205051816_add_default_version.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/supabase/migrations/20231205051816_add_default_version.sql b/supabase/migrations/20231205051816_add_default_version.sql index cb2fb8ac..1e318777 100644 --- a/supabase/migrations/20231205051816_add_default_version.sql +++ b/supabase/migrations/20231205051816_add_default_version.sql @@ -62,7 +62,7 @@ create or replace view public.packages as select * from app.package_versions pv where pv.package_id = pa.id - order by pv.version_struct + order by pv.version_struct desc limit 1 ) newest_ver; From 5f6b73226d3a00a39661ac577644f81f347f6c88 Mon Sep 17 00:00:00 2001 From: Raminder Singh Date: Tue, 5 Dec 2023 20:59:10 +0530 Subject: [PATCH 11/16] drop ambiguous function --- supabase/migrations/20231205051816_add_default_version.sql | 1 + 1 file changed, 1 insertion(+) diff --git a/supabase/migrations/20231205051816_add_default_version.sql b/supabase/migrations/20231205051816_add_default_version.sql index 1e318777..9f79b63f 100644 --- a/supabase/migrations/20231205051816_add_default_version.sql +++ b/supabase/migrations/20231205051816_add_default_version.sql @@ -76,6 +76,7 @@ grant update (control_description, control_relocatable, control_requires, defaul to authenticated; -- publish_package accepts an additional `default_version` argument +drop function public.publish_package(app.valid_name, varchar, bool, text[]); create or replace function public.publish_package( package_name app.valid_name, package_description varchar(1000), From 5da5c8201eca4b767f9415571b5c336bd876e51d Mon Sep 17 00:00:00 2001 From: Raminder Singh Date: Tue, 5 Dec 2023 21:18:17 +0530 Subject: [PATCH 12/16] only calling pgtle.set_default_version if default_version is non-null --- .../20231205101809_dbdev_supports_default_version.sql | 6 +++++- 1 file changed, 5 insertions(+), 1 deletion(-) diff --git a/supabase/migrations/20231205101809_dbdev_supports_default_version.sql b/supabase/migrations/20231205101809_dbdev_supports_default_version.sql index d3c40b14..bf8323d6 100644 --- a/supabase/migrations/20231205101809_dbdev_supports_default_version.sql +++ b/supabase/migrations/20231205101809_dbdev_supports_default_version.sql @@ -205,7 +205,11 @@ begin json_array_elements(contents) as r loop - perform pgtle.set_default_version(rec_package_name, rec_default_ver); + if rec_default_ver is not null then + perform pgtle.set_default_version(rec_package_name, rec_default_ver); + else + raise notice using errcode='22000', message=format('DBDEV INFO: missing default version'); + end if; end loop; From 392801ed360fe70f3d52767b2b4ba7567b314e09 Mon Sep 17 00:00:00 2001 From: Raminder Singh Date: Tue, 5 Dec 2023 22:07:37 +0530 Subject: [PATCH 13/16] correct order of dropping and uninstalling the supabase-dbdev extension --- .../20231205101809_dbdev_supports_default_version.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/supabase/migrations/20231205101809_dbdev_supports_default_version.sql b/supabase/migrations/20231205101809_dbdev_supports_default_version.sql index bf8323d6..6525631e 100644 --- a/supabase/migrations/20231205101809_dbdev_supports_default_version.sql +++ b/supabase/migrations/20231205101809_dbdev_supports_default_version.sql @@ -282,8 +282,8 @@ Requires: */ create extension if not exists http with schema extensions; create extension if not exists pg_tle; -select pgtle.uninstall_extension_if_exists('supabase-dbdev'); drop extension if exists "supabase-dbdev"; +select pgtle.uninstall_extension_if_exists('supabase-dbdev'); select pgtle.install_extension( 'supabase-dbdev', From 9ca2b7896334037650fb8cfa4c90c49f3dffcfe9 Mon Sep 17 00:00:00 2001 From: Raminder Singh Date: Thu, 7 Dec 2023 09:56:05 +0530 Subject: [PATCH 14/16] fix dbdev version in download notice call --- .../20231205101809_dbdev_supports_default_version.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/supabase/migrations/20231205101809_dbdev_supports_default_version.sql b/supabase/migrations/20231205101809_dbdev_supports_default_version.sql index 6525631e..714d7ffc 100644 --- a/supabase/migrations/20231205101809_dbdev_supports_default_version.sql +++ b/supabase/migrations/20231205101809_dbdev_supports_default_version.sql @@ -227,7 +227,7 @@ begin ), array[ ('apiKey', $stmt$ || pg_catalog.quote_literal(api_key) || $stmt$)::http_header, - ('x-client-info', 'dbdev/0.0.2')::http_header + ('x-client-info', 'dbdev/0.0.4')::http_header ], 'application/json', json_build_object('package_name', $stmt$ || pg_catalog.quote_literal($1) || $stmt$)::text From 46d0c7e052c45882261bfca6317e6208a583eb60 Mon Sep 17 00:00:00 2001 From: Raminder Singh Date: Thu, 7 Dec 2023 10:01:17 +0530 Subject: [PATCH 15/16] use control_description instead of name for TLE's description --- .../20231205101809_dbdev_supports_default_version.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/supabase/migrations/20231205101809_dbdev_supports_default_version.sql b/supabase/migrations/20231205101809_dbdev_supports_default_version.sql index 714d7ffc..761bc567 100644 --- a/supabase/migrations/20231205101809_dbdev_supports_default_version.sql +++ b/supabase/migrations/20231205101809_dbdev_supports_default_version.sql @@ -93,7 +93,7 @@ begin where name = rec_package_name ) then - perform pgtle.install_extension(rec_package_name, rec_ver, rec_package_name, rec_sql, rec_requires); + perform pgtle.install_extension(rec_package_name, rec_ver, rec_description, rec_sql, rec_requires); end if; -- Install other available versions From 1ef85d584bc136c0ca075db69248234be24ff008 Mon Sep 17 00:00:00 2001 From: Raminder Singh Date: Wed, 3 Jan 2024 17:21:01 +0530 Subject: [PATCH 16/16] make app.default_version_struct column non-null --- .../20231205051816_add_default_version.sql | 46 +++++-------------- 1 file changed, 11 insertions(+), 35 deletions(-) diff --git a/supabase/migrations/20231205051816_add_default_version.sql b/supabase/migrations/20231205051816_add_default_version.sql index 9f79b63f..a7f8fc34 100644 --- a/supabase/migrations/20231205051816_add_default_version.sql +++ b/supabase/migrations/20231205051816_add_default_version.sql @@ -1,39 +1,7 @@ --- The original semver domain defined in 20220117141507_semver.sql doesn't allow null --- app.semver_struct values, but we need a nullable app.semver column for the new --- default_version_struct column in the app.packages table (see alter table app.packages below). --- So we modify the `is_valid` function such that it returns true if the input version itself is --- null. All the existing tables where app.semver domain is used already have an additional --- non null constraint, so their behaviour doesn't change. -create or replace function app.is_valid(version app.semver_struct) - returns boolean - immutable - language sql -as $$ - select ( - version is null or ( - version.major is not null - and version.minor is not null - and version.patch is not null - ) - ) -$$; - --- same definition as the original function defined in 20220117141507_semver.sql with the only --- difference being that this is marked strict. This is done so that the function returns null --- on null input instead of `..` -create or replace function app.semver_to_text(version app.semver) - returns text - immutable - strict - language sql -as $$ - select - format('%s.%s.%s', version.major, version.minor, version.patch) -$$; - --- default version columns are nullable for backward compatibility with older clients +-- default_version column has a default value '0.0.0' only temporarily because the column is not null. +-- It will be removed below. alter table app.packages -add column default_version_struct app.semver, +add column default_version_struct app.semver not null default app.text_to_semver('0.0.0'), add column default_version text generated always as (app.semver_to_text(default_version_struct)) stored; -- for now we set the default version to current latest version @@ -43,6 +11,10 @@ set default_version_struct = app.text_to_semver(pp.latest_version) from public.packages pp where packages.id = pp.id; +-- now that every row has a valid default_version, remove the default value of '0.0.0' +alter table app.packages +alter column default_version_struct drop default; + -- add new default_version column to the view create or replace view public.packages as select @@ -95,6 +67,10 @@ begin raise exception 'user not logged in'; end if; + if default_version is null then + raise exception 'default_version is required. If you are on `dbdev` CLI version 0.1.5 or older upgrade to the latest version.'; + end if; + foreach require in array requires loop if not exists (