|
| 1 | +package sql |
| 2 | + |
| 3 | +import ( |
| 4 | + "database/sql" |
| 5 | + "fmt" |
| 6 | +) |
| 7 | + |
| 8 | +//nolint:lll |
| 9 | +var psqlSystemPromptTemplate = ` |
| 10 | +You are a Postgresql expert. Given an input question, create a syntactically correct psql query to run. Do not add any extra information to the query. The query must be usable as-is. |
| 11 | +Unless the user specifies in the question a specific number of examples to obtain, query for at most {{.top_k}} results using the LIMIT clause as per Postgresql. You can order the results to return the most informative data in the database. |
| 12 | +Never query for all columns from a table. You must query only the columns that are needed to answer the question. Wrap each column name in double quotes (") to denote them as delimited identifiers. |
| 13 | +Pay attention to use only the column names you can see in the tables below. Be careful to not query for columns that do not exist. Also, pay attention to which column is in which table. |
| 14 | +Pay attention to use date('now') function to get the current date, if the question involves "today". Do not use markdown to format the query.` |
| 15 | + |
| 16 | +// psqlSchema retrieves the schema information for all tables in a PostgreSQL database. |
| 17 | +// |
| 18 | +//nolint:funlen,gocognit |
| 19 | +func (s *SQL) psqlSchema() (*string, error) { |
| 20 | + rows, err := s.db.Query(` |
| 21 | + SELECT |
| 22 | + c.table_name, |
| 23 | + c.column_name, |
| 24 | + c.data_type, |
| 25 | + c.column_default, |
| 26 | + c.is_nullable, |
| 27 | + tc.constraint_type, |
| 28 | + kcu.constraint_name, |
| 29 | + ccu.table_name AS foreign_table_name, |
| 30 | + ccu.column_name AS foreign_column_name |
| 31 | + FROM |
| 32 | + information_schema.columns c |
| 33 | + LEFT JOIN |
| 34 | + information_schema.key_column_usage kcu ON c.table_name = kcu.table_name AND c.column_name = kcu.column_name |
| 35 | + LEFT JOIN |
| 36 | + information_schema.table_constraints tc ON kcu.constraint_name = tc.constraint_name |
| 37 | + LEFT JOIN |
| 38 | + information_schema.constraint_column_usage ccu ON tc.constraint_name = ccu.constraint_name |
| 39 | + WHERE |
| 40 | + c.table_schema = 'public' |
| 41 | + ORDER BY |
| 42 | + c.table_name, c.ordinal_position; |
| 43 | +`) |
| 44 | + if err != nil { |
| 45 | + return nil, fmt.Errorf("querying schema: %w", err) |
| 46 | + } |
| 47 | + defer rows.Close() |
| 48 | + |
| 49 | + schema := "" |
| 50 | + currentTable := "" |
| 51 | + |
| 52 | + for rows.Next() { |
| 53 | + //nolint:lll |
| 54 | + var tableName, columnName, dataType, columnDefault, isNullable, constraintType, constraintName, foreignTableName, foreignColumnName sql.NullString |
| 55 | + //nolint:lll |
| 56 | + if rowsErr := rows.Scan(&tableName, &columnName, &dataType, &columnDefault, &isNullable, &constraintType, &constraintName, &foreignTableName, &foreignColumnName); rowsErr != nil { |
| 57 | + return nil, fmt.Errorf("scanning row: %w", rowsErr) |
| 58 | + } |
| 59 | + |
| 60 | + //nolin:nestif |
| 61 | + if tableName.Valid && tableName.String != currentTable { |
| 62 | + if currentTable != "" { |
| 63 | + schema += "\n" // Add a newline before a new table |
| 64 | + } |
| 65 | + schema += fmt.Sprintf("Table: %s\n", tableName.String) |
| 66 | + currentTable = tableName.String |
| 67 | + } |
| 68 | + |
| 69 | + //nolint:nestif |
| 70 | + if columnName.Valid { |
| 71 | + schema += fmt.Sprintf(" Column: %s, Type: %s", columnName.String, dataType.String) |
| 72 | + |
| 73 | + if columnDefault.Valid { |
| 74 | + schema += fmt.Sprintf(", Default: %s", columnDefault.String) |
| 75 | + } |
| 76 | + |
| 77 | + if isNullable.Valid { |
| 78 | + schema += fmt.Sprintf(", Nullable: %s", isNullable.String) |
| 79 | + } |
| 80 | + |
| 81 | + if constraintType.Valid { |
| 82 | + schema += fmt.Sprintf(", Constraint: %s (%s)", constraintType.String, constraintName.String) |
| 83 | + if foreignTableName.Valid && foreignColumnName.Valid { |
| 84 | + schema += fmt.Sprintf(", References: %s(%s)", foreignTableName.String, foreignColumnName.String) |
| 85 | + } |
| 86 | + } |
| 87 | + |
| 88 | + schema += "\n" |
| 89 | + } |
| 90 | + } |
| 91 | + |
| 92 | + if rowsErr := rows.Err(); rowsErr != nil { |
| 93 | + return nil, fmt.Errorf("rows error: %w", rowsErr) |
| 94 | + } |
| 95 | + |
| 96 | + return &schema, nil |
| 97 | +} |
0 commit comments