|
| 1 | +-- name: ListServers :many |
| 2 | +SELECT r.reg_type as registry_type, |
| 3 | + s.id, |
| 4 | + s.name, |
| 5 | + s.version, |
| 6 | + l.latest_server_id IS NOT NULL AS is_latest, |
| 7 | + s.created_at, |
| 8 | + s.updated_at, |
| 9 | + s.description, |
| 10 | + s.title, |
| 11 | + s.website, |
| 12 | + s.upstream_meta, |
| 13 | + s.server_meta, |
| 14 | + s.repository_url, |
| 15 | + s.repository_id, |
| 16 | + s.repository_subfolder, |
| 17 | + s.repository_type |
| 18 | + FROM mcp_server s |
| 19 | + JOIN registry r ON s.reg_id = r.id |
| 20 | + LEFT JOIN latest_server_version l ON s.id = l.latest_server_id |
| 21 | + WHERE (sqlc.narg(next)::timestamp with time zone IS NULL OR sqlc.narg(next) > s.created_at) |
| 22 | + ORDER BY |
| 23 | + -- next page sorting |
| 24 | + CASE WHEN sqlc.narg(next)::timestamp with time zone IS NULL THEN s.reg_type END ASC, |
| 25 | + CASE WHEN sqlc.narg(next)::timestamp with time zone IS NULL THEN s.name END ASC, |
| 26 | + CASE WHEN sqlc.narg(next)::timestamp with time zone IS NULL THEN s.created_at END ASC, |
| 27 | + CASE WHEN sqlc.narg(next)::timestamp with time zone IS NULL THEN s.version END ASC, -- acts as tie breaker |
| 28 | + -- previous page sorting |
| 29 | + CASE WHEN sqlc.narg(prev)::timestamp with time zone IS NULL THEN s.reg_type END DESC, |
| 30 | + CASE WHEN sqlc.narg(prev)::timestamp with time zone IS NULL THEN s.name END DESC, |
| 31 | + CASE WHEN sqlc.narg(prev)::timestamp with time zone IS NULL THEN s.created_at END DESC, |
| 32 | + CASE WHEN sqlc.narg(prev)::timestamp with time zone IS NULL THEN s.version END DESC -- acts as tie breaker |
| 33 | + LIMIT sqlc.arg(size)::bigint; |
| 34 | + |
| 35 | + -- name: ListServerPackages :many |
| 36 | +SELECT p.server_id, |
| 37 | + p.registry_type, |
| 38 | + p.pkg_registry_url, |
| 39 | + p.pkg_identifier, |
| 40 | + p.pkg_version, |
| 41 | + p.runtime_hint, |
| 42 | + p.runtime_arguments, |
| 43 | + p.package_arguments, |
| 44 | + p.env_vars, |
| 45 | + p.sha256_hash, |
| 46 | + p.transport, |
| 47 | + p.transport_url, |
| 48 | + p.transport_headers |
| 49 | + FROM mcp_server_package p |
| 50 | + JOIN mcp_server s ON p.server_id = s.id |
| 51 | + WHERE s.id IN (sqlc.slice(server_ids)::UUID[]) |
| 52 | + ORDER BY p.pkg_version DESC; |
| 53 | + |
| 54 | + -- name: ListServerRemotes :many |
| 55 | +SELECT r.server_id, |
| 56 | + r.transport, |
| 57 | + r.transport_url, |
| 58 | + r.transport_headers |
| 59 | + FROM mcp_server_remote r |
| 60 | + WHERE r.server_id IN (sqlc.slice(server_ids)::UUID[]) |
| 61 | + ORDER BY r.transport, r.transport_url; |
| 62 | + |
| 63 | +-- name: ListServerVersions :many |
| 64 | +SELECT s.id, |
| 65 | + s.name, |
| 66 | + s.version, |
| 67 | + s.created_at, |
| 68 | + s.updated_at, |
| 69 | + s.description, |
| 70 | + s.title, |
| 71 | + s.website, |
| 72 | + s.upstream_meta, |
| 73 | + s.server_meta, |
| 74 | + s.repository_url, |
| 75 | + s.repository_id, |
| 76 | + s.repository_subfolder, |
| 77 | + s.repository_type |
| 78 | + FROM mcp_server s |
| 79 | + WHERE s.name = sqlc.arg(name) |
| 80 | + ORDER BY |
| 81 | + CASE WHEN sqlc.narg(next)::timestamp with time zone IS NULL THEN s.created_at END ASC, |
| 82 | + CASE WHEN sqlc.narg(next)::timestamp with time zone IS NULL THEN s.version END DESC -- acts as tie breaker |
| 83 | + LIMIT sqlc.arg(size)::bigint; |
| 84 | + |
| 85 | +-- name: UpsertServerVersion :exec |
| 86 | +INSERT INTO mcp_server ( |
| 87 | + name, |
| 88 | + version, |
| 89 | + reg_id, |
| 90 | + created_at, |
| 91 | + updated_at, |
| 92 | + description, |
| 93 | + title, |
| 94 | + website, |
| 95 | + upstream_meta, |
| 96 | + server_meta, |
| 97 | + repository_url, |
| 98 | + repository_id, |
| 99 | + repository_subfolder, |
| 100 | + repository_type |
| 101 | +) VALUES ( |
| 102 | + sqlc.arg(name), |
| 103 | + sqlc.arg(version), |
| 104 | + sqlc.arg(reg_id), |
| 105 | + CURRENT_TIMESTAMP, |
| 106 | + CURRENT_TIMESTAMP, |
| 107 | + sqlc.narg(description), |
| 108 | + sqlc.narg(title), |
| 109 | + sqlc.narg(website), |
| 110 | + sqlc.narg(upstream_meta), |
| 111 | + sqlc.narg(server_meta), |
| 112 | + sqlc.narg(repository_url), |
| 113 | + sqlc.narg(repository_id), |
| 114 | + sqlc.narg(repository_subfolder), |
| 115 | + sqlc.narg(repository_type) |
| 116 | +) ON CONFLICT (reg_id, name, version) |
| 117 | + DO UPDATE SET |
| 118 | + updated_at = CURRENT_TIMESTAMP, |
| 119 | + description = sqlc.narg(description), |
| 120 | + title = sqlc.narg(title), |
| 121 | + website = sqlc.narg(website), |
| 122 | + upstream_meta = sqlc.narg(upstream_meta), |
| 123 | + server_meta = sqlc.narg(server_meta), |
| 124 | + repository_url = sqlc.narg(repository_url), |
| 125 | + repository_id = sqlc.narg(repository_id), |
| 126 | + repository_subfolder = sqlc.narg(repository_subfolder), |
| 127 | + repository_type = sqlc.narg(repository_type); |
| 128 | + |
| 129 | +-- name: UpsertLatestServerVersion :exec |
| 130 | +INSERT INTO latest_server_version ( |
| 131 | + reg_id, |
| 132 | + name, |
| 133 | + version, |
| 134 | + latest_server_id |
| 135 | +) VALUES ( |
| 136 | + sqlc.arg(reg_id), |
| 137 | + sqlc.arg(name), |
| 138 | + sqlc.arg(version), |
| 139 | + sqlc.arg(server_id) |
| 140 | +) ON CONFLICT (reg_id, name) |
| 141 | + DO UPDATE SET |
| 142 | + version = sqlc.arg(version), |
| 143 | + latest_server_id = sqlc.arg(server_id); |
| 144 | + |
| 145 | +-- name: UpsertServerPackage :exec |
| 146 | +INSERT INTO mcp_server_package ( |
| 147 | + server_id, |
| 148 | + registry_type, |
| 149 | + pkg_registry_url, |
| 150 | + pkg_identifier, |
| 151 | + pkg_version, |
| 152 | + runtime_hint, |
| 153 | + runtime_arguments, |
| 154 | + package_arguments, |
| 155 | + env_vars, |
| 156 | + sha256_hash, |
| 157 | + transport, |
| 158 | + transport_url, |
| 159 | + transport_headers |
| 160 | +) VALUES ( |
| 161 | + sqlc.arg(server_id), |
| 162 | + sqlc.arg(registry_type), |
| 163 | + sqlc.arg(pkg_registry_url), |
| 164 | + sqlc.arg(pkg_identifier), |
| 165 | + sqlc.arg(pkg_version), |
| 166 | + sqlc.narg(runtime_hint), |
| 167 | + sqlc.narg(runtime_arguments), |
| 168 | + sqlc.narg(package_arguments), |
| 169 | + sqlc.narg(env_vars), |
| 170 | + sqlc.narg(sha256_hash), |
| 171 | + sqlc.arg(transport), |
| 172 | + sqlc.narg(transport_url), |
| 173 | + sqlc.narg(transport_headers) |
| 174 | +); |
| 175 | + |
| 176 | +-- name: UpsertServerRemote :exec |
| 177 | +INSERT INTO mcp_server_remote ( |
| 178 | + server_id, |
| 179 | + transport, |
| 180 | + transport_url, |
| 181 | + transport_headers |
| 182 | +) VALUES ( |
| 183 | + sqlc.arg(server_id), |
| 184 | + sqlc.arg(transport), |
| 185 | + sqlc.narg(transport_url), |
| 186 | + sqlc.narg(transport_headers) |
| 187 | +) ON CONFLICT (server_id, transport, transport_url) |
| 188 | + DO UPDATE SET |
| 189 | + transport_headers = sqlc.narg(transport_headers); |
| 190 | + |
| 191 | +-- name: UpsertServerIcon :exec |
| 192 | +INSERT INTO mcp_server_icon ( |
| 193 | + server_id, |
| 194 | + source_uri, |
| 195 | + mime_type, |
| 196 | + theme |
| 197 | +) VALUES ( |
| 198 | + sqlc.arg(server_id), |
| 199 | + sqlc.arg(source_uri), |
| 200 | + sqlc.arg(mime_type), |
| 201 | + sqlc.arg(theme) |
| 202 | +) ON CONFLICT (server_id, source_uri, mime_type, theme) |
| 203 | + DO UPDATE SET |
| 204 | + theme = sqlc.arg(theme); |
0 commit comments