Organiza tus páginas con colecciones
Guarda y categoriza el contenido según tus preferencias.
En esta página, se describe cómo realizar una búsqueda que combine datos de texto completo y no de texto.
Realiza una búsqueda mixta de texto completo y no de texto
Los índices de búsqueda admiten texto completo, concordancia exacta, columnas numéricas y columnas JSON/JSONB. Puedes combinar condiciones de texto y no texto en la cláusula WHERE de manera similar a las consultas de búsqueda de varias columnas. El optimizador de consultas intenta optimizar los predicados que no son de texto con un
índice de búsqueda. Si eso no es posible, Spanner evalúa la condición para cada fila que coincida con el índice de búsqueda. Las columnas a las que se hace referencia y que no se almacenan en el índice de búsqueda se recuperan de la tabla base.
El comportamiento de las consultas en esta tabla incluye lo siguiente:
Rating y Genres se incluyen en el índice de búsqueda.
Spanner acelera las condiciones con listas de publicación de índices de búsqueda. ARRAY_INCLUDES_ANY y ARRAY_INCLUDES_ALL son funciones de Google SQL y no son compatibles con el dialecto de PostgreSQL.
La consulta puede combinar conjunciones, disyunciones y negaciones de cualquier manera, incluso mezclar predicados de texto completo y no de texto. El índice de búsqueda acelera esta consulta por completo.
Likes se almacena en el índice, pero el esquema no le solicita a Spanner que cree un índice de tokens para sus valores posibles.
Por lo tanto, el predicado de texto completo en Title y el predicado que no es de texto en Rating se aceleran, pero el predicado en Likes no. En
Spanner, la consulta recupera todos los documentos con el término "car"
en el Title y una calificación superior a 4, y luego filtra los documentos que
no tienen al menos 1,000 Me gusta. Esta consulta usa muchos recursos si casi todos los álbumes tienen el término "auto" en el título y casi todos tienen una calificación de 5, pero pocos álbumes tienen 1,000 Me gusta. En esos casos, indexar Likes de manera similar a Rating ahorra recursos.
Cover no se almacena en el índice. La siguiente consulta realiza una unión de vuelta entre AlbumsIndex y Albums para recuperar Cover para todos los álbumes que coincidan.
[[["Fácil de comprender","easyToUnderstand","thumb-up"],["Resolvió mi problema","solvedMyProblem","thumb-up"],["Otro","otherUp","thumb-up"]],[["Difícil de entender","hardToUnderstand","thumb-down"],["Información o código de muestra incorrectos","incorrectInformationOrSampleCode","thumb-down"],["Faltan la información o los ejemplos que necesito","missingTheInformationSamplesINeed","thumb-down"],["Problema de traducción","translationIssue","thumb-down"],["Otro","otherDown","thumb-down"]],["Última actualización: 2025-09-05 (UTC)"],[],[],null,["# Mix full-text and non-text queries\n\n| **Note:** This feature is available with the Spanner Enterprise edition and Enterprise Plus edition. For more information, see the [Spanner editions overview](/spanner/docs/editions-overview).\n\n\u003cbr /\u003e\n\nThis page describes how to perform a search that mixes full-text and non-text\ndata.\n\nPerform a mixed full-text and non-text search\n---------------------------------------------\n\n[Search indexes](/spanner/docs/full-text-search/search-indexes) support\nfull-text, exact match, numeric columns, and JSON/JSONB columns. You can combine\ntext and non-text conditions in the `WHERE` clause similarly to multi-column\nsearch queries. The query optimizer tries to optimize non-text predicates with a\nsearch index. If that's not possible, Spanner evaluates the\ncondition for every row that matches the search index. Referenced columns not\nstored in the search index are fetched from the base table.\n\nConsider the following example: \n\n### GoogleSQL\n\n CREATE TABLE Albums (\n AlbumId STRING(MAX) NOT NULL,\n Title STRING(MAX),\n Rating FLOAT64,\n Genres ARRAY\u003cSTRING(MAX)\u003e,\n Likes INT64,\n Cover BYTES(MAX),\n Title_Tokens TOKENLIST AS (TOKENIZE_FULLTEXT(Title)) HIDDEN,\n Rating_Tokens TOKENLIST AS (TOKENIZE_NUMBER(Rating)) HIDDEN,\n Genres_Tokens TOKENLIST AS (TOKEN(Genres)) HIDDEN\n ) PRIMARY KEY(AlbumId);\n\n CREATE SEARCH INDEX AlbumsIndex\n ON Albums(Title_Tokens, Rating_Tokens, Genres_Tokens)\n STORING (Likes);\n\n### PostgreSQL\n\nSpanner PostgreSQL support has the following\nlimitations:\n\n- `spanner.tokenize_number` function only supports the `bigint` type.\n- `spanner.token` doesn't support tokenizing arrays.\n\n CREATE TABLE albums (\n albumid character varying NOT NULL,\n title character varying,\n rating bigint,\n genres character varying NOT NULL,\n likes bigint,\n cover bytea,\n title_tokens spanner.tokenlist AS (spanner.tokenize_fulltext(title)) VIRTUAL HIDDEN,\n rating_tokens spanner.tokenlist AS (spanner.tokenize_number(rating)) VIRTUAL HIDDEN,\n genres_tokens spanner.tokenlist AS (spanner.token(genres)) VIRTUAL HIDDEN,\n PRIMARY KEY(albumid));\n\n CREATE SEARCH INDEX albumsindex\n ON albums(title_tokens, rating_tokens, genres_tokens)\n INCLUDE (likes);\n\nThe behavior of queries on this table include the following:\n\n- `Rating` and `Genres` are included in the search index.\n Spanner accelerates conditions using search index posting\n lists. `ARRAY_INCLUDES_ANY`, `ARRAY_INCLUDES_ALL` are GoogleSQL\n functions and are not supported for PostgreSQL dialect.\n\n SELECT Album\n FROM Albums\n WHERE Rating \u003e 4\n AND ARRAY_INCLUDES_ANY(Genres, ['jazz'])\n\n- The query can combine conjunctions, disjunctions, and negations in any way,\n including mixing full-text and non-text predicates. This query is fully\n accelerated by the search index.\n\n SELECT Album\n FROM Albums\n WHERE (SEARCH(Title_Tokens, 'car')\n OR Rating \u003e 4)\n AND NOT ARRAY_INCLUDES_ANY(Genres, ['jazz'])\n\n- `Likes` is stored in the index, but the schema doesn't request\n Spanner to build a token index for its possible values.\n Therefore, the full-text predicate on `Title` and non-text predicate on\n `Rating` is accelerated, but the predicate on `Likes` isn't. In\n Spanner, the query fetches all documents with the term \"car\"\n in the `Title` and a rating more than 4, then it filters documents that\n don't have at least 1000 likes. This query uses a lot of resources if almost\n all albums have the term \"car\" in their title and almost all of them have a\n rating of 5, but few albums have 1000 likes. In such cases, indexing\n `Likes` similarly to `Rating` saves resources.\n\n ### GoogleSQL\n\n SELECT Album\n FROM Albums\n WHERE SEARCH(Title_Tokens, 'car')\n AND Rating \u003e 4\n AND Likes \u003e= 1000\n\n ### PostgreSQL\n\n SELECT album\n FROM albums\n WHERE spanner.search(title_tokens, 'car')\n AND rating \u003e 4\n AND likes \u003e= 1000\n\n- `Cover` isn't stored in the index. The following query does a\n [back join](/spanner/docs/query-execution-plans#index_and_back_join_queries)\n between `AlbumsIndex` and `Albums` to fetch `Cover` for all matching albums.\n\n ### GoogleSQL\n\n SELECT AlbumId, Cover\n FROM Albums\n WHERE SEARCH(Title_Tokens, 'car')\n AND Rating \u003e 4\n\n ### PostgreSQL\n\n SELECT albumid, cover\n FROM albums\n WHERE spanner.search(title_tokens, 'car')\n AND rating \u003e 4\n\nWhat's next\n-----------\n\n- Learn about [full-text search queries](/spanner/docs/full-text-search/query-overview).\n- Learn how to [rank search results](/spanner/docs/full-text-search/ranked-search).\n- Learn how to [perform a substring search](/spanner/docs/full-text-search/substring-search).\n- Learn how to [paginate search results](/spanner/docs/full-text-search/paginate-search-results).\n- Learn how to [search multiple columns](/spanner/docs/full-text-search/search-multiple-columns)."]]