packages: stage 2 of packages tables migration (#48007)

Stage 2 of the migration started [here](https://github.com/sourcegraph/sourcegraph/pull/47105). Not much
to it, very simples:
delete everything in `lsif_dependency_repos` that isnt referenced in `package_repo_versions`. This only includes every entry which wasnt the smallest ID for a given (scheme,name) tuple, as per the original migration [here](https://github.com/sourcegraph/sourcegraph/pull/47105/files#diff-396fb0e7bd74e13d842f1bbb870ca3e337f2237224e51dba9d9f19855d922c27R43)

## Test plan

Ran the queries in SELECT instead to make sure it matches what is expected
This commit is contained in:
Noah S-C 2023-02-23 15:21:15 +00:00 committed by GitHub
parent 04df339abd
commit 2f96647cab
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
8 changed files with 45 additions and 65 deletions

View File

@ -0,0 +1,7 @@
[
{
"path": "internal/codeintel/dependencies/internal/store",
"prefix": "TestListPackageRepoRefs",
"reason": "References a column directly in the test that is being dropped post 4.5. No application code references the column"
}
]

View File

@ -5,7 +5,6 @@ import (
"testing"
"github.com/google/go-cmp/cmp"
"github.com/keegancsmith/sqlf"
"github.com/sourcegraph/log/logtest"
"github.com/sourcegraph/sourcegraph/internal/codeintel/dependencies/shared"
@ -119,11 +118,6 @@ func TestListPackageRepoRefs(t *testing.T) {
}
}
// want to mimic data that might exist because of the 2-step migration
if err := store.db.Exec(ctx, sqlf.Sprintf(`INSERT INTO lsif_dependency_repos (scheme, name, version) VALUES ('npm','foo','4.2.0')`)); err != nil {
t.Fatal(err)
}
var lastID int
for _, test := range [][]shared.PackageRepoReference{
{{Scheme: "npm", Name: "bar"}, {Scheme: "npm", Name: "foo"}, {Scheme: "npm", Name: "banana"}},

View File

@ -116,10 +116,6 @@
"Name": "func_insert_zoekt_repo",
"Definition": "CREATE OR REPLACE FUNCTION public.func_insert_zoekt_repo()\n RETURNS trigger\n LANGUAGE plpgsql\nAS $function$\nBEGIN\n INSERT INTO zoekt_repos (repo_id) VALUES (NEW.id);\n\n RETURN NULL;\nEND;\n$function$\n"
},
{
"Name": "func_lsif_dependency_repos_backfill",
"Definition": "CREATE OR REPLACE FUNCTION public.func_lsif_dependency_repos_backfill()\n RETURNS trigger\n LANGUAGE plpgsql\nAS $function$\n BEGIN\n INSERT INTO package_repo_versions (package_id, version)\n VALUES (NEW.id, NEW.version);\n\n RETURN NULL;\n END;\n$function$\n"
},
{
"Name": "func_lsif_uploads_delete",
"Definition": "CREATE OR REPLACE FUNCTION public.func_lsif_uploads_delete()\n RETURNS trigger\n LANGUAGE plpgsql\nAS $function$\n BEGIN\n UPDATE lsif_uploads_audit_logs\n SET record_deleted_at = NOW()\n WHERE upload_id IN (\n SELECT id FROM OLD\n );\n\n RETURN NULL;\n END;\n$function$\n"
@ -12941,19 +12937,6 @@
"IsGenerated": "NEVER",
"GenerationExpression": "",
"Comment": ""
},
{
"Name": "version",
"Index": 3,
"TypeName": "text",
"IsNullable": false,
"Default": "'👁temporary_sentinel_value👁'::text",
"CharacterMaximumLength": 0,
"IsIdentity": false,
"IdentityGeneration": "",
"IsGenerated": "NEVER",
"GenerationExpression": "",
"Comment": ""
}
],
"Indexes": [
@ -12967,16 +12950,6 @@
"ConstraintType": "p",
"ConstraintDefinition": "PRIMARY KEY (id)"
},
{
"Name": "lsif_dependency_repos_unique_triplet",
"IsPrimaryKey": false,
"IsUnique": true,
"IsExclusion": false,
"IsDeferrable": false,
"IndexDefinition": "CREATE UNIQUE INDEX lsif_dependency_repos_unique_triplet ON lsif_dependency_repos USING btree (scheme, name, version)",
"ConstraintType": "u",
"ConstraintDefinition": "UNIQUE (scheme, name, version)"
},
{
"Name": "lsif_dependency_repos_name_idx",
"IsPrimaryKey": false,
@ -12989,12 +12962,7 @@
}
],
"Constraints": null,
"Triggers": [
{
"Name": "lsif_dependency_repos_backfill",
"Definition": "CREATE TRIGGER lsif_dependency_repos_backfill AFTER INSERT ON lsif_dependency_repos FOR EACH ROW WHEN (new.version \u003c\u003e '👁temporary_sentinel_value👁'::text) EXECUTE FUNCTION func_lsif_dependency_repos_backfill()"
}
]
"Triggers": []
},
{
"Name": "lsif_dependency_syncing_jobs",

View File

@ -1834,20 +1834,16 @@ Foreign-key constraints:
# Table "public.lsif_dependency_repos"
```
Column | Type | Collation | Nullable | Default
---------+--------+-----------+----------+---------------------------------------------------
id | bigint | | not null | nextval('lsif_dependency_repos_id_seq'::regclass)
name | text | | not null |
version | text | | not null | '👁temporary_sentinel_value👁'::text
scheme | text | | not null |
Column | Type | Collation | Nullable | Default
--------+--------+-----------+----------+---------------------------------------------------
id | bigint | | not null | nextval('lsif_dependency_repos_id_seq'::regclass)
name | text | | not null |
scheme | text | | not null |
Indexes:
"lsif_dependency_repos_pkey" PRIMARY KEY, btree (id)
"lsif_dependency_repos_unique_triplet" UNIQUE CONSTRAINT, btree (scheme, name, version)
"lsif_dependency_repos_name_idx" btree (name)
Referenced by:
TABLE "package_repo_versions" CONSTRAINT "package_id_fk" FOREIGN KEY (package_id) REFERENCES lsif_dependency_repos(id) ON DELETE CASCADE
Triggers:
lsif_dependency_repos_backfill AFTER INSERT ON lsif_dependency_repos FOR EACH ROW WHEN (new.version <> '👁temporary_sentinel_value👁'::text) EXECUTE FUNCTION func_lsif_dependency_repos_backfill()
```

View File

@ -0,0 +1,16 @@
ALTER TABLE lsif_dependency_repos ADD COLUMN IF NOT EXISTS version TEXT DEFAULT '👁temporary_sentinel_value👁';
CREATE OR REPLACE FUNCTION func_lsif_dependency_repos_backfill() RETURNS TRIGGER AS $$
BEGIN
INSERT INTO package_repo_versions (package_id, version)
VALUES (NEW.id, NEW.version);
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS lsif_dependency_repos_backfill ON lsif_dependency_repos;
CREATE TRIGGER lsif_dependency_repos_backfill AFTER INSERT ON lsif_dependency_repos
FOR EACH ROW
WHEN (NEW.version <> '👁temporary_sentinel_value👁')
EXECUTE FUNCTION func_lsif_dependency_repos_backfill();

View File

@ -0,0 +1,2 @@
name: package_repos_separate_versions_table_stage2
parents: [1676996650]

View File

@ -0,0 +1,14 @@
DROP TRIGGER IF EXISTS lsif_dependency_repos_backfill ON lsif_dependency_repos;
DROP FUNCTION IF EXISTS func_lsif_dependency_repos_backfill;
ALTER TABLE lsif_dependency_repos
DROP COLUMN IF EXISTS version;
DELETE FROM lsif_dependency_repos
WHERE id IN (
SELECT lr.id
FROM lsif_dependency_repos lr
LEFT JOIN package_repo_versions prv
ON lr.id = prv.package_id
WHERE prv.package_id IS NULL
);

View File

@ -293,17 +293,6 @@ BEGIN
END;
$$;
CREATE FUNCTION func_lsif_dependency_repos_backfill() RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
INSERT INTO package_repo_versions (package_id, version)
VALUES (NEW.id, NEW.version);
RETURN NULL;
END;
$$;
CREATE FUNCTION func_lsif_uploads_delete() RETURNS trigger
LANGUAGE plpgsql
AS $$
@ -2562,7 +2551,6 @@ ALTER SEQUENCE lsif_dependency_indexing_jobs_id_seq1 OWNED BY lsif_dependency_in
CREATE TABLE lsif_dependency_repos (
id bigint NOT NULL,
name text NOT NULL,
version text DEFAULT '👁temporary_sentinel_value👁'::text NOT NULL,
scheme text NOT NULL
);
@ -4568,9 +4556,6 @@ ALTER TABLE ONLY lsif_dependency_indexing_jobs
ALTER TABLE ONLY lsif_dependency_repos
ADD CONSTRAINT lsif_dependency_repos_pkey PRIMARY KEY (id);
ALTER TABLE ONLY lsif_dependency_repos
ADD CONSTRAINT lsif_dependency_repos_unique_triplet UNIQUE (scheme, name, version);
ALTER TABLE ONLY lsif_dirty_repositories
ADD CONSTRAINT lsif_dirty_repositories_pkey PRIMARY KEY (repository_id);
@ -5231,8 +5216,6 @@ CREATE TRIGGER batch_spec_workspace_execution_last_dequeues_update AFTER UPDATE
CREATE TRIGGER changesets_update_computed_state BEFORE INSERT OR UPDATE ON changesets FOR EACH ROW EXECUTE FUNCTION changesets_computed_state_ensure();
CREATE TRIGGER lsif_dependency_repos_backfill AFTER INSERT ON lsif_dependency_repos FOR EACH ROW WHEN ((new.version <> '👁temporary_sentinel_value👁'::text)) EXECUTE FUNCTION func_lsif_dependency_repos_backfill();
CREATE TRIGGER trig_create_zoekt_repo_on_repo_insert AFTER INSERT ON repo FOR EACH ROW EXECUTE FUNCTION func_insert_zoekt_repo();
CREATE TRIGGER trig_delete_batch_change_reference_on_changesets AFTER DELETE ON batch_changes FOR EACH ROW EXECUTE FUNCTION delete_batch_change_reference_on_changesets();