check_business_cards_table.sql 3.3 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118
  1. -- ===============================================
  2. -- 检查business_cards表结构和字段状态
  3. -- 用途: 验证age和native_place字段的添加情况
  4. -- ===============================================
  5. -- 1. 检查表是否存在
  6. SELECT
  7. table_name,
  8. table_type,
  9. table_schema
  10. FROM information_schema.tables
  11. WHERE table_name = 'business_cards';
  12. -- 2. 查看完整的表结构
  13. SELECT
  14. column_name,
  15. data_type,
  16. character_maximum_length,
  17. is_nullable,
  18. column_default,
  19. ordinal_position
  20. FROM information_schema.columns
  21. WHERE table_name = 'business_cards'
  22. ORDER BY ordinal_position;
  23. -- 3. 专门检查age和native_place字段
  24. SELECT
  25. column_name,
  26. data_type,
  27. character_maximum_length,
  28. is_nullable,
  29. column_default,
  30. CASE
  31. WHEN column_name = 'age' THEN '年龄字段'
  32. WHEN column_name = 'native_place' THEN '籍贯字段'
  33. ELSE '其他字段'
  34. END as field_description
  35. FROM information_schema.columns
  36. WHERE table_name = 'business_cards'
  37. AND column_name IN ('age', 'native_place')
  38. ORDER BY column_name;
  39. -- 4. 查看字段注释
  40. SELECT
  41. a.attname AS column_name,
  42. format_type(a.atttypid, a.atttypmod) AS data_type,
  43. COALESCE(pg_catalog.col_description(a.attrelid, a.attnum), '无注释') AS comment
  44. FROM
  45. pg_catalog.pg_attribute a
  46. JOIN
  47. pg_catalog.pg_class c ON a.attrelid = c.oid
  48. JOIN
  49. pg_catalog.pg_namespace n ON c.relnamespace = n.oid
  50. WHERE
  51. c.relname = 'business_cards'
  52. AND a.attname IN ('age', 'native_place')
  53. AND a.attnum > 0
  54. AND NOT a.attisdropped
  55. ORDER BY a.attname;
  56. -- 5. 检查是否有数据使用了新字段
  57. SELECT
  58. COUNT(*) as total_records,
  59. COUNT(age) as records_with_age,
  60. COUNT(native_place) as records_with_native_place,
  61. COUNT(CASE WHEN age IS NOT NULL THEN 1 END) as non_null_age,
  62. COUNT(CASE WHEN native_place IS NOT NULL AND native_place != '' THEN 1 END) as non_empty_native_place
  63. FROM business_cards;
  64. -- 6. 如果有数据,显示样本
  65. SELECT
  66. id,
  67. name_zh,
  68. age,
  69. native_place,
  70. created_at
  71. FROM business_cards
  72. WHERE age IS NOT NULL OR (native_place IS NOT NULL AND native_place != '')
  73. LIMIT 5;
  74. -- 7. 检查age字段的数据范围(如果有数据)
  75. SELECT
  76. MIN(age) as min_age,
  77. MAX(age) as max_age,
  78. AVG(age) as avg_age,
  79. COUNT(DISTINCT age) as distinct_age_values
  80. FROM business_cards
  81. WHERE age IS NOT NULL;
  82. -- 8. 检查native_place字段的数据统计(如果有数据)
  83. SELECT
  84. COUNT(DISTINCT native_place) as distinct_native_places,
  85. LENGTH(MAX(native_place)) as max_length,
  86. LENGTH(MIN(native_place)) as min_length
  87. FROM business_cards
  88. WHERE native_place IS NOT NULL AND native_place != '';
  89. -- 9. 使用psql命令查看表结构(需要在psql中执行)
  90. -- \d business_cards
  91. -- 10. 检查表的所有约束
  92. SELECT
  93. tc.constraint_name,
  94. tc.constraint_type,
  95. tc.table_name,
  96. kcu.column_name
  97. FROM information_schema.table_constraints tc
  98. JOIN information_schema.key_column_usage kcu
  99. ON tc.constraint_name = kcu.constraint_name
  100. WHERE tc.table_name = 'business_cards'
  101. ORDER BY tc.constraint_type, tc.constraint_name;
  102. -- ===============================================
  103. -- 说明:
  104. -- 1. 此脚本用于验证字段是否正确添加
  105. -- 2. 可以多次执行,不会修改数据
  106. -- 3. 帮助确认数据库结构变更是否成功
  107. -- ===============================================