Skip to content

array_type_field_filter: Add new contains filter to search on Array type field #460

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 4 commits into from
Oct 6, 2020
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
79 changes: 72 additions & 7 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -45,7 +45,7 @@ const config = {

<details><summary markdown="span"><strong>For LoopBack 3 users</strong></summary>

Use the [Data source generator](http://loopback.io/doc/en/lb3/Data-source-generator.html) to add a PostgreSQL data source to your application.
Use the [Data source generator](http://loopback.io/doc/en/lb3/Data-source-generator.html) to add a PostgreSQL data source to your application.
The generator will prompt for the database server hostname, port, and other settings
required to connect to a PostgreSQL database. It will also run the `npm install` command above for you.

Expand Down Expand Up @@ -96,7 +96,7 @@ const config = {

Check out [node-pg-pool](https://github.com/brianc/node-pg-pool) and [node postgres pooling example](https://github.com/brianc/node-postgres#pooling-example) for more information.

### Properties
### Configuration options

<table>
<thead>
Expand All @@ -106,7 +106,7 @@ Check out [node-pg-pool](https://github.com/brianc/node-pg-pool) and [node postg
<th>Description</th>
</tr>
</thead>
<tbody>
<tbody>
<tr>
<td>connector</td>
<td>String</td>
Expand Down Expand Up @@ -176,6 +176,14 @@ Check out [node-pg-pool](https://github.com/brianc/node-pg-pool) and [node postg
<td>Boolean/String</td>
<td>Set to <code>false</code> to disable default sorting on <code>id</code> column(s). Set to <code>numericIdOnly</code> to only apply to IDs with a number type <code>id</code>.</td>
</tr>
<tr>
<td>allowExtendedOperators</td>
<td>Boolean</td>
<td>Set to <code>true</code> to enable PostgreSQL-specific operators
such as <code>contains</code>. Learn more in
<a href="#extended-operators">Extended operators</a> below.
</td>
</tr>
</tbody>
</table>

Expand Down Expand Up @@ -272,7 +280,7 @@ The model definition consists of the following properties.
<th>Description</th>
</tr>
</thead>
<tbody>
<tbody>
<tr>
<td>name</td>
<td>Camel-case of the database table name</td>
Expand Down Expand Up @@ -412,6 +420,12 @@ details on LoopBack's data types.
VARCHAR2<br/>
Default length is 1024
</td>
</tr>
<tr>
<td>String[]</td>
<td>
VARCHAR2[]
</td>
</tr>
<tr>
<td>Number</td>
Expand Down Expand Up @@ -531,14 +545,65 @@ CustomerRepository.find({
});
```

## Extended operators

PostgreSQL supports the following PostgreSQL-specific operators:

- [`contains`](#operator-contains)

Please note extended operators are disabled by default, you must enable
them at datasource level or model level by setting `allowExtendedOperators` to
`true`.

### Operator `contains`

The `contains` operator allow you to query array properties and pick only
rows where the stored value contains all of the items specified by the query.

The operator is implemented using PostgreSQL [array operator
`@>`](https://www.postgresql.org/docs/current/functions-array.html).

**Note** The fields you are querying must be setup to use the postgresql array data type - see [Defining models](#defining-models) above.

Assuming a model such as this:

```ts
@model({
settings: {
allowExtendedOperators: true,
}
})
class Post {
@property({
type: ['string'],
postgresql: {
dataType: 'varchar[]',
},
})
categories?: string[];
}
```

You can query the tags fields as follows:

```ts
const posts = await postRepository.find({
where: {
{
categories: {'contains': ['AA']},
}
}
});
```

## Discovery and auto-migration

### Model discovery

The PostgreSQL connector supports _model discovery_ that enables you to create LoopBack models
based on an existing database schema. Once you defined your datasource:
- LoopBack 4 users could use the commend [`lb4 discover`](https://loopback.io/doc/en/lb4/Discovering-models.html) to discover models.
- For LB3 users, please check [Discovering models from relational databases](https://loopback.io/doc/en/lb3/Discovering-models-from-relational-databases.html).
- LoopBack 4 users could use the commend [`lb4 discover`](https://loopback.io/doc/en/lb4/Discovering-models.html) to discover models.
- For LB3 users, please check [Discovering models from relational databases](https://loopback.io/doc/en/lb3/Discovering-models-from-relational-databases.html).

(See [database discovery API](http://apidocs.strongloop.com/loopback-datasource-juggler/#datasource-prototype-discoverandbuildmodels) for related APIs information)

Expand Down Expand Up @@ -612,7 +677,7 @@ Here are some limitations and tips:

### Auto-migrate/Auto-update models with foreign keys

Foreign key constraints can be defined in the model definition.
Foreign key constraints can be defined in the model definition.

**Note**: The order of table creation is important. A referenced table must exist before creating a foreign key constraint.

Expand Down
3 changes: 3 additions & 0 deletions lib/postgresql.js
Original file line number Diff line number Diff line change
Expand Up @@ -522,6 +522,9 @@ PostgreSQL.prototype.buildExpression = function(columnName, operator,
const regexOperator = operatorValue.ignoreCase ? ' ~* ?' : ' ~ ?';
return new ParameterizedSQL(columnName + regexOperator,
[operatorValue.source]);
case 'contains':
return new ParameterizedSQL(columnName + ' @> array[' + operatorValue.map((v) => `'${v}'`) + ']::'
+ propertyDefinition.postgresql.dataType);
default:
// invoke the base implementation of `buildExpression`
return this.invokeSuper('buildExpression', columnName, operator,
Expand Down
28 changes: 23 additions & 5 deletions test/postgresql.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -73,7 +73,7 @@ describe('postgresql connector', function() {
dataType: 'varchar[]',
},
},
});
}, {allowExtendedOperators: true});
created = new Date();
});

Expand Down Expand Up @@ -218,7 +218,7 @@ describe('postgresql connector', function() {
post.should.have.property('tags');
post.tags.should.be.Array();
post.tags.length.should.eql(2);
post.tags.should.eql(['AA', 'AB']);
post.tags.toArray().should.eql(['AA', 'AB']);
return Post.updateAll({where: {id: postId}}, {tags: ['AA', 'AC']});
})
.then(()=> {
Expand All @@ -228,7 +228,7 @@ describe('postgresql connector', function() {
post.should.have.property('tags');
post.tags.should.be.Array();
post.tags.length.should.eql(2);
post.tags.should.eql(['AA', 'AC']);
post.tags.toArray().should.eql(['AA', 'AC']);
done();
})
.catch((error) => {
Expand All @@ -245,7 +245,7 @@ describe('postgresql connector', function() {
post.should.have.property('categories');
post.categories.should.be.Array();
post.categories.length.should.eql(2);
post.categories.should.eql(['AA', 'AB']);
post.categories.toArray().should.eql(['AA', 'AB']);
return Post.updateAll({where: {id: postId}}, {categories: ['AA', 'AC']});
})
.then(()=> {
Expand All @@ -255,14 +255,32 @@ describe('postgresql connector', function() {
post.should.have.property('categories');
post.categories.should.be.Array();
post.categories.length.should.eql(2);
post.categories.should.eql(['AA', 'AC']);
post.categories.toArray().should.eql(['AA', 'AC']);
done();
})
.catch((error) => {
done(error);
});
});

it('should support where filter for array type field', async () => {
await Post.create({
title: 'LoopBack Participates in Hacktoberfest',
categories: ['LoopBack', 'Announcements'],
});
await Post.create({
title: 'Growing LoopBack Community',
categories: ['LoopBack', 'Community'],
});

const found = await Post.find({where: {and: [
{
categories: {'contains': ['LoopBack', 'Community']},
},
]}});
found.map(p => p.title).should.deepEqual(['Growing LoopBack Community']);
});

it('should support boolean types with false value', function(done) {
Post.create(
{title: 'T2', content: 'C2', approved: false, created: created},
Expand Down