Schema.php 18 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509
  1. <?php
  2. /**
  3. * @link http://www.yiiframework.com/
  4. * @copyright Copyright (c) 2008 Yii Software LLC
  5. * @license http://www.yiiframework.com/license/
  6. */
  7. namespace yii\db\pgsql;
  8. use yii\db\Expression;
  9. use yii\db\TableSchema;
  10. use yii\db\ColumnSchema;
  11. use yii\db\ViewFinderTrait;
  12. /**
  13. * Schema is the class for retrieving metadata from a PostgreSQL database
  14. * (version 9.x and above).
  15. *
  16. * @author Gevik Babakhani <gevikb@gmail.com>
  17. * @since 2.0
  18. */
  19. class Schema extends \yii\db\Schema
  20. {
  21. use ViewFinderTrait;
  22. /**
  23. * @var string the default schema used for the current session.
  24. */
  25. public $defaultSchema = 'public';
  26. /**
  27. * @var array mapping from physical column types (keys) to abstract
  28. * column types (values)
  29. * @see http://www.postgresql.org/docs/current/static/datatype.html#DATATYPE-TABLE
  30. */
  31. public $typeMap = [
  32. 'bit' => self::TYPE_INTEGER,
  33. 'bit varying' => self::TYPE_INTEGER,
  34. 'varbit' => self::TYPE_INTEGER,
  35. 'bool' => self::TYPE_BOOLEAN,
  36. 'boolean' => self::TYPE_BOOLEAN,
  37. 'box' => self::TYPE_STRING,
  38. 'circle' => self::TYPE_STRING,
  39. 'point' => self::TYPE_STRING,
  40. 'line' => self::TYPE_STRING,
  41. 'lseg' => self::TYPE_STRING,
  42. 'polygon' => self::TYPE_STRING,
  43. 'path' => self::TYPE_STRING,
  44. 'character' => self::TYPE_CHAR,
  45. 'char' => self::TYPE_CHAR,
  46. 'bpchar' => self::TYPE_CHAR,
  47. 'character varying' => self::TYPE_STRING,
  48. 'varchar' => self::TYPE_STRING,
  49. 'text' => self::TYPE_TEXT,
  50. 'bytea' => self::TYPE_BINARY,
  51. 'cidr' => self::TYPE_STRING,
  52. 'inet' => self::TYPE_STRING,
  53. 'macaddr' => self::TYPE_STRING,
  54. 'real' => self::TYPE_FLOAT,
  55. 'float4' => self::TYPE_FLOAT,
  56. 'double precision' => self::TYPE_DOUBLE,
  57. 'float8' => self::TYPE_DOUBLE,
  58. 'decimal' => self::TYPE_DECIMAL,
  59. 'numeric' => self::TYPE_DECIMAL,
  60. 'money' => self::TYPE_MONEY,
  61. 'smallint' => self::TYPE_SMALLINT,
  62. 'int2' => self::TYPE_SMALLINT,
  63. 'int4' => self::TYPE_INTEGER,
  64. 'int' => self::TYPE_INTEGER,
  65. 'integer' => self::TYPE_INTEGER,
  66. 'bigint' => self::TYPE_BIGINT,
  67. 'int8' => self::TYPE_BIGINT,
  68. 'oid' => self::TYPE_BIGINT, // should not be used. it's pg internal!
  69. 'smallserial' => self::TYPE_SMALLINT,
  70. 'serial2' => self::TYPE_SMALLINT,
  71. 'serial4' => self::TYPE_INTEGER,
  72. 'serial' => self::TYPE_INTEGER,
  73. 'bigserial' => self::TYPE_BIGINT,
  74. 'serial8' => self::TYPE_BIGINT,
  75. 'pg_lsn' => self::TYPE_BIGINT,
  76. 'date' => self::TYPE_DATE,
  77. 'interval' => self::TYPE_STRING,
  78. 'time without time zone' => self::TYPE_TIME,
  79. 'time' => self::TYPE_TIME,
  80. 'time with time zone' => self::TYPE_TIME,
  81. 'timetz' => self::TYPE_TIME,
  82. 'timestamp without time zone' => self::TYPE_TIMESTAMP,
  83. 'timestamp' => self::TYPE_TIMESTAMP,
  84. 'timestamp with time zone' => self::TYPE_TIMESTAMP,
  85. 'timestamptz' => self::TYPE_TIMESTAMP,
  86. 'abstime' => self::TYPE_TIMESTAMP,
  87. 'tsquery' => self::TYPE_STRING,
  88. 'tsvector' => self::TYPE_STRING,
  89. 'txid_snapshot' => self::TYPE_STRING,
  90. 'unknown' => self::TYPE_STRING,
  91. 'uuid' => self::TYPE_STRING,
  92. 'json' => self::TYPE_STRING,
  93. 'jsonb' => self::TYPE_STRING,
  94. 'xml' => self::TYPE_STRING,
  95. ];
  96. /**
  97. * Creates a query builder for the PostgreSQL database.
  98. * @return QueryBuilder query builder instance
  99. */
  100. public function createQueryBuilder()
  101. {
  102. return new QueryBuilder($this->db);
  103. }
  104. /**
  105. * Resolves the table name and schema name (if any).
  106. * @param TableSchema $table the table metadata object
  107. * @param string $name the table name
  108. */
  109. protected function resolveTableNames($table, $name)
  110. {
  111. $parts = explode('.', str_replace('"', '', $name));
  112. if (isset($parts[1])) {
  113. $table->schemaName = $parts[0];
  114. $table->name = $parts[1];
  115. } else {
  116. $table->schemaName = $this->defaultSchema;
  117. $table->name = $name;
  118. }
  119. $table->fullName = $table->schemaName !== $this->defaultSchema ? $table->schemaName . '.' . $table->name : $table->name;
  120. }
  121. /**
  122. * Quotes a table name for use in a query.
  123. * A simple table name has no schema prefix.
  124. * @param string $name table name
  125. * @return string the properly quoted table name
  126. */
  127. public function quoteSimpleTableName($name)
  128. {
  129. return strpos($name, '"') !== false ? $name : '"' . $name . '"';
  130. }
  131. /**
  132. * Loads the metadata for the specified table.
  133. * @param string $name table name
  134. * @return TableSchema|null driver dependent table metadata. Null if the table does not exist.
  135. */
  136. public function loadTableSchema($name)
  137. {
  138. $table = new TableSchema();
  139. $this->resolveTableNames($table, $name);
  140. if ($this->findColumns($table)) {
  141. $this->findConstraints($table);
  142. return $table;
  143. } else {
  144. return null;
  145. }
  146. }
  147. /**
  148. * Returns all schema names in the database, including the default one but not system schemas.
  149. * This method should be overridden by child classes in order to support this feature
  150. * because the default implementation simply throws an exception.
  151. * @return array all schema names in the database, except system schemas
  152. * @since 2.0.4
  153. */
  154. protected function findSchemaNames()
  155. {
  156. $sql = <<<SQL
  157. SELECT ns.nspname AS schema_name
  158. FROM pg_namespace ns
  159. WHERE ns.nspname != 'information_schema' AND ns.nspname NOT LIKE 'pg_%'
  160. ORDER BY ns.nspname
  161. SQL;
  162. return $this->db->createCommand($sql)->queryColumn();
  163. }
  164. /**
  165. * Returns all table names in the database.
  166. * @param string $schema the schema of the tables. Defaults to empty string, meaning the current or default schema.
  167. * @return array all table names in the database. The names have NO schema name prefix.
  168. */
  169. protected function findTableNames($schema = '')
  170. {
  171. if ($schema === '') {
  172. $schema = $this->defaultSchema;
  173. }
  174. $sql = <<<SQL
  175. SELECT c.relname AS table_name
  176. FROM pg_class c
  177. INNER JOIN pg_namespace ns ON ns.oid = c.relnamespace
  178. WHERE ns.nspname = :schemaName AND c.relkind IN ('r','v','m','f')
  179. ORDER BY c.relname
  180. SQL;
  181. return $this->db->createCommand($sql, [':schemaName' => $schema])->queryColumn();
  182. }
  183. /**
  184. * @inheritdoc
  185. */
  186. protected function findViewNames($schema = '')
  187. {
  188. if ($schema === '') {
  189. $schema = $this->defaultSchema;
  190. }
  191. $sql = <<<SQL
  192. SELECT c.relname AS table_name
  193. FROM pg_class c
  194. INNER JOIN pg_namespace ns ON ns.oid = c.relnamespace
  195. WHERE ns.nspname = :schemaName AND (c.relkind = 'v' OR c.relkind = 'm')
  196. ORDER BY c.relname
  197. SQL;
  198. return $this->db->createCommand($sql, [':schemaName' => $schema])->queryColumn();
  199. }
  200. /**
  201. * Collects the foreign key column details for the given table.
  202. * @param TableSchema $table the table metadata
  203. */
  204. protected function findConstraints($table)
  205. {
  206. $tableName = $this->quoteValue($table->name);
  207. $tableSchema = $this->quoteValue($table->schemaName);
  208. //We need to extract the constraints de hard way since:
  209. //http://www.postgresql.org/message-id/26677.1086673982@sss.pgh.pa.us
  210. $sql = <<<SQL
  211. select
  212. ct.conname as constraint_name,
  213. a.attname as column_name,
  214. fc.relname as foreign_table_name,
  215. fns.nspname as foreign_table_schema,
  216. fa.attname as foreign_column_name
  217. from
  218. (SELECT ct.conname, ct.conrelid, ct.confrelid, ct.conkey, ct.contype, ct.confkey, generate_subscripts(ct.conkey, 1) AS s
  219. FROM pg_constraint ct
  220. ) AS ct
  221. inner join pg_class c on c.oid=ct.conrelid
  222. inner join pg_namespace ns on c.relnamespace=ns.oid
  223. inner join pg_attribute a on a.attrelid=ct.conrelid and a.attnum = ct.conkey[ct.s]
  224. left join pg_class fc on fc.oid=ct.confrelid
  225. left join pg_namespace fns on fc.relnamespace=fns.oid
  226. left join pg_attribute fa on fa.attrelid=ct.confrelid and fa.attnum = ct.confkey[ct.s]
  227. where
  228. ct.contype='f'
  229. and c.relname={$tableName}
  230. and ns.nspname={$tableSchema}
  231. order by
  232. fns.nspname, fc.relname, a.attnum
  233. SQL;
  234. $constraints = [];
  235. foreach ($this->db->createCommand($sql)->queryAll() as $constraint) {
  236. if ($this->db->slavePdo->getAttribute(\PDO::ATTR_CASE) === \PDO::CASE_UPPER) {
  237. $constraint = array_change_key_case($constraint, CASE_LOWER);
  238. }
  239. if ($constraint['foreign_table_schema'] !== $this->defaultSchema) {
  240. $foreignTable = $constraint['foreign_table_schema'] . '.' . $constraint['foreign_table_name'];
  241. } else {
  242. $foreignTable = $constraint['foreign_table_name'];
  243. }
  244. $name = $constraint['constraint_name'];
  245. if (!isset($constraints[$name])) {
  246. $constraints[$name] = [
  247. 'tableName' => $foreignTable,
  248. 'columns' => [],
  249. ];
  250. }
  251. $constraints[$name]['columns'][$constraint['column_name']] = $constraint['foreign_column_name'];
  252. }
  253. foreach ($constraints as $name => $constraint) {
  254. $table->foreignKeys[$name] = array_merge([$constraint['tableName']], $constraint['columns']);
  255. }
  256. }
  257. /**
  258. * Gets information about given table unique indexes.
  259. * @param TableSchema $table the table metadata
  260. * @return array with index and column names
  261. */
  262. protected function getUniqueIndexInformation($table)
  263. {
  264. $sql = <<<SQL
  265. SELECT
  266. i.relname as indexname,
  267. pg_get_indexdef(idx.indexrelid, k + 1, TRUE) AS columnname
  268. FROM (
  269. SELECT *, generate_subscripts(indkey, 1) AS k
  270. FROM pg_index
  271. ) idx
  272. INNER JOIN pg_class i ON i.oid = idx.indexrelid
  273. INNER JOIN pg_class c ON c.oid = idx.indrelid
  274. INNER JOIN pg_namespace ns ON c.relnamespace = ns.oid
  275. WHERE idx.indisprimary = FALSE AND idx.indisunique = TRUE
  276. AND c.relname = :tableName AND ns.nspname = :schemaName
  277. ORDER BY i.relname, k
  278. SQL;
  279. return $this->db->createCommand($sql, [
  280. ':schemaName' => $table->schemaName,
  281. ':tableName' => $table->name,
  282. ])->queryAll();
  283. }
  284. /**
  285. * Returns all unique indexes for the given table.
  286. * Each array element is of the following structure:
  287. *
  288. * ```php
  289. * [
  290. * 'IndexName1' => ['col1' [, ...]],
  291. * 'IndexName2' => ['col2' [, ...]],
  292. * ]
  293. * ```
  294. *
  295. * @param TableSchema $table the table metadata
  296. * @return array all unique indexes for the given table.
  297. */
  298. public function findUniqueIndexes($table)
  299. {
  300. $uniqueIndexes = [];
  301. $rows = $this->getUniqueIndexInformation($table);
  302. foreach ($rows as $row) {
  303. if ($this->db->slavePdo->getAttribute(\PDO::ATTR_CASE) === \PDO::CASE_UPPER) {
  304. $row = array_change_key_case($row, CASE_LOWER);
  305. }
  306. $column = $row['columnname'];
  307. if (!empty($column) && $column[0] === '"') {
  308. // postgres will quote names that are not lowercase-only
  309. // https://github.com/yiisoft/yii2/issues/10613
  310. $column = substr($column, 1, -1);
  311. }
  312. $uniqueIndexes[$row['indexname']][] = $column;
  313. }
  314. return $uniqueIndexes;
  315. }
  316. /**
  317. * Collects the metadata of table columns.
  318. * @param TableSchema $table the table metadata
  319. * @return bool whether the table exists in the database
  320. */
  321. protected function findColumns($table)
  322. {
  323. $tableName = $this->db->quoteValue($table->name);
  324. $schemaName = $this->db->quoteValue($table->schemaName);
  325. $sql = <<<SQL
  326. SELECT
  327. d.nspname AS table_schema,
  328. c.relname AS table_name,
  329. a.attname AS column_name,
  330. t.typname AS data_type,
  331. a.attlen AS character_maximum_length,
  332. pg_catalog.col_description(c.oid, a.attnum) AS column_comment,
  333. a.atttypmod AS modifier,
  334. a.attnotnull = false AS is_nullable,
  335. CAST(pg_get_expr(ad.adbin, ad.adrelid) AS varchar) AS column_default,
  336. coalesce(pg_get_expr(ad.adbin, ad.adrelid) ~ 'nextval',false) AS is_autoinc,
  337. array_to_string((select array_agg(enumlabel) from pg_enum where enumtypid=a.atttypid)::varchar[],',') as enum_values,
  338. CASE atttypid
  339. WHEN 21 /*int2*/ THEN 16
  340. WHEN 23 /*int4*/ THEN 32
  341. WHEN 20 /*int8*/ THEN 64
  342. WHEN 1700 /*numeric*/ THEN
  343. CASE WHEN atttypmod = -1
  344. THEN null
  345. ELSE ((atttypmod - 4) >> 16) & 65535
  346. END
  347. WHEN 700 /*float4*/ THEN 24 /*FLT_MANT_DIG*/
  348. WHEN 701 /*float8*/ THEN 53 /*DBL_MANT_DIG*/
  349. ELSE null
  350. END AS numeric_precision,
  351. CASE
  352. WHEN atttypid IN (21, 23, 20) THEN 0
  353. WHEN atttypid IN (1700) THEN
  354. CASE
  355. WHEN atttypmod = -1 THEN null
  356. ELSE (atttypmod - 4) & 65535
  357. END
  358. ELSE null
  359. END AS numeric_scale,
  360. CAST(
  361. information_schema._pg_char_max_length(information_schema._pg_truetypid(a, t), information_schema._pg_truetypmod(a, t))
  362. AS numeric
  363. ) AS size,
  364. a.attnum = any (ct.conkey) as is_pkey
  365. FROM
  366. pg_class c
  367. LEFT JOIN pg_attribute a ON a.attrelid = c.oid
  368. LEFT JOIN pg_attrdef ad ON a.attrelid = ad.adrelid AND a.attnum = ad.adnum
  369. LEFT JOIN pg_type t ON a.atttypid = t.oid
  370. LEFT JOIN pg_namespace d ON d.oid = c.relnamespace
  371. LEFT join pg_constraint ct on ct.conrelid=c.oid and ct.contype='p'
  372. WHERE
  373. a.attnum > 0 and t.typname != ''
  374. and c.relname = {$tableName}
  375. and d.nspname = {$schemaName}
  376. ORDER BY
  377. a.attnum;
  378. SQL;
  379. $columns = $this->db->createCommand($sql)->queryAll();
  380. if (empty($columns)) {
  381. return false;
  382. }
  383. foreach ($columns as $column) {
  384. if ($this->db->slavePdo->getAttribute(\PDO::ATTR_CASE) === \PDO::CASE_UPPER) {
  385. $column = array_change_key_case($column, CASE_LOWER);
  386. }
  387. $column = $this->loadColumnSchema($column);
  388. $table->columns[$column->name] = $column;
  389. if ($column->isPrimaryKey) {
  390. $table->primaryKey[] = $column->name;
  391. if ($table->sequenceName === null && preg_match("/nextval\\('\"?\\w+\"?\.?\"?\\w+\"?'(::regclass)?\\)/", $column->defaultValue) === 1) {
  392. $table->sequenceName = preg_replace(['/nextval/', '/::/', '/regclass/', '/\'\)/', '/\(\'/'], '', $column->defaultValue);
  393. }
  394. $column->defaultValue = null;
  395. } elseif ($column->defaultValue) {
  396. if ($column->type === 'timestamp' && $column->defaultValue === 'now()') {
  397. $column->defaultValue = new Expression($column->defaultValue);
  398. } elseif ($column->type === 'boolean') {
  399. $column->defaultValue = ($column->defaultValue === 'true');
  400. } elseif (stripos($column->dbType, 'bit') === 0 || stripos($column->dbType, 'varbit') === 0) {
  401. $column->defaultValue = bindec(trim($column->defaultValue, 'B\''));
  402. } elseif (preg_match("/^'(.*?)'::/", $column->defaultValue, $matches)) {
  403. $column->defaultValue = $matches[1];
  404. } elseif (preg_match('/^(?:\()?(.*?)(?(1)\))(?:::.+)?$/', $column->defaultValue, $matches)) {
  405. if ($matches[1] === 'NULL') {
  406. $column->defaultValue = null;
  407. } else {
  408. $column->defaultValue = $column->phpTypecast($matches[1]);
  409. }
  410. } else {
  411. $column->defaultValue = $column->phpTypecast($column->defaultValue);
  412. }
  413. }
  414. }
  415. return true;
  416. }
  417. /**
  418. * Loads the column information into a [[ColumnSchema]] object.
  419. * @param array $info column information
  420. * @return ColumnSchema the column schema object
  421. */
  422. protected function loadColumnSchema($info)
  423. {
  424. $column = $this->createColumnSchema();
  425. $column->allowNull = $info['is_nullable'];
  426. $column->autoIncrement = $info['is_autoinc'];
  427. $column->comment = $info['column_comment'];
  428. $column->dbType = $info['data_type'];
  429. $column->defaultValue = $info['column_default'];
  430. $column->enumValues = ($info['enum_values'] !== null) ? explode(',', str_replace(["''"], ["'"], $info['enum_values'])) : null;
  431. $column->unsigned = false; // has no meaning in PG
  432. $column->isPrimaryKey = $info['is_pkey'];
  433. $column->name = $info['column_name'];
  434. $column->precision = $info['numeric_precision'];
  435. $column->scale = $info['numeric_scale'];
  436. $column->size = $info['size'] === null ? null : (int) $info['size'];
  437. if (isset($this->typeMap[$column->dbType])) {
  438. $column->type = $this->typeMap[$column->dbType];
  439. } else {
  440. $column->type = self::TYPE_STRING;
  441. }
  442. $column->phpType = $this->getColumnPhpType($column);
  443. return $column;
  444. }
  445. /**
  446. * @inheritdoc
  447. */
  448. public function insert($table, $columns)
  449. {
  450. $params = [];
  451. $sql = $this->db->getQueryBuilder()->insert($table, $columns, $params);
  452. $returnColumns = $this->getTableSchema($table)->primaryKey;
  453. if (!empty($returnColumns)) {
  454. $returning = [];
  455. foreach ((array) $returnColumns as $name) {
  456. $returning[] = $this->quoteColumnName($name);
  457. }
  458. $sql .= ' RETURNING ' . implode(', ', $returning);
  459. }
  460. $command = $this->db->createCommand($sql, $params);
  461. $command->prepare(false);
  462. $result = $command->queryOne();
  463. return !$command->pdoStatement->rowCount() ? false : $result;
  464. }
  465. }